Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add CHARINDEX function for sqlserver #1675

Merged
merged 5 commits into from
May 4, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -137,6 +137,14 @@ class Trim<T : String?>(
override fun toQueryBuilder(queryBuilder: QueryBuilder): Unit = queryBuilder { append("TRIM(", expr, ")") }
}

/**
* Represents an SQL function that returns the index of the first occurrence of [substring] in [expr] or 0
*/
class Locate<T : String?>(val expr: Expression<T>, val substring: String) : Function<Int>(IntegerColumnType()) {
override fun toQueryBuilder(queryBuilder: QueryBuilder) =
currentDialect.functionProvider.locate(queryBuilder, expr, substring)
}

// General-Purpose Aggregate Functions

/**
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,9 @@ fun <T : String?> Expression<T>.substring(start: Int, length: Int): Substring<T>
/** Removes the longest string containing only spaces from both ends of string expression. */
fun <T : String?> Expression<T>.trim(): Trim<T> = Trim(this)

/** Returns the index of the first occurrence of [substring] in this string expression or 0 if it doesn't contain [substring] */
fun <T : String?> Expression<T>.locate(substring: String): Locate<T> = Locate(this, substring)

// General-Purpose Aggregate Functions

/** Returns the minimum value of this expression across all non-null input values, or `null` if there are no non-null values. */
Expand Down
Original file line number Diff line number Diff line change
@@ -1,13 +1,12 @@
package org.jetbrains.exposed.sql.vendors

import org.jetbrains.exposed.exceptions.UnsupportedByDialectException
import org.jetbrains.exposed.exceptions.throwUnsupportedException
import org.jetbrains.exposed.sql.*
import org.jetbrains.exposed.sql.transactions.TransactionManager
import java.nio.ByteBuffer
import java.util.*
import java.util.concurrent.ConcurrentHashMap
import kotlin.collections.HashMap
import kotlin.collections.LinkedHashSet

/**
* Provides definitions for all the supported SQL data types.
Expand Down Expand Up @@ -208,6 +207,22 @@ abstract class FunctionProvider {
append(")")
}

/**
* SQL function that returns the index of the first occurrence of the given substring [substring]
* in the string expression [expr]
*
* @param queryBuilder Query builder to append the SQL function to.
* @param expr String expression to find the substring in.
* @param substring: Substring to find
* @return index of the first occurrence of [substring] in [expr] starting from 1
* or 0 if [expr] doesn't contain [substring]
*/
open fun <T : String?> locate(queryBuilder: QueryBuilder, expr: Expression<T>, substring: String) {
throw UnsupportedByDialectException(
"There's no generic SQL for LOCATE. There must be vendor specific implementation.", currentDialect
)
}

// Pattern matching

/**
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -108,6 +108,18 @@ internal object H2FunctionProvider : FunctionProvider() {

return super.insert(false, table, columns, sql, transaction).replaceFirst("INSERT", "MERGE")
}

/**
* Implementation of [FunctionProvider.locate]
* Note: search is case-sensitive
* */
override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("LOCATE(\'", substring, "\',", expr, ")")
}
}

/**
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,14 @@ internal object MariaDBFunctionProvider : MysqlFunctionProvider() {
): Unit = queryBuilder {
append(expr1, " REGEXP ", pattern)
}

override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("LOCATE(\'", substring, "\',", expr, ")")
}
}

/**
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -72,6 +72,14 @@ internal open class MysqlFunctionProvider : FunctionProvider() {
override fun <T : String?> Expression<T>.match(pattern: String, mode: MatchMode?): Op<Boolean> =
MATCH(this, pattern, mode ?: MysqlMatchMode.STRICT)

override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("LOCATE(\'", substring, "\',", expr, ")")
}

override fun <T : String?> regexp(
expr1: Expression<T>,
pattern: Expression<String>,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -92,6 +92,14 @@ internal object OracleFunctionProvider : FunctionProvider() {
append(col, " ", order.name, ")")
}

override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("INSTR(", expr, ",\'", substring, "\')")
}

override fun <T> year(expr: Expression<T>, queryBuilder: QueryBuilder): Unit = queryBuilder {
append("Extract(YEAR FROM ")
append(expr)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -46,6 +46,18 @@ internal object PostgreSQLFunctionProvider : FunctionProvider() {
}
}

/**
* Implementation of [FunctionProvider.locate]
* Note: search is case-sensitive
* */
override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("POSITION(\'", substring, "\' IN ", expr, ")")
}

override fun <T : String?> regexp(
expr1: Expression<T>,
pattern: Expression<String>,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -73,6 +73,14 @@ internal object SQLServerFunctionProvider : FunctionProvider() {
}
}

override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("CHARINDEX(\'", substring, "\',", expr, ")")
}

override fun <T : String?> regexp(
expr1: Expression<T>,
pattern: Expression<String>,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,18 @@ internal object SQLiteFunctionProvider : FunctionProvider() {
}
}

/**
* Implementation of [FunctionProvider.locate]
* Note: search is case-sensitive
* */
override fun <T : String?> locate(
queryBuilder: QueryBuilder,
expr: Expression<T>,
substring: String
) = queryBuilder {
append("INSTR(", expr, ",\'", substring, "\')")
}

override fun <T : String?> regexp(
expr1: Expression<T>,
pattern: Expression<String>,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,9 @@ import org.jetbrains.exposed.sql.tests.shared.dml.DMLTestsData
import org.jetbrains.exposed.sql.tests.shared.dml.withCitiesAndUsers
import org.jetbrains.exposed.sql.vendors.H2Dialect
import org.jetbrains.exposed.sql.vendors.OracleDialect
import org.jetbrains.exposed.sql.vendors.PostgreSQLDialect
import org.jetbrains.exposed.sql.vendors.SQLServerDialect
import org.jetbrains.exposed.sql.vendors.SQLiteDialect
import org.jetbrains.exposed.sql.vendors.h2Mode
import org.junit.Test
import kotlin.test.assertEquals
Expand Down Expand Up @@ -301,6 +303,46 @@ class FunctionsTests : DatabaseTestsBase() {
}
}

@Test
fun testLocate() {
withCitiesAndUsers { cities, _, _ ->
val locate = cities.name.locate("e")
val results = cities.slice(locate).selectAll().toList()

assertEquals(6, results[0][locate]) // St. Petersburg
assertEquals(0, results[1][locate]) // Munich
assertEquals(6, results[2][locate]) // Prague
}
}

@Test
fun testLocate02() {
withCitiesAndUsers { cities, _, _ ->
val locate = cities.name.locate("Peter")
val results = cities.slice(locate).selectAll().toList()

assertEquals(5, results[0][locate]) // St. Petersburg
assertEquals(0, results[1][locate]) // Munich
assertEquals(0, results[2][locate]) // Prague
}
}

@Test
fun testLocate03() {
withCitiesAndUsers { cities, _, _ ->
val isCaseSensitiveDialect = currentDialectTest is SQLiteDialect ||
currentDialectTest is PostgreSQLDialect ||
currentDialectTest is H2Dialect

val locate = cities.name.locate("p")
val results = cities.slice(locate).selectAll().toList()

assertEquals(if (isCaseSensitiveDialect) 0 else 5, results[0][locate]) // St. Petersburg
assertEquals(0, results[1][locate]) // Munich
assertEquals(if (isCaseSensitiveDialect) 0 else 1, results[2][locate]) // Prague
}
}

@Test
fun testRandomFunction01() {
val t = DMLTestsData.Cities
Expand Down