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

feat: EXPOSED-66 Extend partial index to SQLServer and SQLite #1763

Merged
merged 3 commits into from
Jun 19, 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
2 changes: 2 additions & 0 deletions exposed-core/api/exposed-core.api
Original file line number Diff line number Diff line change
Expand Up @@ -3309,6 +3309,7 @@ public class org/jetbrains/exposed/sql/vendors/SQLServerDialect : org/jetbrains/
protected fun createIndexWithType (Ljava/lang/String;Ljava/lang/String;Ljava/lang/String;Ljava/lang/String;Ljava/lang/String;)Ljava/lang/String;
public fun createSchema (Lorg/jetbrains/exposed/sql/Schema;)Ljava/lang/String;
public fun dropDatabase (Ljava/lang/String;)Ljava/lang/String;
public fun dropIndex (Ljava/lang/String;Ljava/lang/String;ZZ)Ljava/lang/String;
public fun dropSchema (Lorg/jetbrains/exposed/sql/Schema;Z)Ljava/lang/String;
public fun getDefaultReferenceOption ()Lorg/jetbrains/exposed/sql/ReferenceOption;
public fun getLikePatternSpecialChars ()Ljava/util/Map;
Expand All @@ -3330,6 +3331,7 @@ public class org/jetbrains/exposed/sql/vendors/SQLiteDialect : org/jetbrains/exp
public fun createDatabase (Ljava/lang/String;)Ljava/lang/String;
public fun createIndex (Lorg/jetbrains/exposed/sql/Index;)Ljava/lang/String;
public fun dropDatabase (Ljava/lang/String;)Ljava/lang/String;
public fun dropIndex (Ljava/lang/String;Ljava/lang/String;ZZ)Ljava/lang/String;
public fun getSupportsCreateSchema ()Z
public fun getSupportsCreateSequence ()Z
public fun getSupportsMultipleGeneratedKeys ()Z
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -1097,15 +1097,19 @@ abstract class VendorDialect(
}

