diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/AbstractQuery.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/AbstractQuery.kt index 1552559be5..fe71d3d20a 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/AbstractQuery.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/AbstractQuery.kt @@ -10,8 +10,7 @@ abstract class AbstractQuery>(targets: List) : Sized var orderByExpressions: List, SortOrder>> = mutableListOf() private set - var distinct: Boolean = false - protected set + var limit: Int? = null protected set var offset: Long = 0 @@ -23,7 +22,6 @@ abstract class AbstractQuery>(targets: List
) : Sized protected fun copyTo(other: AbstractQuery) { other.orderByExpressions = orderByExpressions.toMutableList() - other.distinct = distinct other.limit = limit other.offset = offset other.fetchSize = fetchSize @@ -38,9 +36,7 @@ abstract class AbstractQuery>(targets: List
) : Sized if (it.args.isNotEmpty()) listOf(it.args) else emptyList() } - fun withDistinct(value: Boolean = true): T = apply { - distinct = value - } as T + abstract fun withDistinct(value: Boolean = true): T override fun limit(n: Int, offset: Long): T = apply { limit = n diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Query.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Query.kt index 8671500db2..86cbfaecb1 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Query.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Query.kt @@ -16,6 +16,8 @@ enum class SortOrder(val code: String) { } open class Query(override var set: FieldSet, where: Op?) : AbstractQuery(set.source.targetTables()) { + var distinct: Boolean = false + protected set var groupedByColumns: List> = mutableListOf() private set @@ -39,6 +41,7 @@ open class Query(override var set: FieldSet, where: Op?) : AbstractQuer override fun copy(): Query = Query(set, where).also { copy -> copyTo(copy) + copy.distinct = distinct copy.groupedByColumns = groupedByColumns.toMutableList() copy.having = having copy.forUpdate = forUpdate @@ -49,6 +52,10 @@ open class Query(override var set: FieldSet, where: Op?) : AbstractQuer return this } + override fun withDistinct(value: Boolean): Query = apply { + distinct = value + } + override fun notForUpdate(): Query { forUpdate = false return this diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/SetOperations.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/SetOperations.kt new file mode 100644 index 0000000000..36b1884517 --- /dev/null +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/SetOperations.kt @@ -0,0 +1,170 @@ +package org.jetbrains.exposed.sql + +import org.jetbrains.exposed.exceptions.UnsupportedByDialectException +import org.jetbrains.exposed.sql.statements.Statement +import org.jetbrains.exposed.sql.statements.api.PreparedStatementApi +import org.jetbrains.exposed.sql.vendors.MariaDBDialect +import org.jetbrains.exposed.sql.vendors.MysqlDialect +import org.jetbrains.exposed.sql.vendors.currentDialect +import java.sql.ResultSet + +sealed class SetOperation( + val operationName: String, + val firstStatement: AbstractQuery<*>, + val secondStatement: AbstractQuery<*> +) : AbstractQuery((firstStatement.targets + secondStatement.targets).distinct()) { + val rawStatements: List> = listOf(firstStatement, secondStatement) + init { + require(rawStatements.isNotEmpty()) { "$operationName is empty" } + require(rawStatements.none { it is Query && it.isForUpdate() }) { "FOR UPDATE is not allowed within $operationName" } + require(rawStatements.map { it.set.realFields.size }.distinct().size == 1) { + "Each $operationName query must have the same number of columns" + } + if (!currentDialect.supportsSubqueryUnions) { + require(rawStatements.none { (it as AbstractQuery<*>).let { q -> q.orderByExpressions.isNotEmpty() || q.limit != null } }) { + "$operationName may not contain subqueries" + } + } + } + + override val set: FieldSet = firstStatement.set + + override val queryToExecute: Statement = this + + override fun count(): Long { + try { + count = true + return transaction.exec(this) { rs -> + rs.next() + rs.getLong(1).also { + rs.close() + } + }!! + } finally { + count = false + } + } + + override fun empty(): Boolean { + val oldLimit = limit + try { + limit = 1 + val rs = transaction.exec(this)!! + return !rs.next().also { rs.close() } + } finally { + limit = oldLimit + } + } + + override fun PreparedStatementApi.executeInternal(transaction: Transaction): ResultSet = executeQuery() + + override fun prepareSQL(builder: QueryBuilder): String { + builder { + if (count) append("SELECT COUNT(*) FROM (") + + prepareStatementSQL(this) + + if (orderByExpressions.isNotEmpty()) { + append(" ORDER BY ") + orderByExpressions.appendTo { + append((it.first as? ExpressionAlias<*>)?.alias ?: it.first, " ", it.second.name) + } + } + + limit?.let { + append(" ") + append(currentDialect.functionProvider.queryLimit(it, offset, true)) + } + + if (count) append(") subquery") + } + return builder.toString() + } + + protected open fun prepareStatementSQL(builder: QueryBuilder) { + builder { + rawStatements.appendTo(separator = " $operationName ") { + when (it) { + is Query -> { + val isSubQuery = it.orderByExpressions.isNotEmpty() || it.limit != null + if (isSubQuery) append("(") + it.prepareSQL(this) + if (isSubQuery) append(")") + } + is SetOperation -> it.prepareSQL(this) + } + } + } + } +} + +class Union(firstStatement: AbstractQuery<*>, secondStatement: AbstractQuery<*>) : SetOperation("UNION", firstStatement, secondStatement) { + override fun withDistinct(value: Boolean): SetOperation { + return if (!value) { + UnionAll(firstStatement, secondStatement).also { + copyTo(it) + } + } else { + this + } + } + + override fun copy() = Union(firstStatement, secondStatement).also { + copyTo(it) + } +} + +class UnionAll(firstStatement: AbstractQuery<*>, secondStatement: AbstractQuery<*>) : SetOperation("UNION ALL", firstStatement, secondStatement) { + + override fun withDistinct(value: Boolean): SetOperation { + return if (value) { + Union(firstStatement, secondStatement) + } else { + this + } + } + + override fun copy() = UnionAll(firstStatement, secondStatement).also { + copyTo(it) + } +} + +class Intersect(firstStatement: AbstractQuery<*>, secondStatement: AbstractQuery<*>) : SetOperation("INTERSECT", firstStatement, secondStatement) { + override fun copy() = Intersect(firstStatement, secondStatement).also { + copyTo(it) + } + + override fun withDistinct(value: Boolean): SetOperation = this + + override fun prepareStatementSQL(builder: QueryBuilder) { + if (currentDialect is MysqlDialect && currentDialect !is MariaDBDialect) { + throw UnsupportedByDialectException("$operationName is unsupported", currentDialect) + } else { + super.prepareStatementSQL(builder) + } + } +} + +class Except(firstStatement: AbstractQuery<*>, secondStatement: AbstractQuery<*>) : SetOperation("EXCEPT", firstStatement, secondStatement) { + override fun copy() = Intersect(firstStatement, secondStatement).also { + copyTo(it) + } + + override fun withDistinct(value: Boolean): SetOperation = this + + override fun prepareStatementSQL(builder: QueryBuilder) { + if (currentDialect is MysqlDialect && currentDialect !is MariaDBDialect) { + throw UnsupportedByDialectException("$operationName is unsupported", currentDialect) + } else { + super.prepareStatementSQL(builder) + } + } +} + +fun AbstractQuery<*>.union(other: Query): Union = Union(this, other) + +fun AbstractQuery<*>.unionAll(other: Query): UnionAll = UnionAll(this, other) + +fun AbstractQuery<*>.intersect(other: Query): Intersect = Intersect(this, other) + +fun AbstractQuery<*>.except(other: Query): Except = Except(this, other) diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Union.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Union.kt deleted file mode 100644 index 92b7d8bd5e..0000000000 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Union.kt +++ /dev/null @@ -1,107 +0,0 @@ -package org.jetbrains.exposed.sql - -import org.jetbrains.exposed.sql.statements.Statement -import org.jetbrains.exposed.sql.statements.api.PreparedStatementApi -import org.jetbrains.exposed.sql.vendors.currentDialect -import java.sql.ResultSet - -class Union( - unionAll: Boolean, - vararg rawStatements: Statement, -) : AbstractQuery(rawStatements.flatMap { it.targets }.distinct()) { - init { - require(rawStatements.isNotEmpty()) { "UNION is empty" } - require(rawStatements.none { it is Query && it.isForUpdate() }) { "FOR UPDATE is not allowed within UNION" } - require(rawStatements.all { it is AbstractQuery<*> }) { "Only Query or Union supported as statements for UNION" } - require(rawStatements.map { (it as AbstractQuery<*>).set.realFields.size }.distinct().size == 1) { - "Each UNION query must have the same number of columns" - } - if (!currentDialect.supportsSubqueryUnions) { - require(rawStatements.none { (it as AbstractQuery<*>).let { q -> q.orderByExpressions.isNotEmpty() || q.limit != null } }) { - "UNION may not contain subqueries" - } - } - distinct = !unionAll - } - - internal val statements = rawStatements.filterIsInstance>().toTypedArray() - - override val set: FieldSet = statements.first().set - - override val queryToExecute: Statement = this - - private val unionKeyword: String get() = if (distinct) "UNION" else "UNION ALL" - - override fun copy() = Union(distinct, rawStatements = statements).also { - copyTo(it) - } - - override fun count(): Long { - try { - count = true - return transaction.exec(this) { - it.next() - it.getLong(1) - }!! - } finally { - count = false - } - } - - override fun empty(): Boolean { - val oldLimit = limit - try { - limit = 1 - return !transaction.exec(this)!!.next() - } finally { - limit = oldLimit - } - } - - override fun PreparedStatementApi.executeInternal(transaction: Transaction): ResultSet = executeQuery() - - override fun prepareSQL(builder: QueryBuilder): String { - builder { - if (count) append("SELECT COUNT(*) FROM (") - - prepareStatementSQL(this) - - if (orderByExpressions.isNotEmpty()) { - append(" ORDER BY ") - orderByExpressions.appendTo { - append((it.first as? ExpressionAlias<*>)?.alias ?: it.first, " ", it.second.name) - } - } - - limit?.let { - append(" ") - append(currentDialect.functionProvider.queryLimit(it, offset, true)) - } - - if (count) append(") subquery") - } - return builder.toString() - } - - private fun prepareStatementSQL(builder: QueryBuilder) { - builder { - statements.appendTo(separator = " $unionKeyword ") { - when (it) { - is Query -> { - val isSubQuery = it.orderByExpressions.isNotEmpty() || it.limit != null - if (isSubQuery) append("(") - it.prepareSQL(this) - if (isSubQuery) append(")") - } - is Union -> it.prepareSQL(this) - } - } - } - } -} - -fun Query.union(other: Query) = Union(unionAll = false, this, other) - -fun Query.unionAll(other: Query) = Union(unionAll = true, this, other) - -fun Union.union(other: Query) = Union(!distinct, *statements, other) diff --git a/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/UnionTests.kt b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/UnionTests.kt index 37cdac6d1d..010ba69841 100644 --- a/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/UnionTests.kt +++ b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/UnionTests.kt @@ -3,6 +3,7 @@ package org.jetbrains.exposed.sql.tests.shared.dml import org.jetbrains.exposed.sql.* import org.jetbrains.exposed.sql.tests.DatabaseTestsBase import org.jetbrains.exposed.sql.tests.TestDB +import org.jetbrains.exposed.sql.tests.shared.assertEqualCollections import org.jetbrains.exposed.sql.vendors.currentDialect import org.junit.Test import kotlin.test.assertEquals @@ -72,6 +73,58 @@ class UnionTests : DatabaseTestsBase() { } } + @Test + fun `test intersection of three queries`() { + withCitiesAndUsers(listOf(TestDB.MYSQL)) { _, users, _ -> + val usersQuery = users.selectAll() + val sergeyQuery = users.select { users.id eq "sergey" } + usersQuery.unionAll(usersQuery).intersect(sergeyQuery).map { it[users.id] }.apply { + assertEquals(1, size) + assertTrue(containsAll(listOf("sergey"))) + } + } + } + + @Test + fun `test except of two queries`() { + withCitiesAndUsers(listOf(TestDB.MYSQL)) { _, users, _ -> + val usersQuery = users.selectAll() + val expectedUsers = usersQuery.map { it[users.id] } - "sergey" + val sergeyQuery = users.select { users.id eq "sergey" } + usersQuery.except(sergeyQuery).map { it[users.id] }.apply { + assertEquals(4, size) + assertEqualCollections(expectedUsers, this) + } + } + } + + @Test + fun `test except of three queries`() { + withCitiesAndUsers(listOf(TestDB.MYSQL)) { _, users, _ -> + val usersQuery = users.selectAll() + val expectedUsers = usersQuery.map { it[users.id] } - "sergey" + val sergeyQuery = users.select { users.id eq "sergey" } + usersQuery.unionAll(usersQuery).except(sergeyQuery).map { it[users.id] }.apply { + assertEquals(4, size) + assertEqualCollections(expectedUsers, this) + } + } + } + + @Test + fun `test except of two excepts queries`() { + withCitiesAndUsers(listOf(TestDB.MYSQL)) { _, users, _ -> + val usersQuery = users.selectAll() + val expectedUsers = usersQuery.map { it[users.id] } - "sergey" - "andrey" + val sergeyQuery = users.select { users.id eq "sergey" } + val andreyQuery = users.select { users.id eq "andrey" } + usersQuery.except(sergeyQuery).except(andreyQuery).map { it[users.id] }.apply { + assertEquals(3, size) + assertEqualCollections(expectedUsers, this) + } + } + } + @Test fun `test union of more than two queries`() { withCitiesAndUsers { _, users, _ -> @@ -165,7 +218,7 @@ class UnionTests : DatabaseTestsBase() { fun `test union with all results of three queries`() { withCitiesAndUsers { _, users, _ -> val andreyQuery = users.select { users.id eq "andrey" } - andreyQuery.unionAll(andreyQuery).union(andreyQuery).map { it[users.id] }.apply { + andreyQuery.unionAll(andreyQuery).unionAll(andreyQuery).map { it[users.id] }.apply { assertEquals(List(3) { "andrey" }, this) } }