From 8ab74147817197d1aa4e4cfc717e6e86d65f5283 Mon Sep 17 00:00:00 2001 From: bog-walk <82039410+bog-walk@users.noreply.github.com> Date: Tue, 5 Mar 2024 18:32:17 -0500 Subject: [PATCH] feat: EXPOSED-238 Support EXPLAIN statements (#2022) Add ExplainQuery class that processes EXPLAIN statements for all valid wrapped statements. The constructor uses 2 new Transaction properties to ensure that the wrapped statements are not executed and that the internal statements is passed to the invoking instance. Add an ExplainResultRow class so that the explain query can be executed and iterated over in a similar manner to a standard query. This class currently is only good for printing a readable string version of the results and needs getters. Add unit tests. --- exposed-core/api/exposed-core.api | 29 +++ .../org/jetbrains/exposed/sql/ExplainQuery.kt | 118 ++++++++++ .../org/jetbrains/exposed/sql/Queries.kt | 4 +- .../org/jetbrains/exposed/sql/Transaction.kt | 7 + .../exposed/sql/statements/Statement.kt | 9 +- .../exposed/sql/vendors/FunctionProvider.kt | 29 +++ .../org/jetbrains/exposed/sql/vendors/H2.kt | 12 ++ .../exposed/sql/vendors/MariaDBDialect.kt | 21 +- .../exposed/sql/vendors/OracleDialect.kt | 11 + .../exposed/sql/vendors/PostgreSQL.kt | 15 ++ .../exposed/sql/vendors/SQLServerDialect.kt | 11 + .../exposed/sql/vendors/SQLiteDialect.kt | 13 ++ .../sql/tests/shared/dml/ExplainTests.kt | 201 ++++++++++++++++++ 13 files changed, 470 insertions(+), 10 deletions(-) create mode 100644 exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/ExplainQuery.kt create mode 100644 exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/ExplainTests.kt diff --git a/exposed-core/api/exposed-core.api b/exposed-core/api/exposed-core.api index 722e0613c3..70f64567c1 100644 --- a/exposed-core/api/exposed-core.api +++ b/exposed-core/api/exposed-core.api @@ -783,6 +783,33 @@ public abstract interface annotation class org/jetbrains/exposed/sql/Experimenta public abstract interface annotation class org/jetbrains/exposed/sql/ExperimentalKeywordApi : java/lang/annotation/Annotation { } +public class org/jetbrains/exposed/sql/ExplainQuery : org/jetbrains/exposed/sql/statements/Statement, java/lang/Iterable, kotlin/jvm/internal/markers/KMappedMarker { + public fun (ZLjava/lang/String;Lorg/jetbrains/exposed/sql/statements/Statement;)V + public fun arguments ()Ljava/lang/Iterable; + public synthetic fun executeInternal (Lorg/jetbrains/exposed/sql/statements/api/PreparedStatementApi;Lorg/jetbrains/exposed/sql/Transaction;)Ljava/lang/Object; + public fun executeInternal (Lorg/jetbrains/exposed/sql/statements/api/PreparedStatementApi;Lorg/jetbrains/exposed/sql/Transaction;)Ljava/sql/ResultSet; + public final fun getAnalyze ()Z + public final fun getOptions ()Ljava/lang/String; + public fun iterator ()Ljava/util/Iterator; + public fun prepareSQL (Lorg/jetbrains/exposed/sql/Transaction;Z)Ljava/lang/String; +} + +public final class org/jetbrains/exposed/sql/ExplainQueryKt { + public static final fun explain (Lorg/jetbrains/exposed/sql/Transaction;ZLjava/lang/String;Lkotlin/jvm/functions/Function1;)Lorg/jetbrains/exposed/sql/ExplainQuery; + public static synthetic fun explain$default (Lorg/jetbrains/exposed/sql/Transaction;ZLjava/lang/String;Lkotlin/jvm/functions/Function1;ILjava/lang/Object;)Lorg/jetbrains/exposed/sql/ExplainQuery; +} + +public final class org/jetbrains/exposed/sql/ExplainResultRow { + public static final field Companion Lorg/jetbrains/exposed/sql/ExplainResultRow$Companion; + public fun (Ljava/util/Map;[Ljava/lang/Object;)V + public final fun getFieldIndex ()Ljava/util/Map; + public fun toString ()Ljava/lang/String; +} + +public final class org/jetbrains/exposed/sql/ExplainResultRow$Companion { + public final fun create (Ljava/sql/ResultSet;Ljava/util/Map;)Lorg/jetbrains/exposed/sql/ExplainResultRow; +} + public abstract class org/jetbrains/exposed/sql/Expression { public static final field Companion Lorg/jetbrains/exposed/sql/Expression$Companion; public fun ()V @@ -3532,6 +3559,7 @@ public abstract class org/jetbrains/exposed/sql/vendors/FunctionProvider { public fun ()V protected final fun appendInsertToUpsertClause (Lorg/jetbrains/exposed/sql/QueryBuilder;Lorg/jetbrains/exposed/sql/Table;Ljava/util/List;Lorg/jetbrains/exposed/sql/Transaction;)V protected final fun appendJoinPartForUpdateClause (Lorg/jetbrains/exposed/sql/QueryBuilder;Lorg/jetbrains/exposed/sql/Table;Lorg/jetbrains/exposed/sql/Join;Lorg/jetbrains/exposed/sql/Transaction;)V + protected fun appendOptionsToExplain (Ljava/lang/StringBuilder;Ljava/lang/String;)V protected final fun appendUpdateToUpsertClause (Lorg/jetbrains/exposed/sql/QueryBuilder;Lorg/jetbrains/exposed/sql/Table;Ljava/util/List;Ljava/util/List;Lorg/jetbrains/exposed/sql/Transaction;Z)V public fun arraySlice (Lorg/jetbrains/exposed/sql/Expression;Ljava/lang/Integer;Ljava/lang/Integer;Lorg/jetbrains/exposed/sql/QueryBuilder;)V public fun cast (Lorg/jetbrains/exposed/sql/Expression;Lorg/jetbrains/exposed/sql/IColumnType;Lorg/jetbrains/exposed/sql/QueryBuilder;)V @@ -3539,6 +3567,7 @@ public abstract class org/jetbrains/exposed/sql/vendors/FunctionProvider { public fun concat (Ljava/lang/String;Lorg/jetbrains/exposed/sql/QueryBuilder;[Lorg/jetbrains/exposed/sql/Expression;)V public fun day (Lorg/jetbrains/exposed/sql/Expression;Lorg/jetbrains/exposed/sql/QueryBuilder;)V public fun delete (ZLorg/jetbrains/exposed/sql/Table;Ljava/lang/String;Ljava/lang/Integer;Lorg/jetbrains/exposed/sql/Transaction;)Ljava/lang/String; + public fun explain (ZLjava/lang/String;Ljava/lang/String;Lorg/jetbrains/exposed/sql/Transaction;)Ljava/lang/String; public fun getDEFAULT_VALUE_EXPRESSION ()Ljava/lang/String; protected final fun getKeyColumnsForUpsert (Lorg/jetbrains/exposed/sql/Table;[Lorg/jetbrains/exposed/sql/Column;)Ljava/util/List; protected final fun getUpdateColumnsForUpsert (Ljava/util/List;Ljava/util/List;Ljava/util/List;)Ljava/util/List; diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/ExplainQuery.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/ExplainQuery.kt new file mode 100644 index 0000000000..2b80034ef7 --- /dev/null +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/ExplainQuery.kt @@ -0,0 +1,118 @@ +package org.jetbrains.exposed.sql + +import org.jetbrains.exposed.sql.statements.Statement +import org.jetbrains.exposed.sql.statements.StatementType +import org.jetbrains.exposed.sql.statements.api.PreparedStatementApi +import org.jetbrains.exposed.sql.transactions.TransactionManager +import java.sql.ResultSet + +/** + * Represents the SQL query that obtains information about a statement execution plan. + * + * @param analyze Whether the statement whose execution plan is being queried should actually be executed as well. + * @param options String of comma-separated parameters to append after the `EXPLAIN` keyword. + */ +open class ExplainQuery( + val analyze: Boolean, + val options: String?, + private val internalStatement: Statement<*> +) : Iterable, Statement(StatementType.SHOW, emptyList()) { + private val transaction + get() = TransactionManager.current() + + override fun PreparedStatementApi.executeInternal(transaction: Transaction): ResultSet = executeQuery() + + override fun arguments(): Iterable>> = internalStatement.arguments() + + override fun prepareSQL(transaction: Transaction, prepared: Boolean): String { + val internalSql = internalStatement.prepareSQL(transaction, prepared) + return transaction.db.dialect.functionProvider.explain(analyze, options, internalSql, transaction) + } + + override fun iterator(): Iterator { + val resultIterator = ResultIterator(transaction.exec(this)!!) + return Iterable { resultIterator }.iterator() + } + + private inner class ResultIterator(private val rs: ResultSet) : Iterator { + private val fieldIndex: Map = List(rs.metaData.columnCount) { i -> + rs.metaData.getColumnName(i + 1) to i + }.toMap() + + private var hasNext = false + set(value) { + field = value + if (!field) { + rs.statement?.close() + transaction.openResultSetsCount-- + } + } + + init { + hasNext = rs.next() + } + + override fun hasNext(): Boolean = hasNext + + override operator fun next(): ExplainResultRow { + if (!hasNext) throw NoSuchElementException() + val result = ExplainResultRow.create(rs, fieldIndex) + hasNext = rs.next() + return result + } + } +} + +/** + * A row of data representing a single record retrieved from a database result set about a statement execution plan. + * + * @param fieldIndex Mapping of the field names stored on this row to their index positions. + */ +class ExplainResultRow( + val fieldIndex: Map, + private val data: Array +) { + override fun toString(): String = fieldIndex.entries.joinToString { "${it.key}=${data[it.value]}" } + + companion object { + /** Creates an [ExplainResultRow] storing all fields in [fieldIndex] with their values retrieved from a [ResultSet]. */ + fun create(rs: ResultSet, fieldIndex: Map): ExplainResultRow { + val fieldValues = arrayOfNulls(fieldIndex.size) + fieldIndex.values.forEach { index -> + fieldValues[index] = rs.getObject(index + 1) + } + return ExplainResultRow(fieldIndex, fieldValues) + } + } +} + +/** +* Creates an [ExplainQuery] using the `EXPLAIN` keyword, which obtains information about a statement execution plan. +* +* **Note:** This operation is not supported by all vendors, please check the documentation. +* +* @param analyze (optional) Whether the statement whose execution plan is being queried should actually be executed as well. +* **Note:** The `ANALYZE` parameter is not supported by all vendors, please check the documentation. +* @param options (optional) String of comma-separated parameters to append after the `EXPLAIN` keyword. +* **Note:** Optional parameters are not supported by all vendors, please check the documentation. +* @param body The statement for which an execution plan should be queried. This can be a `SELECT`, `INSERT`, + * `REPLACE`, `UPDATE` or `DELETE` statement. +* @sample org.jetbrains.exposed.sql.tests.shared.dml.ExplainTests.testExplainWithStatementsNotExecuted +*/ +fun Transaction.explain( + analyze: Boolean = false, + options: String? = null, + body: Transaction.() -> Any? +): ExplainQuery { + val query = try { + blockStatementExecution = true + val internalStatement = body() as? Statement<*> ?: explainStatement + checkNotNull(internalStatement) { "A valid query or statement must be provided to the EXPLAIN body." } + ExplainQuery(analyze, options, internalStatement) + } finally { + explainStatement = null + blockStatementExecution = false + } + + return query +} diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Queries.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Queries.kt index 8b4a277d87..e752cf661d 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Queries.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Queries.kt @@ -392,7 +392,7 @@ fun T.insertIgnore( fun T.update(where: (SqlExpressionBuilder.() -> Op)? = null, limit: Int? = null, body: T.(UpdateStatement) -> Unit): Int { val query = UpdateStatement(this, limit, where?.let { SqlExpressionBuilder.it() }) body(query) - return query.execute(TransactionManager.current())!! + return query.execute(TransactionManager.current()) ?: 0 } /** @@ -406,7 +406,7 @@ fun T.update(where: (SqlExpressionBuilder.() -> Op)? = null fun Join.update(where: (SqlExpressionBuilder.() -> Op)? = null, limit: Int? = null, body: (UpdateStatement) -> Unit): Int { val query = UpdateStatement(this, limit, where?.let { SqlExpressionBuilder.it() }) body(query) - return query.execute(TransactionManager.current())!! + return query.execute(TransactionManager.current()) ?: 0 } /** diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Transaction.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Transaction.kt index 730593125b..820d86877a 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Transaction.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Transaction.kt @@ -85,6 +85,13 @@ open class Transaction( /** The currently executing statement. */ var currentStatement: PreparedStatementApi? = null + + /** The current statement for which an execution plan should be queried, but which should never itself be executed. */ + internal var explainStatement: Statement<*>? = null + + /** Whether this [Transaction] should prevent any statement execution from proceeding. */ + internal var blockStatementExecution: Boolean = false + internal val executedStatements: MutableList = arrayListOf() internal var openResultSetsCount: Int = 0 diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/statements/Statement.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/statements/Statement.kt index 70fb63b73f..c8ea1b52bc 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/statements/Statement.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/statements/Statement.kt @@ -50,9 +50,14 @@ abstract class Statement(val type: StatementType, val targets: List> { val arguments = arguments() diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/FunctionProvider.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/FunctionProvider.kt index c300394f9a..887b457f66 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/FunctionProvider.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/FunctionProvider.kt @@ -714,4 +714,33 @@ abstract class FunctionProvider { append(" OFFSET $offset") } } + + /** + * Returns the SQL command that obtains information about a statement execution plan. + * + * @param analyze Whether [internalStatement] should also be executed. + * @param options Optional string of comma-separated parameters specific to the database. + * @param internalStatement SQL string representing the statement to get information about. + * @param transaction Transaction where the operation is executed. + */ + open fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + return buildString { + append("EXPLAIN ") + if (analyze) { + append("ANALYZE ") + } + options?.let { + appendOptionsToExplain(it) + } + append(internalStatement) + } + } + + /** Appends optional parameters to an EXPLAIN query. */ + protected open fun StringBuilder.appendOptionsToExplain(options: String) { append("$options ") } } diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt index 33da261dee..f60a323200 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt @@ -123,6 +123,18 @@ internal object H2FunctionProvider : FunctionProvider() { ) = queryBuilder { append("LOCATE(\'", substring, "\',", expr, ")") } + + override fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + if (options != null) { + transaction.throwUnsupportedException("H2 does not support options other than ANALYZE in EXPLAIN queries.") + } + return super.explain(analyze, null, internalStatement, transaction) + } } /** diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/MariaDBDialect.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/MariaDBDialect.kt index 74f1eeb434..9301742d3f 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/MariaDBDialect.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/MariaDBDialect.kt @@ -1,11 +1,6 @@ package org.jetbrains.exposed.sql.vendors -import org.jetbrains.exposed.sql.Expression -import org.jetbrains.exposed.sql.Index -import org.jetbrains.exposed.sql.QueryBuilder -import org.jetbrains.exposed.sql.Sequence -import org.jetbrains.exposed.sql.append -import org.jetbrains.exposed.sql.exposedLogger +import org.jetbrains.exposed.sql.* internal object MariaDBFunctionProvider : MysqlFunctionProvider() { override fun nextVal(seq: Sequence, builder: QueryBuilder) = builder { @@ -28,6 +23,20 @@ internal object MariaDBFunctionProvider : MysqlFunctionProvider() { ) = queryBuilder { append("LOCATE(\'", substring, "\',", expr, ")") } + + override fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + val sql = super.explain(analyze, options, internalStatement, transaction) + return if (analyze) { + sql.substringAfter("EXPLAIN ") + } else { + sql + } + } } /** diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/OracleDialect.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/OracleDialect.kt index 5f56a4e33e..a85d4801a5 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/OracleDialect.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/OracleDialect.kt @@ -301,6 +301,17 @@ internal object OracleFunctionProvider : FunctionProvider() { override fun queryLimit(size: Int, offset: Long, alreadyOrdered: Boolean): String { return (if (offset > 0) " OFFSET $offset ROWS" else "") + " FETCH FIRST $size ROWS ONLY" } + + override fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + transaction.throwUnsupportedException( + "EXPLAIN queries are not currently supported for Oracle. Please log a YouTrack feature extension request." + ) + } } /** diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/PostgreSQL.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/PostgreSQL.kt index bee5325120..5f56a4a791 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/PostgreSQL.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/PostgreSQL.kt @@ -305,6 +305,21 @@ internal object PostgreSQLFunctionProvider : FunctionProvider() { } return super.delete(ignore, table, where, limit, transaction) } + + override fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + return if (analyze && options != null) { + super.explain(false, "ANALYZE TRUE, $options", internalStatement, transaction) + } else { + super.explain(analyze, options, internalStatement, transaction) + } + } + + override fun StringBuilder.appendOptionsToExplain(options: String) { append("($options) ") } } /** diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt index 6cc09d52bc..7b6e3aadca 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt @@ -233,6 +233,17 @@ internal object SQLServerFunctionProvider : FunctionProvider() { override fun queryLimit(size: Int, offset: Long, alreadyOrdered: Boolean): String { return (if (alreadyOrdered) "" else " ORDER BY(SELECT NULL)") + " OFFSET $offset ROWS FETCH NEXT $size ROWS ONLY" } + + override fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + transaction.throwUnsupportedException( + "EXPLAIN queries are not currently supported for SQL Server. Please log a YouTrack feature extension request." + ) + } } /** diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt index 7539e578b8..1efb27acab 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt @@ -239,6 +239,19 @@ internal object SQLiteFunctionProvider : FunctionProvider() { } return super.delete(ignore, table, where, limit, transaction) } + + override fun explain( + analyze: Boolean, + options: String?, + internalStatement: String, + transaction: Transaction + ): String { + if (analyze || options != null) { + transaction.throwUnsupportedException("SQLite does not support ANALYZE or other options in EXPLAIN queries.") + } + val sql = super.explain(false, null, internalStatement, transaction) + return sql.replaceFirst("EXPLAIN ", "EXPLAIN QUERY PLAN ") + } } /** diff --git a/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/ExplainTests.kt b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/ExplainTests.kt new file mode 100644 index 0000000000..40274e4643 --- /dev/null +++ b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/ExplainTests.kt @@ -0,0 +1,201 @@ +package org.jetbrains.exposed.sql.tests.shared.dml + +import org.jetbrains.exposed.dao.id.IntIdTable +import org.jetbrains.exposed.sql.* +import org.jetbrains.exposed.sql.SqlExpressionBuilder.eq +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.tests.shared.expectException +import org.jetbrains.exposed.sql.vendors.H2Dialect +import org.jetbrains.exposed.sql.vendors.MysqlDialect +import org.jetbrains.exposed.sql.vendors.SQLiteDialect +import org.junit.Test + +class ExplainTests : DatabaseTestsBase() { + private val explainUnsupportedDb = listOf(TestDB.SQLSERVER, TestDB.H2_SQLSERVER, TestDB.ORACLE, TestDB.H2_ORACLE) + + private object Countries : IntIdTable("countries") { + val code = varchar("country_code", 8) + } + + @Test + fun testExplainWithStatementsNotExecuted() { + withTables(excludeSettings = explainUnsupportedDb, Countries) { + val originalCode = "ABC" + + // any statements with explain should not be executed + explain { Countries.insert { it[code] = originalCode } }.toList() + assertTrue(Countries.selectAll().empty()) + + Countries.insert { it[code] = originalCode } + assertEquals(1, Countries.selectAll().count()) + + explain { Countries.update { it[code] = "DEF" } }.toList() + assertEquals(originalCode, Countries.selectAll().single()[Countries.code]) + + explain { Countries.deleteAll() }.toList() + assertEquals(1, Countries.selectAll().count()) + + Countries.deleteAll() + assertTrue(Countries.selectAll().empty()) + } + } + + @Test + fun testExplainWithAllValidStatementsNotExecuted() { + var explainCount = 0 + val cityName = "City A" + + fun Transaction.explainAndIncrement(body: Transaction.() -> Any?) = explain(body = body).also { + it.toList() // as with select queries, explain is only executed when iterated over + explainCount++ + } + + withCitiesAndUsers(exclude = explainUnsupportedDb) { cities, users, userData -> + val testDb = currentDialectTest + debug = true + statementCount = 0 + + // select statements + explainAndIncrement { + cities.select(cities.id).where { cities.name like "A%" } + } + explainAndIncrement { + (users innerJoin cities) + .select(users.name, cities.name) + .where { (users.id.eq("andrey") or users.name.eq("sergey")) and users.cityId.eq(cities.id) } + } + explainAndIncrement { + val query1 = users.selectAll().where { users.id eq "andrey" } + val query2 = users.selectAll().where { users.id eq "sergey" } + query1.union(query2).limit(1) + } + // insert statements + explainAndIncrement { cities.insert { it[name] = cityName } } + val subquery = userData.select(userData.user_id, userData.comment, intParam(42)) + explainAndIncrement { userData.insert(subquery) } + // insert or... statements + if (testDb !is H2Dialect) { + explainAndIncrement { cities.insertIgnore { it[name] = cityName } } + explainAndIncrement { userData.insertIgnore(subquery) } + } + if (testDb is MysqlDialect || testDb is SQLiteDialect) { + explainAndIncrement { cities.replace { it[name] = cityName } } + } + explainAndIncrement { + cities.upsert { + it[id] = 1 + it[name] = cityName + } + } + // update statements + explainAndIncrement { cities.update { it[name] = cityName } } + if (testDb !is SQLiteDialect) { + explainAndIncrement { + val join = users.innerJoin(userData) + join.update { it[userData.value] = 123 } + } + } + // delete statements + explainAndIncrement { cities.deleteWhere { cities.id eq 1 } } + if (testDb is MysqlDialect) { + explainAndIncrement { cities.deleteIgnoreWhere { cities.id eq 1 } } + } + explainAndIncrement { cities.deleteAll() } + + assertEquals(explainCount, statementCount) + assertTrue(statementStats.keys.all { it.startsWith("EXPLAIN ") }) + + debug = false + } + } + + @Test + fun testExplainWithAnalyze() { + val noAnalyzeDb = explainUnsupportedDb + TestDB.SQLITE + withTables(excludeSettings = noAnalyzeDb, Countries) { testDb -> + if (!isOldMySql()) { + val originalCode = "ABC" + + // MySQL only allows ANALYZE with SELECT queries + if (testDb != TestDB.MYSQL) { + // analyze means all wrapped statements should also be executed + explain(analyze = true) { Countries.insert { it[code] = originalCode } }.toList() + assertEquals(1, Countries.selectAll().count()) + + explain(analyze = true) { Countries.update { it[code] = "DEF" } }.toList() + assertEquals("DEF", Countries.selectAll().single()[Countries.code]) + + explain(analyze = true) { Countries.deleteAll() }.toList() + assertTrue(Countries.selectAll().empty()) + } + + explain(analyze = true) { Countries.selectAll() }.toList() + } + } + } + + @Test + fun testExplainWithOptions() { + val optionsAvailableDb = TestDB.postgreSQLRelatedDB.toSet() + TestDB.MYSQL + TestDB.MARIADB + withTables(excludeSettings = TestDB.entries - optionsAvailableDb, Countries) { testDB -> + if (!isOldMySql()) { + val formatOption = when (testDB) { + in TestDB.mySqlRelatedDB -> "FORMAT=JSON" + in TestDB.postgreSQLRelatedDB -> "FORMAT JSON" + else -> throw UnsupportedOperationException("Format option not provided for this dialect") + } + + val query = Countries.select(Countries.id).where { Countries.code like "A%" } + val result = explain(options = formatOption) { query }.single() + val jsonString = result.toString().substringAfter("=") + when (testDB) { + in TestDB.mySqlRelatedDB -> assertTrue(jsonString.startsWith('{') && jsonString.endsWith('}')) + else -> assertTrue(jsonString.startsWith('[') && jsonString.endsWith(']')) + } + + // test multiple options only + if (testDB in TestDB.postgreSQLRelatedDB) { + explain(options = "VERBOSE TRUE, COSTS FALSE") { query }.toList() + } + + // test analyze + options + val combinedOption = if (testDB == TestDB.MYSQL) "FORMAT=TREE" else formatOption + explain(true, combinedOption) { query }.toList() + } + } + } + + @Test + fun testExplainWithInvalidStatements() { + withTables(excludeSettings = explainUnsupportedDb, Countries) { + expectException { + explain { Countries.insertAndGetId { it[code] = "ABC" } } + } + expectException { + explain { + Countries.selectAll() + "Last line in lambda should be expected return value - statement" + } + } + + debug = true + statementCount = 0 + + // only the last statement will be executed with explain + explain { + Countries.deleteAll() + Countries.selectAll() + }.toList() + + assertEquals(1, statementCount) + val executed = statementStats.keys.single() + assertTrue(executed.startsWith("EXPLAIN ") && "SELECT " in executed && "DELETE " !in executed) + + debug = false + } + } +}