fun filterCondition(index: Index): String? {
return if (currentDialect is PostgreSQLDialect) {
index.filterCondition?.let {
QueryBuilder(false)
.append(" WHERE ").append(it)
.toString()
return index.filterCondition?.let {
when (currentDialect) {
is PostgreSQLDialect, is SQLServerDialect, is SQLiteDialect -> {
QueryBuilder(false)
.append(" WHERE ").append(it)
.toString()
}
else -> {
exposedLogger.warn("Index creation with a filter condition is not supported in ${currentDialect.name}")
return null
}
}
} else {
null
}
} ?: ""
}

/**
Expand All @@ -1121,7 +1125,7 @@ abstract class VendorDialect(
val quotedIndexName = t.db.identifierManager.cutIfNecessaryAndQuote(index.indexName)
val columnsList = index.columns.joinToString(prefix = "(", postfix = ")") { t.identity(it) }

val maybeFilterCondition = filterCondition(index) ?: ""
val maybeFilterCondition = filterCondition(index) ?: return ""

return when {
// unique and no filter -> constraint, the type is not supported
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -257,7 +257,15 @@ open class SQLServerDialect : VendorDialect(dialectName, SQLServerDataTypeProvid
}

override fun createIndexWithType(name: String, table: String, columns: String, type: String, filterCondition: String): String {
return "CREATE $type INDEX $name ON $table $columns"
return "CREATE $type INDEX $name ON $table $columns$filterCondition"
}

override fun dropIndex(tableName: String, indexName: String, isUnique: Boolean, isPartial: Boolean): String {
return if (isUnique && !isPartial) {
"ALTER TABLE ${identifierManager.quoteIfNecessary(tableName)} DROP CONSTRAINT IF EXISTS ${identifierManager.quoteIfNecessary(indexName)}"
} else {
"DROP INDEX IF EXISTS ${identifierManager.quoteIfNecessary(indexName)} ON ${identifierManager.quoteIfNecessary(tableName)}"
}
}

// https://docs.microsoft.com/en-us/sql/t-sql/language-elements/like-transact-sql?redirectedfrom=MSDN&view=sql-server-ver15#arguments
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -243,6 +243,10 @@ open class SQLiteDialect : VendorDialect(dialectName, SQLiteDataTypeProvider, SQ
}
}

override fun dropIndex(tableName: String, indexName: String, isUnique: Boolean, isPartial: Boolean): String {
return "DROP INDEX IF EXISTS ${identifierManager.quoteIfNecessary(indexName)}"
}

override fun createDatabase(name: String) = "ATTACH DATABASE '${name.lowercase()}.db' AS ${name.inProperCase()}"

override fun dropDatabase(name: String) = "DETACH DATABASE ${name.inProperCase()}"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -2,12 +2,18 @@ package org.jetbrains.exposed.sql.tests.shared.ddl

import org.jetbrains.exposed.dao.id.IntIdTable
import org.jetbrains.exposed.sql.*
import org.jetbrains.exposed.sql.SqlExpressionBuilder.neq
import org.jetbrains.exposed.sql.tests.DatabaseTestsBase
import org.jetbrains.exposed.sql.tests.TestDB
import org.jetbrains.exposed.sql.tests.currentDialectTest
import org.jetbrains.exposed.sql.tests.shared.assertEquals
import org.jetbrains.exposed.sql.tests.shared.assertTrue
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.currentDialect
import org.junit.Test
import kotlin.test.expect

class CreateIndexTests : DatabaseTestsBase() {

Expand Down Expand Up @@ -85,11 +91,10 @@ class CreateIndexTests : DatabaseTestsBase() {


@Test
fun `test partial index`() {
fun testCreateAndDropPartialIndexWithPostgres() {
val partialIndexTable = object : IntIdTable("PartialIndexTableTest") {
val name = varchar("name", 50)
val value = integer("value")
val anotherName = integer("anotherName")
val anotherValue = integer("anotherValue")
val flag = bool("flag")
init {
Expand Down Expand Up @@ -129,8 +134,7 @@ class CreateIndexTests : DatabaseTestsBase() {
kotlin.test.assertEquals(totalIndexCount, 3, "Indexes expected to be created")
}

fun List<Column<*>>.names(): Set<String> { return map { identity(it) }.toSet() }
fun getIndexes(): List<Index> {
fun getIndices(): List<Index> {
db.dialect.resetCaches()
return currentDialect.existingIndices(partialIndexTable)[partialIndexTable].orEmpty()
}
Expand All @@ -142,8 +146,92 @@ class CreateIndexTests : DatabaseTestsBase() {

execInBatch(listOf(dropUniqueConstraint, dropIndex))

assertEquals(getIndexes().size, 1)
assertEquals(getIndices().size, 1)
SchemaUtils.drop(partialIndexTable)
}
}

@Test
fun testCreateAndDropPartialIndex() {
val tester = object : Table("tester") {
val name = varchar("name", 32).uniqueIndex()
val age = integer("age")
val team = varchar("team", 32)

init {
uniqueIndex("team_only_index", team) { team eq "A" }
index("name_age_index", isUnique = false, name, age) { age greaterEq 20 }
}
}

withDb(listOf(TestDB.SQLITE, TestDB.SQLSERVER, TestDB.POSTGRESQLNG, TestDB.POSTGRESQL)) {
SchemaUtils.createMissingTablesAndColumns(tester)
assertTrue(tester.exists())

val createdStatements = tester.indices.map { SchemaUtils.createIndex(it).first() }
assertEquals(3, createdStatements.size)
if (currentDialectTest is SQLiteDialect) {
assertTrue(createdStatements.all { it.startsWith("CREATE ") })
} else {
assertEquals(2, createdStatements.count { it.startsWith("CREATE ") })
assertEquals(1, createdStatements.count { it.startsWith("ALTER TABLE ") })
}

assertEquals(2, tester.indices.count { it.filterCondition != null })

fun getIndices(): List<Index> {
db.dialect.resetCaches()
return currentDialect.existingIndices(tester)[tester].orEmpty()
}

var indices = getIndices()
assertEquals(3, indices.size)

val uniqueWithPartial = Index(listOf(tester.team), true, "team_only_index", null, Op.TRUE).dropStatement().first()
val dropStatements = indices.map { it.dropStatement().first() }
expect(Unit) { execInBatch(dropStatements + uniqueWithPartial) }

indices = getIndices()
assertEquals(0, indices.size)

// test for non-unique partial index with type
val type: String? = when (currentDialectTest) {
is PostgreSQLDialect -> "BTREE"
is SQLServerDialect -> "NONCLUSTERED"
else -> null
}
val typedPartialIndex = Index(
listOf(tester.name), false, "name_only_index", type, tester.name neq "Default"
)
val createdIndex = SchemaUtils.createIndex(typedPartialIndex).single()
assertTrue(createdIndex.startsWith("CREATE "))
assertTrue(" WHERE " in createdIndex)
assertTrue(typedPartialIndex.dropStatement().first().startsWith("DROP INDEX "))

SchemaUtils.drop(tester)
}
}

@Test
fun testPartialIndexNotCreated() {
val tester = object : Table("tester") {
val age = integer("age")

init {
index("age_index", false, age) { age greaterEq 10 }
}
}

withTables(tester) {
SchemaUtils.createMissingTablesAndColumns()
assertTrue(tester.exists())

val expectedIndexCount = when (currentDialectTest) {
is PostgreSQLDialect, is SQLServerDialect, is SQLiteDialect -> 1
else -> 0
}
val actualIndexCount = currentDialectTest.existingIndices(tester)[tester].orEmpty().size
assertEquals(expectedIndexCount, actualIndexCount)
}
}
}