Skip to content

Commit

Permalink
feat: EXPOSED-560 Support DISTINCT ON from Postgres (#2275)
Browse files Browse the repository at this point in the history
* feat: EXPOSED-560 Support DISTINCT ON from Postgres
---------

Co-authored-by: Jocelyne <[email protected]>
  • Loading branch information
obabichevjb and joc-a authored Oct 30, 2024
1 parent c5c5c7b commit 9f3396c
Show file tree
Hide file tree
Showing 4 changed files with 179 additions and 1 deletion.
Original file line number Diff line number Diff line change
Expand Up @@ -171,11 +171,28 @@

<code-block lang="kotlin">
val directors =
StarWarsFilms.select(StarWarsFilms.director).where { StarWarsFilms.sequelId less 5 }.withDistinct()
StarWarsFilms.select(StarWarsFilms.director)
.where { StarWarsFilms.sequelId less 5 }.withDistinct()
.map {
it[StarWarsFilms.director]
}
</code-block>

<p>Some SQL dialects, such as PostgreSQL and H2, also support the <code>DISTINCT ON</code> clause.
You can use this clause with the <code>withDistinctOn()</code> function:</p>

<code-block lang="kotlin">
val directors =
StarWarsFilms.select(StarWarsFilms.director, StarWarsFilms.name)
.withDistinctOn(StarWarsFilms.director)
.orderBy(
StarWarsFilms.director to SortOrder.ASC,
StarWarsFilms.name to SortOrder.ASC
)
.map {
it[StarWarsFilms.name]
}
</code-block>
</chapter>
<chapter id="selectAll">
<title><code>selectAll</code></title>
Expand Down
4 changes: 4 additions & 0 deletions exposed-core/api/exposed-core.api
Original file line number Diff line number Diff line change
Expand Up @@ -1924,6 +1924,7 @@ public class org/jetbrains/exposed/sql/Query : org/jetbrains/exposed/sql/Abstrac
public synthetic fun forUpdate (Lorg/jetbrains/exposed/sql/vendors/ForUpdateOption;)Lorg/jetbrains/exposed/sql/SizedIterable;
public final fun getComments ()Ljava/util/Map;
public final fun getDistinct ()Z
public final fun getDistinctOn ()Ljava/util/List;
public final fun getGroupedByColumns ()Ljava/util/List;
public final fun getHaving ()Lorg/jetbrains/exposed/sql/Op;
protected fun getQueryToExecute ()Lorg/jetbrains/exposed/sql/statements/Statement;
Expand All @@ -1937,11 +1938,14 @@ public class org/jetbrains/exposed/sql/Query : org/jetbrains/exposed/sql/Abstrac
public synthetic fun notForUpdate ()Lorg/jetbrains/exposed/sql/SizedIterable;
public fun prepareSQL (Lorg/jetbrains/exposed/sql/QueryBuilder;)Ljava/lang/String;
protected final fun setDistinct (Z)V
protected final fun setDistinctOn (Ljava/util/List;)V
public fun setSet (Lorg/jetbrains/exposed/sql/FieldSet;)V
public final fun where (Lkotlin/jvm/functions/Function1;)Lorg/jetbrains/exposed/sql/Query;
public final fun where (Lorg/jetbrains/exposed/sql/Op;)Lorg/jetbrains/exposed/sql/Query;
public synthetic fun withDistinct (Z)Lorg/jetbrains/exposed/sql/AbstractQuery;
public fun withDistinct (Z)Lorg/jetbrains/exposed/sql/Query;
public final fun withDistinctOn ([Lkotlin/Pair;)Lorg/jetbrains/exposed/sql/Query;
public final fun withDistinctOn ([Lorg/jetbrains/exposed/sql/Column;)Lorg/jetbrains/exposed/sql/Query;
}

public final class org/jetbrains/exposed/sql/Query$CommentPosition : java/lang/Enum {
Expand Down
52 changes: 52 additions & 0 deletions exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Query.kt
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,15 @@ open class Query(override var set: FieldSet, where: Op<Boolean>?) : AbstractQuer
var distinct: Boolean = false
protected set

/**
* List of columns on which the query should be distinct.
*
* This parameter specifies columns for the `DISTINCT ON` clause, which allows selecting distinct rows based on
* the specified columns and is supported by some SQL dialects (e.g., PostgreSQL, H2).
*/
var distinctOn: List<Column<*>>? = null
protected set

/** The stored list of columns for a `GROUP BY` clause in this `SELECT` query. */
var groupedByColumns: List<Expression<*>> = mutableListOf()
private set
Expand Down Expand Up @@ -60,6 +69,7 @@ open class Query(override var set: FieldSet, where: Op<Boolean>?) : AbstractQuer
override fun copyTo(other: Query) {
super.copyTo(other)
other.distinct = distinct
other.distinctOn = distinctOn
other.groupedByColumns = groupedByColumns.toMutableList()
other.having = having
other.forUpdate = forUpdate
Expand All @@ -77,9 +87,46 @@ open class Query(override var set: FieldSet, where: Op<Boolean>?) : AbstractQuer
}

override fun withDistinct(value: Boolean): Query = apply {
if (value) {
require(distinctOn == null) { "DISTINCT cannot be used with the DISTINCT ON modifier. Only one of them should be applied." }
}
distinct = value
}

/**
* Specifies that the `SELECT` query should retrieve distinct results based on the given list of columns.
*
* This method can be used to set a `DISTINCT ON` clause for the query, which is supported by some SQL dialects
* (e.g., PostgreSQL, H2). The resulting query will retrieve rows that are distinct based on the specified columns.
*
* @param columns The columns to apply the `DISTINCT ON` clause.
* @return The current `Query` instance with the `DISTINCT ON` clause applied.
*/
fun withDistinctOn(vararg columns: Column<*>): Query = apply {
if (columns.isEmpty()) return@apply

require(!distinct) { "DISTINCT ON cannot be used with the DISTINCT modifier. Only one of them should be applied." }
distinctOn = (distinctOn ?: emptyList()) + columns
}

/**
* Specifies that the `SELECT` query should retrieve distinct results based on the given list of columns with sort orders.
* This method sets a `DISTINCT ON` clause and may reorder the results as indicated.
*
* This method can be used to set a `DISTINCT ON` clause for the query, which is supported by some SQL dialects
* (e.g., PostgreSQL, H2), along with an `ORDER BY` clause for the specified columns.
*
* @param columns The columns and their sort orders to apply the `DISTINCT ON` clause.
* @return The current `Query` instance with the `DISTINCT ON` clause and reordering applied.
*/
fun withDistinctOn(vararg columns: Pair<Column<*>, SortOrder>): Query = apply {
if (columns.isEmpty()) return@apply

require(!distinct) { "DISTINCT ON cannot be used with the DISTINCT modifier. Only one of them should be applied." }
withDistinctOn(columns = columns.map { it.first }.toTypedArray())
return orderBy(order = columns)
}

@Deprecated(
message = "As part of SELECT DSL design changes, this will be removed in future releases.",
replaceWith = ReplaceWith("adjustSelect { body.invoke() }"),
Expand Down Expand Up @@ -174,6 +221,11 @@ open class Query(override var set: FieldSet, where: Op<Boolean>?) : AbstractQuer
if (distinct) {
append("DISTINCT ")
}
distinctOn
?.takeIf { it.isNotEmpty() }
?.let { columns ->
columns.appendTo(prefix = "DISTINCT ON (", postfix = ") ") { append(it) }
}
set.realFields.appendTo { +it }
}
if (set.source != Table.Dual || currentDialect.supportsDualTableConcept) {
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
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.tests.DatabaseTestsBase
import org.jetbrains.exposed.sql.tests.TestDB
import org.jetbrains.exposed.sql.tests.shared.assertEqualLists
import org.jetbrains.exposed.sql.tests.shared.assertEquals
import org.jetbrains.exposed.sql.tests.shared.expectException
import org.junit.Test
import kotlin.test.assertNull

class DistinctOnTests : DatabaseTestsBase() {

private val distinctOnSupportedDb = TestDB.ALL_POSTGRES + TestDB.ALL_H2

@Test
fun testDistinctOn() {
val tester = object : IntIdTable("distinct_function_test") {
val value1 = integer("value1")
val value2 = integer("value2")
}

withTables(excludeSettings = TestDB.ALL - distinctOnSupportedDb, tester) {
tester.batchInsert(
listOf(
listOf(1, 1), listOf(1, 2), listOf(1, 2),
listOf(2, 1), listOf(2, 2), listOf(2, 2),
listOf(4, 4), listOf(4, 4), listOf(4, 4),
)
) {
this[tester.value1] = it[0]
this[tester.value2] = it[1]
}

val distinctValue1 = tester.selectAll()
.withDistinctOn(tester.value1)
.orderBy(tester.value1 to SortOrder.ASC, tester.value2 to SortOrder.ASC)
.map { it[tester.value1] to it[tester.value2] }
assertEqualLists(listOf(1 to 1, 2 to 1, 4 to 4), distinctValue1)

val distinctValue2 = tester.selectAll()
.withDistinctOn(tester.value2)
.orderBy(tester.value2 to SortOrder.ASC, tester.value1 to SortOrder.ASC)
.map { it[tester.value1] to it[tester.value2] }
assertEqualLists(listOf(1 to 1, 1 to 2, 4 to 4), distinctValue2)

val distinctBoth = tester.selectAll()
.withDistinctOn(tester.value1, tester.value2)
.orderBy(tester.value1 to SortOrder.ASC, tester.value2 to SortOrder.ASC)
.map { it[tester.value1] to it[tester.value2] }
assertEqualLists(listOf(1 to 1, 1 to 2, 2 to 1, 2 to 2, 4 to 4), distinctBoth)

val distinctSequential = tester.selectAll()
.withDistinctOn(tester.value1 to SortOrder.ASC)
.withDistinctOn(tester.value2 to SortOrder.ASC)
.map { it[tester.value1] to it[tester.value2] }
assertEqualLists(distinctBoth, distinctSequential)
}
}

@Test
fun testExceptions() {
val tester = object : IntIdTable("distinct_function_test") {
val value = integer("value1")
}

withTables(excludeSettings = TestDB.ALL - distinctOnSupportedDb, tester) {
val query1 = tester.selectAll()
.withDistinct()
expectException<IllegalArgumentException> {
query1.withDistinctOn(tester.value)
}

val query2 = tester.selectAll()
.withDistinctOn(tester.value)
expectException<IllegalArgumentException> {
query2.withDistinct()
}
}
}

@Test
fun testEmptyDistinctOn() {
val tester = object : IntIdTable("distinct_function_test") {
val value = integer("value1")
}

withTables(excludeSettings = TestDB.ALL - distinctOnSupportedDb, tester) {
addLogger(StdOutSqlLogger)
// Empty list of columns should not cause exception
tester.insert {
it[value] = 1
}

val query = tester.selectAll()
.withDistinctOn(columns = emptyArray<Column<*>>())
assertNull(query.distinctOn)

val value = query
.first()[tester.value]
assertEquals(1, value)
}
}
}

0 comments on commit 9f3396c

Please sign in to comment.