diff --git a/documentation-website/Writerside/topics/DSL-CRUD-operations.topic b/documentation-website/Writerside/topics/DSL-CRUD-operations.topic
index f44dedd7c7..4310e87b58 100644
--- a/documentation-website/Writerside/topics/DSL-CRUD-operations.topic
+++ b/documentation-website/Writerside/topics/DSL-CRUD-operations.topic
@@ -171,11 +171,28 @@
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]
}
+
+
Some SQL dialects, such as PostgreSQL and H2, also support the DISTINCT ON
clause.
+ You can use this clause with the withDistinctOn()
function:
+
+
+ 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]
+ }
+
selectAll
diff --git a/exposed-core/api/exposed-core.api b/exposed-core/api/exposed-core.api
index b21738db24..4b4ae81be6 100644
--- a/exposed-core/api/exposed-core.api
+++ b/exposed-core/api/exposed-core.api
@@ -1905,6 +1905,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;
@@ -1918,11 +1919,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 {
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 443f9bbfc1..4a8fc4411b 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
@@ -24,6 +24,15 @@ open class Query(override var set: FieldSet, where: Op?) : 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>? = null
+ protected set
+
/** The stored list of columns for a `GROUP BY` clause in this `SELECT` query. */
var groupedByColumns: List> = mutableListOf()
private set
@@ -80,6 +89,35 @@ open class Query(override var set: FieldSet, where: Op?) : AbstractQuer
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 {
+ 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, SortOrder>): Query = apply {
+ @Suppress("SpreadOperator")
+ withDistinctOn(*columns.map { it.first }.toTypedArray())
+ return orderBy(*columns)
+ }
+
@Deprecated(
message = "As part of SELECT DSL design changes, this will be removed in future releases.",
replaceWith = ReplaceWith("adjustSelect { body.invoke() }"),
@@ -174,6 +212,9 @@ open class Query(override var set: FieldSet, where: Op?) : AbstractQuer
if (distinct) {
append("DISTINCT ")
}
+ distinctOn?.let { columns ->
+ columns.appendTo(prefix = "DISTINCT ON (", postfix = ")") { +"${it.table.tableName}.${it.name}" }
+ }
set.realFields.appendTo { +it }
}
if (set.source != Table.Dual || currentDialect.supportsDualTableConcept) {
diff --git a/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/DistinctOnTests.kt b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/DistinctOnTests.kt
new file mode 100644
index 0000000000..22f2d6c364
--- /dev/null
+++ b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/dml/DistinctOnTests.kt
@@ -0,0 +1,57 @@
+package org.jetbrains.exposed.sql.tests.shared.dml
+
+import org.jetbrains.exposed.dao.id.IntIdTable
+import org.jetbrains.exposed.sql.SortOrder
+import org.jetbrains.exposed.sql.batchInsert
+import org.jetbrains.exposed.sql.selectAll
+import org.jetbrains.exposed.sql.tests.DatabaseTestsBase
+import org.jetbrains.exposed.sql.tests.TestDB
+import org.jetbrains.exposed.sql.tests.shared.assertEqualLists
+import org.junit.Test
+
+class DistinctOnTests : DatabaseTestsBase() {
+ @Test
+ fun test() {
+ val tester = object : IntIdTable("distinct_function_test") {
+ val value1 = integer("value1")
+ val value2 = integer("value2")
+ }
+
+ withTables(excludeSettings = TestDB.ALL - TestDB.ALL_POSTGRES - TestDB.ALL_H2, 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)
+ }
+ }
+}