diff --git a/ktorm-core/src/main/kotlin/org/ktorm/expression/SqlFormatter.kt b/ktorm-core/src/main/kotlin/org/ktorm/expression/SqlFormatter.kt index 9d55740d..1eaf540e 100644 --- a/ktorm-core/src/main/kotlin/org/ktorm/expression/SqlFormatter.kt +++ b/ktorm-core/src/main/kotlin/org/ktorm/expression/SqlFormatter.kt @@ -438,14 +438,7 @@ public abstract class SqlFormatter( if (!expr.declaredName.isNullOrBlank()) { write("${expr.declaredName.quoted} ") } else { - if (expr.expression.removeBrackets) { - visit(expr.expression) - } else { - write("(") - visit(expr.expression) - removeLastBlank() - write(") ") - } + writeSqlExpression(expr.expression) } return expr @@ -475,52 +468,20 @@ public abstract class SqlFormatter( override fun visitUnary(expr: UnaryExpression): UnaryExpression { if (expr.type == UnaryExpressionType.IS_NULL || expr.type == UnaryExpressionType.IS_NOT_NULL) { - if (expr.operand.removeBrackets) { - visit(expr.operand) - } else { - write("(") - visit(expr.operand) - removeLastBlank() - write(") ") - } - + writeSqlExpression(expr.operand) writeKeyword("${expr.type} ") } else { writeKeyword("${expr.type} ") - - if (expr.operand.removeBrackets) { - visit(expr.operand) - } else { - write("(") - visit(expr.operand) - removeLastBlank() - write(") ") - } + writeSqlExpression(expr.operand) } return expr } override fun visitBinary(expr: BinaryExpression): BinaryExpression { - if (expr.left.removeBrackets) { - visit(expr.left) - } else { - write("(") - visit(expr.left) - removeLastBlank() - write(") ") - } - + writeSqlExpression(expr.left) writeKeyword("${expr.type} ") - - if (expr.right.removeBrackets) { - visit(expr.right) - } else { - write("(") - visit(expr.right) - removeLastBlank() - write(") ") - } + writeSqlExpression(expr.right) return expr } @@ -533,16 +494,7 @@ public abstract class SqlFormatter( override fun visitCasting(expr: CastingExpression): CastingExpression { writeKeyword("cast(") - - if (expr.expression.removeBrackets) { - visit(expr.expression) - } else { - write("(") - visit(expr.expression) - removeLastBlank() - write(") ") - } - + writeSqlExpression(expr.expression) writeKeyword("as ${expr.sqlType.typeName}) ") return expr } @@ -711,4 +663,15 @@ public abstract class SqlFormatter( override fun visitUnknown(expr: SqlExpression): SqlExpression { throw DialectFeatureNotSupportedException("Unsupported expression type: ${expr.javaClass}") } + + protected fun writeSqlExpression(expr: SqlExpression) { + if (expr.removeBrackets) { + visit(expr) + } else { + write("(") + visit(expr) + removeLastBlank() + write(") ") + } + } } diff --git a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PgObject.kt b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PgObject.kt new file mode 100644 index 00000000..2e47d951 --- /dev/null +++ b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PgObject.kt @@ -0,0 +1,67 @@ +/* + * Copyright 2018-2023 the original author or authors. + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +package org.ktorm.support.postgresql + +import java.sql.PreparedStatement +import java.sql.ResultSet + +/** + * Custom PGObject class that can be used instead of the actual implementation. The actual implementation is not a + * JDK 9 module, thus we are not able to require it in module-info.java. + * + * The implementation accesses the postgresql API by reflection. + */ +@JvmInline +internal value class PgObject private constructor(internal val pgObject: Any) { + + internal val type: String + get() = getTypeMethod.invoke(pgObject) as String + + internal val value: String? + get() = getValueMethod.invoke(pgObject) as String? + + internal companion object { + private val pgObjectClass = Class.forName("org.postgresql.util.PGobject") + private val pgObjectConstructor = pgObjectClass.getDeclaredConstructor() + private val setTypeMethod = pgObjectClass.getMethod("setType", String::class.java) + private val setValueMethod = pgObjectClass.getMethod("setValue", String::class.java) + private val getTypeMethod = pgObjectClass.getMethod("getType") + private val getValueMethod = pgObjectClass.getMethod("getValue") + + internal fun fromPGobject(obj: Any): PgObject = PgObject(pgObjectClass.cast(obj)) + + internal operator fun invoke(type: String, value: String?): PgObject { + val pgObject = pgObjectConstructor.newInstance() + setTypeMethod.invoke(pgObject, type) + setValueMethod.invoke(pgObject, value) + return PgObject(pgObject) + } + } +} + +internal fun PreparedStatement.setPgObject(parameterIndex: Int, ktormPgObject: PgObject) { + this.setObject(parameterIndex, ktormPgObject.pgObject) +} + +internal fun ResultSet.getPgObject(columnIndex: Int): PgObject? { + val obj = this.getObject(columnIndex) + if (obj == null) { + return null + } else { + return PgObject.fromPGobject(obj) + } +} diff --git a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlExpressionVisitor.kt b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlExpressionVisitor.kt index 6a28b95d..57e72650 100644 --- a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlExpressionVisitor.kt +++ b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlExpressionVisitor.kt @@ -48,6 +48,7 @@ public interface PostgreSqlExpressionVisitor : SqlExpressionVisitor { is HStoreExpression -> visitHStore(expr) is CubeExpression -> visitCube(expr) is DefaultValueExpression -> visitDefaultValue(expr) + is TextSearchExpression -> visitTextSearch(expr) else -> super.visitScalar(expr) } @@ -182,4 +183,20 @@ public interface PostgreSqlExpressionVisitor : SqlExpressionVisitor { public fun visitDefaultValue(expr: DefaultValueExpression): DefaultValueExpression { return expr } + + /** + * Function that visits a [TextSearchExpression]. + */ + public fun visitTextSearch(expr: TextSearchExpression): TextSearchExpression { + val left = expr.left?.let { + visitScalar(it) + } + val right = visitScalar(expr.right) + + if (left === expr.left && right === expr.right) { + return expr + } else { + return expr.copy(left = left, right = right) + } + } } diff --git a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlFormatter.kt b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlFormatter.kt index c40454ff..45959d40 100644 --- a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlFormatter.kt +++ b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/PostgreSqlFormatter.kt @@ -173,73 +173,35 @@ public open class PostgreSqlFormatter( } override fun visitILike(expr: ILikeExpression): ILikeExpression { - if (expr.left.removeBrackets) { - visit(expr.left) - } else { - write("(") - visit(expr.left) - removeLastBlank() - write(") ") - } - + writeSqlExpression(expr.left) writeKeyword("ilike ") - - if (expr.right.removeBrackets) { - visit(expr.right) - } else { - write("(") - visit(expr.right) - removeLastBlank() - write(") ") - } + writeSqlExpression(expr.right) return expr } override fun visitHStore(expr: HStoreExpression): HStoreExpression { - if (expr.left.removeBrackets) { - visit(expr.left) - } else { - write("(") - visit(expr.left) - removeLastBlank() - write(") ") - } - + writeSqlExpression(expr.left) writeKeyword("${expr.type} ") - - if (expr.right.removeBrackets) { - visit(expr.right) - } else { - write("(") - visit(expr.right) - removeLastBlank() - write(") ") - } + writeSqlExpression(expr.right) return expr } override fun visitCube(expr: CubeExpression): CubeExpression { - if (expr.left.removeBrackets) { - visit(expr.left) - } else { - write("(") - visit(expr.left) - removeLastBlank() - write(") ") - } - + writeSqlExpression(expr.left) writeKeyword("${expr.type} ") + writeSqlExpression(expr.right) - if (expr.right.removeBrackets) { - visit(expr.right) - } else { - write("(") - visit(expr.right) - removeLastBlank() - write(") ") + return expr + } + + public override fun visitTextSearch(expr: TextSearchExpression): TextSearchExpression { + if (expr.left != null) { + writeSqlExpression(expr.left) } + writeKeyword("${expr.type} ") + writeSqlExpression(expr.right) return expr } diff --git a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/SqlTypes.kt b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/SqlTypes.kt index aef42061..7ceea23a 100644 --- a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/SqlTypes.kt +++ b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/SqlTypes.kt @@ -19,7 +19,6 @@ package org.ktorm.support.postgresql import org.ktorm.schema.BaseTable import org.ktorm.schema.Column import org.ktorm.schema.SqlType -import java.lang.reflect.InvocationTargetException import java.sql.PreparedStatement import java.sql.ResultSet import java.sql.Types @@ -125,32 +124,16 @@ public fun BaseTable<*>.cube(name: String): Column { * https://www.postgresql.org/docs/9.5/cube.html */ public object CubeSqlType : SqlType(Types.OTHER, "cube") { - // Access postgresql API by reflection, because it is not a JDK 9 module, - // we are not able to require it in module-info.java. - private val pgObjectClass = Class.forName("org.postgresql.util.PGobject") - private val getValueMethod = pgObjectClass.getMethod("getValue") - override fun doSetParameter(ps: PreparedStatement, index: Int, parameter: Cube) { ps.setObject(index, parameter, Types.OTHER) } - override fun doGetResult(rs: ResultSet, index: Int): Cube? { - val obj = pgObjectClass.cast(rs.getObject(index)) - if (obj == null) { - return null - } else { - @Suppress("SwallowedException") - try { - // (1, 2, 3), (4, 5, 6) - val value = getValueMethod.invoke(obj) as String - val numbers = value.replace("(", "").replace(")", "").split(",").map { it.trim().toDouble() } - val (x, y) = numbers.chunked(numbers.size / 2).map { it.toDoubleArray() } - return Cube(x, y) - } catch (e: InvocationTargetException) { - throw e.targetException - } + override fun doGetResult(rs: ResultSet, index: Int): Cube? = + rs.getPgObject(index)?.value?.let { + val numbers = it.replace("(", "").replace(")", "").split(",").map { it.trim().toDouble() } + val (x, y) = numbers.chunked(numbers.size / 2).map { it.toDoubleArray() } + Cube(x, y) } - } } /** @@ -172,29 +155,127 @@ public fun BaseTable<*>.earth(name: String): Column { * Part of PostgreSQL `earthdistance` SQL extension. */ public object EarthSqlType : SqlType(Types.OTHER, "earth") { - // Access postgresql API by reflection, because it is not a JDK 9 module, - // we are not able to require it in module-info.java. - private val pgObjectClass = Class.forName("org.postgresql.util.PGobject") - private val getValueMethod = pgObjectClass.getMethod("getValue") - override fun doSetParameter(ps: PreparedStatement, index: Int, parameter: Earth) { ps.setObject(index, parameter, Types.OTHER) } - override fun doGetResult(rs: ResultSet, index: Int): Earth? { - val obj = pgObjectClass.cast(rs.getObject(index)) - if (obj == null) { - return null - } else { - @Suppress("SwallowedException") - try { - // (1, 2, 3) - val value = getValueMethod.invoke(obj) as String - val (x, y, z) = value.removeSurrounding("(", ")").split(",").map { it.trim().toDouble() } - return Earth(x, y, z) - } catch (e: InvocationTargetException) { - throw e.targetException - } + override fun doGetResult(rs: ResultSet, index: Int): Earth? = + rs.getPgObject(index)?.value?.let { + val (x, y, z) = it.removeSurrounding("(", ")").split(",").map { it.trim().toDouble() } + return Earth(x, y, z) + } +} + +/** + * Sorted list of lexemes, which are words that have been normalized to merge different variants of the same word and + * are used for text search. + * See: https://www.postgresql.org/docs/current/datatype-textsearch.html + */ +public typealias TSVector = List + +/** + * A lexeme of a tsvector which is the actual word with its weighted positions. The positions are optional and empty by + * default. + * See: https://www.postgresql.org/docs/current/datatype-textsearch.html + */ +public data class TSVectorLexeme(val word: String, val positions: List = emptyList()) + +/** + * The position of a lexeme contains its numeric position and a weight represented as a character ranging A-D. The + * weight is optional and the default value is 'D'. If the weight does not exist, then the weight is 'D' + * See: https://www.postgresql.org/docs/current/datatype-textsearch.html + */ +public data class TSVectorLexemePosition(val position: Int, val weight: Char? = null) + +/** + * Defines a column typed [TSVectorSqlType]. + */ +public fun BaseTable<*>.tsvector(name: String): Column = registerColumn(name, TSVectorSqlType) + +/** + * Defines a column typed [TSQuerySqlType]. + */ +public fun BaseTable<*>.tsquery(name: String): Column = registerColumn(name, TSQuerySqlType) + +/** + * [SqlType] Implementation represents PostgreSQL `tsvector` type. + */ +public object TSVectorSqlType : SqlType(Types.OTHER, "tsvector") { + // Examples of a tsvector: + // - ' ' 'Joe''s' 'a' 'and' 'contains' 'lexeme' 'quote' 'spaces' 'the' + // - 'a':1A 'cat':6 'fat':2B,5C 'nice: 3,7' 'slow: 4B,8' + // + // A single word always starts and ends with a "'". If the word contains a "'", then this character can be escaped + // by using it twice ("''"). + // Regex explained: Start with "'", then match as long as there is no "'", except when it is "''" and finish on "'". + private const val wordRegex = """'((?:[^']|'')+)'""" + // The positions list starts with ":" as the separator to the word and then continues as a list of the position + // number and optionally its weight. The position entries are seperated by "," + // Regex explained: Start with ":", then match for any word character (includes numbers and letters) followed by an + // optional "," (the last entry doe not contain ",") + private const val positionsListRegex = """:((?:\w+,?)+)""" + // A lexeme contains of a word and optionally its positions list. + private val tsVectorLexemeRegex = Regex("""$wordRegex(?:$positionsListRegex)?""") + + override fun doGetResult(rs: ResultSet, index: Int): TSVector? = + rs.getPgObject(index)?.value?.let { value -> + tsVectorLexemeRegex.findAll(value).map { res -> + val unescapedWord = res.groupValues[1].replace("''", "'") + val positions = res.groupValues[2].split(",").mapNotNull { pos -> + if (pos.isNotEmpty()) { + val position = pos.takeWhile { it.isDigit() }.toInt() + val weight = pos.lastOrNull()?.takeUnless { it.isDigit() } + TSVectorLexemePosition(position, weight) + } else { + null + } + } + TSVectorLexeme(unescapedWord, positions) + }.toList() + } + + override fun doSetParameter(ps: PreparedStatement, index: Int, parameter: TSVector) { + val lexemes = parameter.joinToString(" ") { lexeme -> + val escapedWord = lexeme.word.replace("'", "''") + val positions = lexeme.positions.map { + "${it.position}${it.weight ?: ""}" + }.ifEmpty { null }?.joinToString(",", ":") + "'$escapedWord'${positions ?: ""}" } + ps.setPgObject(index, PgObject(this.typeName, lexemes)) + } +} + +/** + * The query to do text search + * See: https://www.postgresql.org/docs/current/datatype-textsearch.html + */ +public typealias TSQuery = String + +/** + * [SqlType] Implementation represents PostgreSQL `tsquery` type. + */ +public object TSQuerySqlType : SqlType(Types.OTHER, "tsquery") { + override fun doGetResult(rs: ResultSet, index: Int): TSQuery? = rs.getString(index) + + override fun doSetParameter(ps: PreparedStatement, index: Int, parameter: TSQuery) { + ps.setPgObject(index, PgObject(this.typeName, parameter)) + } +} + +/** + * Configures the text search. E.g.: 'english', 'simple'. Defaults to 'english' if not used. + * See: https://www.postgresql.org/docs/current/textsearch-controls.html + */ +public typealias RegConfig = String + +/** + * [SqlType] Implementation represents PostgreSQL `regconfig` type. + */ +public object RegConfigSqlType : SqlType(Types.OTHER, "regconfig") { + override fun doGetResult(rs: ResultSet, index: Int): RegConfig? = rs.getString(index) + + override fun doSetParameter(ps: PreparedStatement, index: Int, parameter: RegConfig) { + ps.setPgObject(index, PgObject(this.typeName, parameter)) } } diff --git a/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/TextSearch.kt b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/TextSearch.kt new file mode 100644 index 00000000..afb8a45f --- /dev/null +++ b/ktorm-support-postgresql/src/main/kotlin/org/ktorm/support/postgresql/TextSearch.kt @@ -0,0 +1,187 @@ +/* + * Copyright 2018-2023 the original author or authors. + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +package org.ktorm.support.postgresql + +import org.ktorm.expression.ArgumentExpression +import org.ktorm.expression.FunctionExpression +import org.ktorm.expression.ScalarExpression +import org.ktorm.schema.BooleanSqlType +import org.ktorm.schema.ColumnDeclaring +import org.ktorm.schema.SqlType +import org.ktorm.schema.TextSqlType + +/** + * Enum for text search operators. + * See: https://www.postgresql.org/docs/current/functions-textsearch.html + */ +public enum class TextSearchExpressionType(private val value: String) { + + /** + * The text search match operator checks whether a tsquery matches a tsvector or a text. + * Translated to the @@ operator in PostgreSQL. + */ + MATCH("@@"), + + /** + * The text search concatenate operator concatenates tsvectors. + * Translated to the || operator in PostgreSQL. + */ + CONCAT("||"), + + /** + * The text search AND operator combines tsquerys by an AND. + * Translated to the && operator in PostgreSQL. + */ + AND("&&"), + + /** + * The text search OR operator combines tsquerys by an OR. + * Translated to the || operator in PostgreSQL. + */ + OR("||"), + + /** + * The text search NOT operator negates a tsquery. + * Translated to the !! operator in PostgreSQL. + */ + NOT("!!"), + + /** + * The text search phrase operator creates a tsquery that checks whether 2 tsquery follow each other. + * Translated to the <-> operator in PostgreSQL. + */ + PHRASE("<->"), + + /** + * The text search contains operator checks whether a tsquery contains another tsquery. + * Translated to the @> operator in PostgreSQL. + */ + CONTAINS("@>"), + + /** + * The text search contained in operator checks whether a tsquery is contained in another tsquery. + * Translated to the <@ operator in PostgreSQL. + */ + CONTAINED_IN("<@"); + + override fun toString(): String = value +} + +/** + * Expression class that represents PostgreSQL text search operations. + * + * @property type the expression's type. + * @property left the expression's left operand. + * @property right the expression's right operand. + */ +public data class TextSearchExpression( + val type: TextSearchExpressionType, + val left: ScalarExpression<*>?, + val right: ScalarExpression<*>, + override val sqlType: SqlType, + override val isLeafNode: Boolean = false, + override val extraProperties: Map = emptyMap() +) : ScalarExpression() + +/** + * Checks whether a tsvector matches a tsquery. Translated to the @@ operator in PostgreSQL. + */ +@JvmName("matchTSQuery") +public infix fun ColumnDeclaring.match(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.MATCH, asExpression(), expr.asExpression(), BooleanSqlType) + +/** + * Checks whether a tsquery matches a tsvector. Translated to the @@ operator in PostgreSQL. + */ +@JvmName("matchTSVector") +public infix fun ColumnDeclaring.match(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.MATCH, asExpression(), expr.asExpression(), BooleanSqlType) + +/** + * Checks whether a text matches a tsquery. Translated to the @@ operator in PostgreSQL. + */ +@JvmName("matchesTSQuery") +public infix fun ColumnDeclaring.match(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.MATCH, asExpression(), expr.asExpression(), BooleanSqlType) + +/** + * Concatenates tsvectors. Translated to the || operator in PostgreSQL. + */ +public infix fun ColumnDeclaring.concat(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.CONCAT, asExpression(), expr.asExpression(), TSVectorSqlType) + +/** + * Combines tsquerys by an AND. Translated to the && operator in PostgreSQL. + */ +public infix fun ColumnDeclaring.and(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.AND, asExpression(), expr.asExpression(), TSQuerySqlType) + +/** + * Combines tsquerys by an OR. Translated to the || operator in PostgreSQL. + */ +public infix fun ColumnDeclaring.or(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.OR, asExpression(), expr.asExpression(), TSQuerySqlType) + +/** + * Negates a tsquery. Translated to the !! operator in PostgreSQL. + */ +public fun not(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.NOT, null, expr.asExpression(), TSQuerySqlType) + +/** + * Creates a tsquery that checks whether 2 tsquery follow each other. Translated to the <-> operator in PostgreSQL. + */ +public infix fun ColumnDeclaring.followedBy(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.PHRASE, asExpression(), expr.asExpression(), TSQuerySqlType) + +/** + * Checks whether a tsquery contains another tsquery. Translated to the @> operator in PostgreSQL. + */ +public infix fun ColumnDeclaring.contains(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.CONTAINS, asExpression(), expr.asExpression(), BooleanSqlType) + +/** + * Checks whether a tsquery is contained in another tsquery. Translated to the <@ operator in PostgreSQL. + */ +public infix fun ColumnDeclaring.containedIn(expr: ColumnDeclaring): TextSearchExpression = + TextSearchExpression(TextSearchExpressionType.CONTAINED_IN, asExpression(), expr.asExpression(), BooleanSqlType) + +/** + * Calls the to_tsquery function of Postgres, which converts a text to a tsquery. + * See: https://www.postgresql.org/docs/current/functions-textsearch.html + * + * @param config The configuration of the query. E.g.: "english" or "simple" + * @param value The text that should be converted to a tsquery + */ +public fun toTSQuery(config: RegConfig, value: String): FunctionExpression = FunctionExpression( + functionName = "to_tsquery", + arguments = listOf(ArgumentExpression(config, RegConfigSqlType), ArgumentExpression(value, TextSqlType)), + sqlType = TSQuerySqlType +) + +/** + * Calls the to_tsvector function of Postgres, which converts a text to a tsvector. + * See: https://www.postgresql.org/docs/current/functions-textsearch.html + * + * @param config The configuration of the query. E.g.: "english" or "simple" + * @param value The text that should be converted to a tsvector + */ +public fun toTSVector(config: RegConfig, value: String): FunctionExpression = FunctionExpression( + functionName = "to_tsvector", + arguments = listOf(ArgumentExpression(config, RegConfigSqlType), ArgumentExpression(value, TextSqlType)), + sqlType = TSVectorSqlType +) diff --git a/ktorm-support-postgresql/src/test/kotlin/org/ktorm/support/postgresql/TextSearchTest.kt b/ktorm-support-postgresql/src/test/kotlin/org/ktorm/support/postgresql/TextSearchTest.kt new file mode 100644 index 00000000..705d5a0a --- /dev/null +++ b/ktorm-support-postgresql/src/test/kotlin/org/ktorm/support/postgresql/TextSearchTest.kt @@ -0,0 +1,337 @@ +package org.ktorm.support.postgresql + +import org.junit.Test +import org.ktorm.database.use +import org.ktorm.dsl.* +import org.ktorm.entity.Entity +import org.ktorm.schema.* +import kotlin.test.assertContains +import kotlin.test.assertEquals +import kotlin.test.assertFalse + +class TextSearchTest : BasePostgreSqlTest() { + + object TestTable : Table("t_textsearch") { + val id = int("id").primaryKey().bindTo { it.id } + val originalText = text("original_text").bindTo { it.originalText } + val textsearch = tsvector("textsearch").bindTo { it.textsearch } + } + + interface TestRecord : Entity { + companion object : Entity.Factory() + + val id: Int + val originalText: String + val textsearch: TSVector + } + + object TestQueryTable : Table("t_textsearch_query") { + val id = int("id").primaryKey().bindTo { it.id } + val query = tsquery("query").bindTo { it.query } + } + + interface TestQueryRecord : Entity { + companion object : Entity.Factory() + + val id: Int + val query: String + } + + private fun insertText(originalText: String, textSearch: ColumnDeclaring? = null): Int = + database.insertReturning(TestTable, TestTable.id){ + set(TestTable.originalText, originalText) + set(TestTable.textsearch, textSearch ?: toTSVector("simple", originalText)) + }!! + + // Test examples coming from https://www.postgresql.org/docs/current/datatype-textsearch.html#DATATYPE-TSVECTOR + @Test + fun testTSVectorWordsOnly() { + database.useConnection { conn -> + conn.createStatement().use { statement -> + statement.execute("select 'a fat cat sat on a mat and ate a fat rat'::tsvector") + val resultSet = statement.resultSet + resultSet.next() + val tsVector = TSVectorSqlType.getResult(resultSet, 1) + assertEquals( + listOf( + TSVectorLexeme("a"), + TSVectorLexeme("and"), + TSVectorLexeme("ate"), + TSVectorLexeme("cat"), + TSVectorLexeme("fat"), + TSVectorLexeme("mat"), + TSVectorLexeme("on"), + TSVectorLexeme("rat"), + TSVectorLexeme("sat") + ), + tsVector + ) + } + } + } + + @Test + fun testTSVectorSpaceAndQuotes() { + database.useConnection { conn -> + conn.createStatement().use { statement -> + statement.execute("select \$\$the lexeme ' ' & 'Joe''s' contains spaces and quotes\$\$::tsvector") + val resultSet = statement.resultSet + resultSet.next() + val tsVector = TSVectorSqlType.getResult(resultSet, 1) + assertEquals( + listOf( + TSVectorLexeme(" "), + TSVectorLexeme("&"), + TSVectorLexeme("Joe's"), + TSVectorLexeme("and"), + TSVectorLexeme("contains"), + TSVectorLexeme("lexeme"), + TSVectorLexeme("quotes"), + TSVectorLexeme("spaces"), + TSVectorLexeme("the"), + ), + tsVector + ) + } + } + } + + @Test + fun testTSVectorWithPositionsAndWeights() { + database.useConnection { conn -> + conn.createStatement().use { statement -> + statement.execute("select 'a:1A fat:2B,4C cat:5D'::tsvector") + val resultSet = statement.resultSet + resultSet.next() + val tsVector = TSVectorSqlType.getResult(resultSet, 1) + assertEquals( + listOf( + TSVectorLexeme("a", listOf(TSVectorLexemePosition(1, 'A'))), + TSVectorLexeme("cat", listOf(TSVectorLexemePosition(5))), + TSVectorLexeme("fat", listOf(TSVectorLexemePosition(2, 'B'), TSVectorLexemePosition(4, 'C'))) + ), + tsVector + ) + } + } + } + + @Test + fun testTSVectorWithPositionsOnly() { + database.useConnection { conn -> + conn.createStatement().use { statement -> + statement.execute("select 'a:1 fat:2 cat:3 sat:4 on:5 a:6 mat:7 and:8 ate:9 a:10 fat:11 rat:12'::tsvector") + val resultSet = statement.resultSet + resultSet.next() + val tsVector = TSVectorSqlType.getResult(resultSet, 1) + assertEquals( + listOf( + TSVectorLexeme("a", listOf(TSVectorLexemePosition(1), TSVectorLexemePosition(6), TSVectorLexemePosition(10))), + TSVectorLexeme("and", listOf(TSVectorLexemePosition(8))), + TSVectorLexeme("ate", listOf(TSVectorLexemePosition(9))), + TSVectorLexeme("cat", listOf(TSVectorLexemePosition(3))), + TSVectorLexeme("fat", listOf(TSVectorLexemePosition(2), TSVectorLexemePosition(11))), + TSVectorLexeme("mat", listOf(TSVectorLexemePosition(7))), + TSVectorLexeme("on", listOf(TSVectorLexemePosition(5))), + TSVectorLexeme("rat", listOf(TSVectorLexemePosition(12))), + TSVectorLexeme("sat", listOf(TSVectorLexemePosition(4))) + ), + tsVector + ) + } + } + } + + @Test + fun testInsertTSVector() { + val tsVector = listOf( + TSVectorLexeme("a", listOf(TSVectorLexemePosition(1, 'A'))), + TSVectorLexeme("cat", listOf(TSVectorLexemePosition(5))), + TSVectorLexeme("fat", listOf(TSVectorLexemePosition(2, 'B'), TSVectorLexemePosition(4, 'C'))), + TSVectorLexeme("sits", listOf(TSVectorLexemePosition(3), TSVectorLexemePosition(6))) + ) + val id = database.insertReturning(TestTable, TestTable.id){ + set(TestTable.textsearch, tsVector) + }!! + val queried = database.from(TestTable).select().where { TestTable.id.eq(id) }.map { row -> + row[TestTable.textsearch] + }.first() + assertEquals(tsVector, queried) + } + + @Test + fun testInsertTSVectorWordsOnly() { + val tsVector = listOf( + TSVectorLexeme("Joe's"), + TSVectorLexeme("cat"), + TSVectorLexeme("fat") + ) + val id = database.insertReturning(TestTable, TestTable.id){ + set(TestTable.textsearch, tsVector) + }!! + val queried = database.from(TestTable).select().where { TestTable.id.eq(id) }.map { row -> + row[TestTable.textsearch] + }.first() + assertEquals(tsVector, queried) + } + + @Test + fun testToTSVector() { + val text = "Joe's contains a single quotation mark" + val id = insertText(text, toTSVector("english", text)) + val expected = listOf( + TSVectorLexeme("contain", listOf(TSVectorLexemePosition(3))), + TSVectorLexeme("joe", listOf(TSVectorLexemePosition(1))), + TSVectorLexeme("mark", listOf(TSVectorLexemePosition(7))), + TSVectorLexeme("quotat", listOf(TSVectorLexemePosition(6))), + TSVectorLexeme("singl", listOf(TSVectorLexemePosition(5))) + ) + val queried = database.from(TestTable).select().where { TestTable.id.eq(id) }.map { row -> + row[TestTable.textsearch] + }.first() + assertEquals(expected, queried) + } + + @Test + fun testTSVectorMatchTSQuery() { + val text = "Hello tsVectorMatchTSQuery test" + val id = insertText(text) + val queried = database.from(TestTable).select().where { TestTable.textsearch match toTSQuery("simple", "tsVectorMatchTSQuery") }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, id) + } + + @Test + fun testTSQueryMatchTSVector() { + val text = "Hello testTSQueryMatchTSVector test" + val id = insertText(text) + val queried = database.from(TestTable).select().where { toTSQuery("simple", "testTSQueryMatchTSVector") match TestTable.textsearch }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, id) + } + + @Test + fun testTextMatchTSQuery() { + val text = "Hello testTSQueryMatchTSVector test" + val id = insertText(text) + val queried = database.from(TestTable).select().where { TestTable.originalText match toTSQuery("english", "testTSQueryMatchTSVector") }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, id) + } + + @Test + fun testTSVectorConcatTSVector() { + val text1 = "Joe's contains a single quotation mark" + val text2 = ", for some reason" + val id = insertText(text1 + text2, toTSVector("simple", text1) concat toTSVector("simple", text2)) + val expected = listOf( + TSVectorLexeme("a", listOf(TSVectorLexemePosition(4))), + TSVectorLexeme("contains", listOf(TSVectorLexemePosition(3))), + TSVectorLexeme("for", listOf(TSVectorLexemePosition(8))), + TSVectorLexeme("joe", listOf(TSVectorLexemePosition(1))), + TSVectorLexeme("mark", listOf(TSVectorLexemePosition(7))), + TSVectorLexeme("quotation", listOf(TSVectorLexemePosition(6))), + TSVectorLexeme("reason", listOf(TSVectorLexemePosition(10))), + TSVectorLexeme("s", listOf(TSVectorLexemePosition(2))), + TSVectorLexeme("single", listOf(TSVectorLexemePosition(5))), + TSVectorLexeme("some", listOf(TSVectorLexemePosition(9))) + ) + val queried = database.from(TestTable).select().where { TestTable.id.eq(id) }.map { row -> + row[TestTable.textsearch] + }.first() + assertEquals(expected, queried) + } + + @Test + fun testTSQueryAndTSQuery() { + val expectedText = "Hello expected text" + val expectedId = insertText(expectedText) + val notExpectedText = "Hello other text" + val notExpectedId = insertText(notExpectedText) + val queried = database.from(TestTable).select().where { TestTable.textsearch match (toTSQuery("simple", "text") and toTSQuery("simple", "expected")) }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, expectedId) + assertFalse(queried.contains(notExpectedId)) + } + + @Test + fun testTSQueryOrTSQuery() { + val expectedText1 = "Hello text1" + val expectedId1 = insertText(expectedText1) + val expectedText2 = "Hello text2" + val expectedId2 = insertText(expectedText2) + val queried = database.from(TestTable).select().where { TestTable.textsearch match (toTSQuery("simple", "text1") or toTSQuery("simple", "text2")) }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, expectedId1) + assertContains(queried, expectedId2) + } + + @Test + fun testNotTSQuery() { + val expectedText = "Hello expected text" + val expectedId = insertText(expectedText) + val notExpectedText = "Hello not expected text" + val notExpectedId = insertText(notExpectedText) + val queried = database.from(TestTable).select().where { TestTable.textsearch match not(toTSQuery("simple", "not")) }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, expectedId) + assertFalse(queried.contains(notExpectedId)) + } + + @Test + fun testTSQueryFollowedByTSQuery() { + val expectedText = "Hello expected text" + val expectedId = insertText(expectedText) + val notExpectedText = "Hello not expected text" + val notExpectedId = insertText(notExpectedText) + val queried = database.from(TestTable).select().where { TestTable.textsearch match (toTSQuery("simple", "hello") followedBy toTSQuery("simple", "expected")) }.map { row -> + row[TestTable.id] + }.toList() + assertContains(queried, expectedId) + assertFalse(queried.contains(notExpectedId)) + } + + @Test + fun testTSQueryContainsTSQuery() { + val id = database.insertReturning(TestQueryTable, TestQueryTable.id) { + set(TestQueryTable.query, toTSQuery("simple", "test") and toTSQuery("simple", "query")) + } + val queried = database.from(TestQueryTable).select().where { TestQueryTable.query contains toTSQuery("simple", "test") }.map { row -> + row[TestQueryTable.id] + }.toList() + assertContains(queried, id) + } + + @Test + fun testTSQueryContainedInTSQuery() { + val id = database.insertReturning(TestQueryTable, TestQueryTable.id) { + set(TestQueryTable.query, toTSQuery("simple", "test") and toTSQuery("simple", "query")) + } + val queried = database.from(TestQueryTable).select().where { toTSQuery("simple", "test") containedIn TestQueryTable.query }.map { row -> + row[TestQueryTable.id] + }.toList() + assertContains(queried, id) + } + + @Test + fun testParentheses() { + val text = "a, b" + val id = insertText(text) + // Query1: a & !b & c + val queried1 = database.from(TestTable).select().where { TestTable.originalText match (toTSQuery("english", "a") and not(toTSQuery("english", "b")) and toTSQuery("english", "c")) }.map { row -> + row[TestTable.id] + }.toList() + // Query2: a & !(b&c) + val queried2 = database.from(TestTable).select().where { TestTable.originalText match (toTSQuery("english", "a") and not(toTSQuery("english", "b") and toTSQuery("english", "c"))) }.map { row -> + row[TestTable.id] + }.toList() + assertFalse(queried1.contains(id)) + assertContains(queried2, id) + } +} diff --git a/ktorm-support-postgresql/src/test/resources/drop-postgresql-data.sql b/ktorm-support-postgresql/src/test/resources/drop-postgresql-data.sql index cfe4c8f5..85720882 100644 --- a/ktorm-support-postgresql/src/test/resources/drop-postgresql-data.sql +++ b/ktorm-support-postgresql/src/test/resources/drop-postgresql-data.sql @@ -7,3 +7,5 @@ drop type if exists mood; drop table if exists t_json; drop table t_earthdistance; drop table if exists t_user; +drop table if exists t_textsearch; +drop table if exists t_textsearch_query; diff --git a/ktorm-support-postgresql/src/test/resources/init-postgresql-data.sql b/ktorm-support-postgresql/src/test/resources/init-postgresql-data.sql index a4decd68..20c35574 100644 --- a/ktorm-support-postgresql/src/test/resources/init-postgresql-data.sql +++ b/ktorm-support-postgresql/src/test/resources/init-postgresql-data.sql @@ -47,6 +47,17 @@ create table t_user( age int ); +create table t_textsearch( + id serial primary key, + original_text text, + textsearch tsvector +); + +create table t_textsearch_query( + id serial primary key, + query tsquery +); + insert into t_department(name, location, "mixedCase") values ('tech', 'Guangzhou', 'one'); insert into t_department(name, location, "mixedCase") values ('finance', 'Beijing', 'two');