From 017a6c92125e6e17556b34cbe2a1842f8642f686 Mon Sep 17 00:00:00 2001 From: Chantal Loncle <82039410+bog-walk@users.noreply.github.com> Date: Wed, 29 Jan 2025 21:38:39 -0500 Subject: [PATCH 1/4] docs: EXPOSED-715 Fix broken custom function examples & move to snippets project - Rewrite multiple function examples that were not compiling - Create new exposed-sql-functions snippets project & extract all code from SQL-Functions.md to this project - Add small section about aggregate statistics functions --- .../snippets/exposed-sql-functions/README.md | 23 ++ .../exposed-sql-functions/build.gradle.kts | 47 ++++ .../src/main/kotlin/org/example/App.kt | 51 ++++ .../example/examples/AggregateFuncExamples.kt | 47 ++++ .../example/examples/CustomFuncExamples.kt | 87 +++++++ .../example/examples/CustomTrimFunction.kt | 29 +++ .../example/examples/StringFuncExamples.kt | 68 ++++++ .../example/examples/WindowFuncExamples.kt | 45 ++++ .../kotlin/org/example/tables/SalesTable.kt | 16 ++ .../snippets/gradle/libs.versions.toml | 6 +- .../Writerside/snippets/settings.gradle.kts | 1 + .../Writerside/topics/SQL-Functions.md | 220 +++++++----------- 12 files changed, 509 insertions(+), 131 deletions(-) create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/README.md create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/build.gradle.kts create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomTrimFunction.kt create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/README.md b/documentation-website/Writerside/snippets/exposed-sql-functions/README.md new file mode 100644 index 0000000000..cfaed83929 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/README.md @@ -0,0 +1,23 @@ +# Exposed SQL Functions examples + +A Gradle application that shows how to work with built-in and custom SQL functions using Exposed API. +The files are referenced in the Schema's [SQL Functions](../../topics/SQL-Functions.md) topic. + +## Build + +To build the application, in a terminal window navigate to the `snippets` folder and run the following command: + +```shell +./gradlew :exposed-sql-functions:build +``` + +## Run + +To run the application, in a terminal window navigate to the `snippets` folder and run the following command: + +```shell +./gradlew :exposed-sql-functions:run +``` + +This will run queries to create new tables and run all functions in the `/examples` folder. +To only run a specific example, modify the `App.kt` file and re-run the project. diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/build.gradle.kts b/documentation-website/Writerside/snippets/exposed-sql-functions/build.gradle.kts new file mode 100644 index 0000000000..57f400d660 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/build.gradle.kts @@ -0,0 +1,47 @@ +plugins { + // Apply the org.jetbrains.kotlin.jvm Plugin to add support for Kotlin. + alias(libs.plugins.jvm) + + // Apply the application plugin to add support for building a CLI application in Java. + application +} + +repositories { + // Use Maven Central for resolving dependencies. + mavenCentral() +} + +dependencies { + // Use the Kotlin JUnit 5 integration. + testImplementation("org.jetbrains.kotlin:kotlin-test-junit5") + + // Use the JUnit 5 integration. + testImplementation(libs.junit.jupiter.engine) + + testRuntimeOnly("org.junit.platform:junit-platform-launcher") + + // This dependency is used by the application. + implementation(libs.guava) + implementation(libs.exposed.core) + implementation(libs.exposed.jdbc) + implementation(libs.exposed.kotlin.datetime) + implementation(libs.h2) + implementation(libs.slf4j) +} + +// Apply a specific Java toolchain to ease working on different environments. +java { + toolchain { + languageVersion = JavaLanguageVersion.of(21) + } +} + +application { + // Define the main class for the application. + mainClass = "org.example.AppKt" +} + +tasks.named("test") { + // Use JUnit Platform for unit tests. + useJUnitPlatform() +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt new file mode 100644 index 0000000000..4aea19ef2f --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt @@ -0,0 +1,51 @@ +package org.example + +import org.example.examples.AggregateFuncExamples +import org.example.examples.CustomFuncExamples +import org.example.examples.StringFuncExamples +import org.example.examples.WindowFuncExamples +import org.example.tables.SalesTable +import org.jetbrains.exposed.sql.Database +import org.jetbrains.exposed.sql.DatabaseConfig +import org.jetbrains.exposed.sql.SchemaUtils +import org.jetbrains.exposed.sql.StdOutSqlLogger +import org.jetbrains.exposed.sql.addLogger +import org.jetbrains.exposed.sql.transactions.transaction + +fun main() { + Database.connect( + "jdbc:h2:mem:test", + "org.h2.Driver", + databaseConfig = DatabaseConfig { useNestedTransactions = true } + ) + + transaction { + addLogger(StdOutSqlLogger) + SchemaUtils.create(SalesTable) + runStringFuncExamples() + runAggregateFuncExamples() + runWindowFuncExamples() + runCustomFuncExamples() + } +} + +fun runStringFuncExamples() { + val stringFuncExamples = StringFuncExamples() + stringFuncExamples.selectStringFunctions() +} + +fun runAggregateFuncExamples() { + val aggregateFuncExamples = AggregateFuncExamples() + aggregateFuncExamples.selectAggregateFunctions() +} + +fun runWindowFuncExamples() { + val windowFuncExamples = WindowFuncExamples() + windowFuncExamples.selectWindowFunctions() +} + +fun runCustomFuncExamples() { + val customFuncExamples = CustomFuncExamples() + customFuncExamples.selectCustomFunctions() + customFuncExamples.selectCustomTrimFunction() +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt new file mode 100644 index 0000000000..beb9d27712 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt @@ -0,0 +1,47 @@ +package org.example.examples + +import org.example.tables.SalesTable +import org.jetbrains.exposed.sql.avg +import org.jetbrains.exposed.sql.count +import org.jetbrains.exposed.sql.max +import org.jetbrains.exposed.sql.min +import org.jetbrains.exposed.sql.stdDevPop +import org.jetbrains.exposed.sql.sum + +/* + Important: This file is referenced by line number in `SQL-Functions.md`. + If you add, remove, or modify any lines, ensure you update the corresponding + line numbers in the `code-block` element of the referenced file. +*/ + +class AggregateFuncExamples { + fun selectAggregateFunctions() { + val minAmount = SalesTable.amount.min() + val maxAmount = SalesTable.amount.max() + val averageAmount = SalesTable.amount.avg() + val amountStats = SalesTable + .select(minAmount, maxAmount, averageAmount, SalesTable.label) + .groupBy(SalesTable.label) + .map { + Triple(it[minAmount], it[maxAmount], it[averageAmount]) + } + println(amountStats) + + val amountSum = SalesTable.amount.sum() + val amountCount = SalesTable.amount.count() + val amountReport = SalesTable + .select(amountSum, amountCount, SalesTable.label) + .groupBy(SalesTable.label) + .map { + it[amountSum] to it[amountCount] + } + println(amountReport) + + val amountStdDev = SalesTable.amount.stdDevPop() + val stdDev = SalesTable + .select(amountStdDev) + .singleOrNull() + ?.get(amountStdDev) + println(stdDev) + } +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt new file mode 100644 index 0000000000..c9b894d070 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt @@ -0,0 +1,87 @@ +package org.example.examples + +import org.example.tables.SalesTable +import org.jetbrains.exposed.sql.CustomFunction +import org.jetbrains.exposed.sql.CustomStringFunction +import org.jetbrains.exposed.sql.TextColumnType +import org.jetbrains.exposed.sql.deleteAll +import org.jetbrains.exposed.sql.function +import org.jetbrains.exposed.sql.insert +import org.jetbrains.exposed.sql.intLiteral +import org.jetbrains.exposed.sql.kotlin.datetime.CurrentDate +import org.jetbrains.exposed.sql.kotlin.datetime.CustomDateFunction +import org.jetbrains.exposed.sql.kotlin.datetime.month +import org.jetbrains.exposed.sql.selectAll +import org.jetbrains.exposed.sql.stringLiteral + +/* + Important: This file is referenced by line number in `SQL-Functions.md`. + If you add, remove, or modify any lines, ensure you update the corresponding + line numbers in the `code-block` element of the referenced file. +*/ + +private const val SALES_MONTH = 1 +private const val SALES_YEAR = 2025 + +class CustomFuncExamples { + fun selectCustomFunctions() { + val sqrtAmount = SalesTable.amount.function("SQRT") + // generates SQL: SQRT(SALES.AMOUNT) + val sqrt = SalesTable + .select(sqrtAmount) + .singleOrNull() + ?.get(sqrtAmount) + println(sqrt) + + val replacedLabel = CustomFunction( + functionName = "REPLACE", + columnType = TextColumnType(), + SalesTable.label, stringLiteral("Label"), stringLiteral("New Label") + ) + // generates SQL: REPLACE(SALES.LABEL, 'Label', 'New Label') + val replacedLabels = SalesTable.select(replacedLabel).map { it[replacedLabel] } + println(replacedLabels) + + val replacedStringLabel = CustomStringFunction( + "REPLACE", SalesTable.label, stringLiteral("Label"), stringLiteral("New Label") + ) + val replacedStringLabels = SalesTable.select(replacedStringLabel).map { it[replacedStringLabel] } + println(replacedStringLabels) + } + + @Suppress("MagicNumber") + fun selectCustomDateFunction() { + val threeMonthsAgo = CustomDateFunction( + functionName = "DATEADD", + stringLiteral("MONTH"), + intLiteral(-3), + CurrentDate + ).month() + // generates SQL: MONTH(DATEADD('MONTH', -3, CURRENT_DATE)) + val salesInLast3Months = SalesTable + .selectAll() + .where { SalesTable.month greater threeMonthsAgo } + .map { it[SalesTable.product] } + println(salesInLast3Months) + } + + fun selectCustomTrimFunction() { + SalesTable.deleteAll() + + SalesTable.insert { + it[label] = "xxxxLabelxxxx" + it[product] = "Product" + it[amount] = 99.toBigDecimal() + it[month] = SALES_MONTH + it[year] = SALES_YEAR + } + + val leadingXTrim = SalesTable.label.customTrim(stringLiteral("x"), TrimSpecifier.LEADING) + val labelWithoutPrefix = SalesTable.select(leadingXTrim).single()[leadingXTrim] // Labelxxxx + println(labelWithoutPrefix) + + val trailingXTrim = SalesTable.label.customTrim(stringLiteral("x"), TrimSpecifier.TRAILING) + val labelWithoutSuffix = SalesTable.select(trailingXTrim).single()[trailingXTrim] // xxxxLabel + println(labelWithoutSuffix) + } +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomTrimFunction.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomTrimFunction.kt new file mode 100644 index 0000000000..1765c73aaa --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomTrimFunction.kt @@ -0,0 +1,29 @@ +package org.example.examples + +import org.jetbrains.exposed.sql.Expression +import org.jetbrains.exposed.sql.Function +import org.jetbrains.exposed.sql.QueryBuilder +import org.jetbrains.exposed.sql.TextColumnType +import org.jetbrains.exposed.sql.append + +enum class TrimSpecifier { BOTH, LEADING, TRAILING } + +class CustomTrim( + val expression: Expression, + val toRemove: Expression?, + val trimSpecifier: TrimSpecifier +) : Function(TextColumnType()) { + override fun toQueryBuilder(queryBuilder: QueryBuilder) { + queryBuilder { + append("TRIM(") + append(trimSpecifier.name) + toRemove?.let { +" $it" } + append(" FROM ", expression, ")") + } + } +} + +fun Expression.customTrim( + toRemove: Expression? = null, + specifier: TrimSpecifier = TrimSpecifier.BOTH +): CustomTrim = CustomTrim(this, toRemove, specifier) diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt new file mode 100644 index 0000000000..c1984374c5 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt @@ -0,0 +1,68 @@ +package org.example.examples + +import org.example.tables.SalesTable +import org.jetbrains.exposed.sql.Concat +import org.jetbrains.exposed.sql.SqlExpressionBuilder.concat +import org.jetbrains.exposed.sql.alias +import org.jetbrains.exposed.sql.charLength +import org.jetbrains.exposed.sql.insert +import org.jetbrains.exposed.sql.locate +import org.jetbrains.exposed.sql.lowerCase +import org.jetbrains.exposed.sql.stringLiteral +import org.jetbrains.exposed.sql.substring +import org.jetbrains.exposed.sql.trim +import org.jetbrains.exposed.sql.upperCase + +/* + Important: This file is referenced by line number in `SQL-Functions.md`. + If you add, remove, or modify any lines, ensure you update the corresponding + line numbers in the `code-block` element of the referenced file. +*/ + +private const val SALES_MONTH = 1 +private const val SALES_YEAR = 2025 + +class StringFuncExamples { + fun selectStringFunctions() { + SalesTable.insert { + it[label] = "Label A" + it[product] = "Product A" + it[amount] = 99.toBigDecimal() + it[month] = SALES_MONTH + it[year] = SALES_YEAR + } + + val lowerCaseLabel = SalesTable.label.lowerCase() + val lowerCaseLabels = SalesTable.select(lowerCaseLabel).map { it[lowerCaseLabel] } + println(lowerCaseLabels) + + val upperCaseProduct = SalesTable.product.upperCase().alias("prd_all_caps") + val upperCaseProducts = SalesTable.select(upperCaseProduct).map { it[upperCaseProduct] } + println(upperCaseProducts) + + val fullProductLabel = Concat(separator = " ", SalesTable.product, stringLiteral("||"), SalesTable.label) + .trim() + .lowerCase() + val fullProductLabels = SalesTable.select(fullProductLabel).map { it[fullProductLabel] } + println(fullProductLabels) + + val shortenedLabel = SalesTable.label.substring(start = 1, length = 3) + val shortenedLabels = SalesTable.select(shortenedLabel).map { it[shortenedLabel] } + println(shortenedLabels) + + val productName = concat( + separator = " - ", + expr = listOf(stringLiteral("Product"), SalesTable.product) + ) + val productNames = SalesTable.select(productName).map { it[productName] } + println(productNames) + + val firstXSIndex = SalesTable.label.locate("XS") + val firstXSIndices = SalesTable.select(firstXSIndex).map { it[firstXSIndex] } + println(firstXSIndices) + + val labelLength = SalesTable.label.charLength() + val labelLengths = SalesTable.select(labelLength).map { it[labelLength] } + println(labelLengths) + } +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt new file mode 100644 index 0000000000..16345e3f66 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt @@ -0,0 +1,45 @@ +package org.example.examples + +import org.example.tables.SalesTable +import org.jetbrains.exposed.sql.SortOrder +import org.jetbrains.exposed.sql.SqlExpressionBuilder.rowNumber +import org.jetbrains.exposed.sql.WindowFrameBound +import org.jetbrains.exposed.sql.sum + +/* + Important: This file is referenced by line number in `SQL-Functions.md`. + If you add, remove, or modify any lines, ensure you update the corresponding + line numbers in the `code-block` element of the referenced file. +*/ + +class WindowFuncExamples { + fun selectWindowFunctions() { + val window1 = SalesTable.amount.sum() + .over() + .partitionBy(SalesTable.year, SalesTable.product) + .orderBy(SalesTable.amount) + val result1 = SalesTable.select(window1).map { it[window1] } + println(result1) + + val window2 = rowNumber() + .over() + .partitionBy(SalesTable.year, SalesTable.product) + .orderBy(SalesTable.amount) + val result2 = SalesTable.select(window2).map { it[window2] } + println(result2) + + val window3 = SalesTable.amount.sum() + .over() + .orderBy(SalesTable.year to SortOrder.DESC, SalesTable.product to SortOrder.ASC_NULLS_FIRST) + val result3 = SalesTable.select(window3).map { it[window3] } + println(result3) + + val window4 = SalesTable.amount.sum() + .over() + .partitionBy(SalesTable.year, SalesTable.product) + .orderBy(SalesTable.amount) + .range(WindowFrameBound.offsetPreceding(2), WindowFrameBound.currentRow()) + val result4 = SalesTable.select(window4).map { it[window4] } + println(result4) + } +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt new file mode 100644 index 0000000000..bb1d68cab4 --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt @@ -0,0 +1,16 @@ +package org.example.tables + +import org.jetbrains.exposed.sql.Table + +const val MAX_LABEL_LENGTH = 100 +const val MAX_PRODUCT_LENGTH = 50 +const val AMOUNT_PRECISION = 8 +const val AMOUNT_SCALE = 2 + +object SalesTable : Table() { + val label = varchar("label", MAX_LABEL_LENGTH) + val product = varchar("product", MAX_PRODUCT_LENGTH) + val amount = decimal("amount", AMOUNT_PRECISION, AMOUNT_SCALE) + val month = integer("month") + val year = integer("year") +} diff --git a/documentation-website/Writerside/snippets/gradle/libs.versions.toml b/documentation-website/Writerside/snippets/gradle/libs.versions.toml index a35a3e9c56..dcf4bcb6da 100644 --- a/documentation-website/Writerside/snippets/gradle/libs.versions.toml +++ b/documentation-website/Writerside/snippets/gradle/libs.versions.toml @@ -5,6 +5,8 @@ guava = "33.0.0-jre" junit-jupiter-engine = "5.10.2" exposed = "0.58.0" +h2 = "2.2.224" +slf4j = "2.0.16" [libraries] guava = { module = "com.google.guava:guava", version.ref = "guava" } @@ -13,6 +15,8 @@ exposed-core = { module = "org.jetbrains.exposed:exposed-core", version.ref = "e exposed-jdbc = { module = "org.jetbrains.exposed:exposed-jdbc", version.ref = "exposed" } exposed-dao = { module = "org.jetbrains.exposed:exposed-dao", version.ref = "exposed" } exposed-kotlin-datetime = { module = "org.jetbrains.exposed:exposed-kotlin-datetime", version.ref = "exposed" } +h2 = { module = "com.h2database:h2", version.ref = "h2"} +slf4j = {module = "org.slf4j:slf4j-nop", version.ref = "slf4j"} [plugins] -jvm = { id = "org.jetbrains.kotlin.jvm", version = "1.9.22" } +jvm = { id = "org.jetbrains.kotlin.jvm", version = "2.1.0" } diff --git a/documentation-website/Writerside/snippets/settings.gradle.kts b/documentation-website/Writerside/snippets/settings.gradle.kts index 1468ce03c7..bb25e7af42 100644 --- a/documentation-website/Writerside/snippets/settings.gradle.kts +++ b/documentation-website/Writerside/snippets/settings.gradle.kts @@ -16,3 +16,4 @@ include("exposed-dsl") include("exposed-modules-maven") include("exposed-modules-kotlin-gradle") include("exposed-modules-groovy-gradle") +include("exposed-sql-functions") diff --git a/documentation-website/Writerside/topics/SQL-Functions.md b/documentation-website/Writerside/topics/SQL-Functions.md index c600df2c42..4c2aa43c8d 100644 --- a/documentation-website/Writerside/topics/SQL-Functions.md +++ b/documentation-website/Writerside/topics/SQL-Functions.md @@ -5,19 +5,23 @@ Exposed provides basic support for classic SQL functions. This topic consists of definitions for those functions, and their usage examples. It also explains how to define [custom functions](#custom-functions). +For the function examples below, consider the following table: + + + ## How to use functions -If you want to retrieve a function result from a query, you have to declare the function as a variable: -```kotlin -val lowerCasedName = FooTable.name.lowerCase() -val lowerCasedNames = FooTable.select(lowerCasedName).map { it[lowerCasedName] } +If you want to retrieve an SQL function result from a query using `.select()`, you should declare the function as a variable first: + + + +This function could also be aliased, in the same way that a [table or query could be aliased](DSL-Querying-data.topic#alias): -``` -Also, functions could be chained and combined: -```kotlin -val trimmedAndLoweredFullName = Concat(FooTable.firstName, stringLiteral(" "), FooTable.lastName).trim().lowerCase() -val fullNames = FooTable.select(trimmedAndLoweredFullName).map { it[trimmedAndLoweredFullName] } + -``` +Also, functions could be chained and combined as needed. The example below generates SQL that concatenates the string values +stored in 2 columns, before wrapping the function in `TRIM()` and `LOWER()`: + + ## String functions ### Lower case and upper case @@ -26,153 +30,117 @@ and [`.upperCase()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/upper-case.html) functions respectively. -```kotlin -val lowerCasedName = FooTable.name.lowerCase() -val lowerCasedNames = FooTable.select(lowerCasedName).map { it[lowerCasedName] } + -``` ### Substring -The [.substring()](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/substring.html) +The [`.substring()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/substring.html) function returns a substring value from the specified start and with the specified length. -```kotlin -val shortenedName = FooTable.name.substring(start = 1, length = 3) -val shortenedNames = FooTable.select(shortenedName).map { it[shortenedName] } + -``` ### Concatenate -The [concat()](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/concat.html) +The [`concat()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/concat.html) function returns a string value that concatenates the text representations of all non-null input values, separated by an optional separator. -```kotlin -val userName = concat(stringLiteral("User - "), FooTable.name) -val userNames = FooTable.select(userName).map { it[userName] } + + + +This concat() requires import statement import org.jetbrains.exposed.sql.SqlExpressionBuilder.concat. + -``` ### Locate -The [.locate()](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/locate.html) -function returns the index of the first occurrence of a specified substring or 0. +The [`.locate()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/locate.html) +function returns the index of the first occurrence of a specified substring, or 0 if the substring is not found. -```kotlin -val firstAIndex = FooTable.name.locate("a") -val firstAIndices = FooTable.select(firstAIndex).map { it[firstAIndex] } + -``` ### Character length -The [.charLength()](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/char-length.html) +The [`.charLength()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/char-length.html) function returns the length, measured in characters, or `null` if the String value is null. -```kotlin -val nameLength = FooTable.name.charLength() -val nameLengths = FooTable.select(nameLength).map { it[nameLength] } - -``` + -## Aggregating functions -These functions should be used in queries with [groupBy](DSL-Querying-data.topic#group-by). +## Aggregate functions +These functions should most likely be used in queries with [`.groupBy()`](DSL-Querying-data.topic#group-by). ### Min/Max/Average To get the minimum, maximum, and average values, use the -[.min()](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/min.html) -[.max()](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/max.html) -and [.avg](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/avg.html) functions +[`.min()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/min.html) +[`.max()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/max.html) +and [`.avg()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/avg.html) functions respectively. These functions can be applied to any comparable expression: -```kotlin -val minId = FooTable.id.min() -val maxId = FooTable.id.max() -val averageId = FooTable.id.avg() -val (min, max, avg) = FooTable.select(minId, maxId, averageId).map { - Triple(it[minId], it[maxId], it[averageId]) -} + + +### Sum/Count +You can also use SQL functions like `SUM()` and `COUNT()` directly with a column expression: + + -``` +### Statistics +Some databases provide aggregate functions specifically for statistics and Exposed provides support for 4 of these: +[`.stdDevPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/stdDevPop.html), +[`.stdDevSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/stdDevSamp.html), +[`.varPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/varPop.html), +[`.varSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/varSamp.html). +The following example retrieves the population standard deviation of values stored in the `amount` column: + + ## Custom functions If you can't find your most loved function used in your database (as Exposed provides only basic support for classic SQL functions), you can define your own functions. -Since Exposed 0.15.1 there multiple options to define custom functions: -1. Function without parameters: -```kotlin -val sqrt = FooTable.id.function("SQRT") -``` -In SQL representation it will be `SQRT(FooTable.id)` +There are multiple options to define custom functions: +1. Functions without parameters: + +[`.function()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/function.html) simply wraps the column expression +in parentheses with the string argument as the function name: + + -2. Function with additional parameters: -```kotlin -val replacedName = CustomFunction("REPLACE", VarCharColumnType(), FooTable.name, stringParam("foo"), stringParam("bar")) +2. Functions with additional parameters: -``` -The [`CustomFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-function/index.html) -class accepts a function name as a first parameter and the resulting column type as second. After that, you can provide any amount of parameters separated by a comma. +The [`CustomFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-function/index.html) class accepts +a function name as the first argument and the column type that should be used to handle its results as the second. +After that, you can provide any amount of additional parameters separated by a comma: + + There are also shortcuts for string, long, and datetime functions: * [`CustomStringFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-string-function.html) * [`CustomLongFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-long-function.html) * [`CustomDateTimeFunction`](https://jetbrains.github.io/Exposed/api/exposed-jodatime/org.jetbrains.exposed.sql.jodatime/-custom-date-time-function.html) -The code above could be simplified to: -```kotlin -val replacedName = CustomStringFunction("REPLACE", FooTable.name, stringParam("foo"), stringParam("bar")) - -``` -For example, the following could be used in SQLite to mimic its `date()` function: -```kotlin -val lastDayOfMonth = CustomDateFunction( - "date", - FooTable.dateColumn, - stringLiteral("start of month"), - stringLiteral("+1 month"), - stringLiteral("-1 day") -) -``` -3. Function that requires more complex query building: +Using one of these shortcuts, the example above could be simplified to: + + + +As an additional example, the following could be used in H2 to mimic its `DATEADD()` function in order to calculate a date 3 months before the current date. +This could then be chained with Exposed's built-in `.month()` function to return the month of the date found, so it can be used in a query: + + + +3. Functions that require more complex query building: All functions in Exposed extend the abstract class [`Function`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-function/index.html), which takes a column type and allows overriding `toQueryBuilder()`. This is what `CustomFunction` actually does, which can be leveraged to create more complex queries. -For example, Exposed provides a `trim()` function that removes leading and trailing whitespace from a String. In MySQL, -this is just the default behavior as specifiers can be provided to limit the trim to either leading or trailing, as well -as providing a specific substring other than spaces to remove. The custom function below supports this extended behavior: - -```kotlin -enum class TrimSpecifier { BOTH, LEADING, TRAILING } - -class CustomTrim( - val expression: Expression, - val toRemove: Expression?, - val trimSpecifier: TrimSpecifier -) : Function(TextColumnType()) { - override fun toQueryBuilder(queryBuilder: QueryBuilder) { - queryBuilder { - append("TRIM(") - append(trimSpecifier.name) - toRemove?.let { +" $it" } - append(" FROM ") - append(expression) - append(")") - } - } -} - -fun Expression.customTrim( - toRemove: Expression? = null, - specifier: TrimSpecifier = TrimSpecifier.BOTH -): CustomTrim = CustomTrim(this, toRemove, specifier) - -transaction { - FooTable.insert { it[name] = "xxxbarxxx" } - - val leadingXTrim = FooTable.name.customTrim(stringLiteral("x"), TrimSpecifier.LEADING) - val trailingXTrim = FooTable.name.customTrim(stringLiteral("x"), TrimSpecifier.TRAILING) - - FooTable.select(leadingXTrim) // barxxx - FooTable.select(trailingXTrim) // xxxbar -} - -``` - -## Window Functions +For example, Exposed provides a `.trim()` function that removes leading and trailing whitespace from a String. In some databases (like H2 and MySQL), +this is just the default behavior as specifiers can be provided to limit the trim to either leading or trailing. These databases also allow you +to provide a specific substring other than spaces to remove. The custom function below supports this extended behavior: + + + + +Ensure that the correct import statement is used: import org.jetbrains.exposed.sql.Function. Otherwise Function +from kotlin-stdlib may be resolved instead and cause compilation errors. + + +This custom function can then be used to achieve the exact trim that is needed: + + + +## Window functions Window functions allow calculations across a set of table rows that are related to the current row. @@ -191,13 +159,9 @@ Existing aggregate functions (like `sum()`, `avg()`) can be used, as well as new To use a window function, include the `OVER` clause by chaining `.over()` after the function call. A `PARTITION BY` and `ORDER BY` clause can be optionally chained using `.partitionBy()` and `.orderBy()`, which both take multiple arguments: -```kotlin -FooTable.amount.sum().over().partitionBy(FooTable.year, FooTable.product).orderBy(FooTable.amount) -rowNumber().over().partitionBy(FooTable.year, FooTable.product).orderBy(FooTable.amount) + -FooTable.amount.sum().over().orderBy(FooTable.year to SortOrder.DESC, FooTable.product to SortOrder.ASC_NULLS_FIRST) -``` Frame clause functions (like `rows()`, `range()`, and `groups()`) are also supported and take a `WindowFrameBound` option depending on the expected result: * `WindowFrameBound.currentRow()` @@ -205,12 +169,8 @@ depending on the expected result: * `WindowFrameBound.unboundedFollowing()` * `WindowFrameBound.offsetPreceding()` * `WindowFrameBound.offsetFollowing()` -```kotlin -FooTable.amount.sum().over() - .partitionBy(FooTable.year, FooTable.product) - .orderBy(FooTable.amount) - .range(WindowFrameBound.offsetPreceding(2), WindowFrameBound.currentRow()) -``` + + If multiple frame clause functions are chained together, only the last one will be used. From 298798a6e8e524897fc00c5a99e18337b82f8f98 Mon Sep 17 00:00:00 2001 From: Viktoriya Nikolova Date: Thu, 30 Jan 2025 08:48:55 +0100 Subject: [PATCH 2/4] add stylistic content adjustments --- .../Writerside/topics/SQL-Functions.md | 35 +++++++++++-------- 1 file changed, 21 insertions(+), 14 deletions(-) diff --git a/documentation-website/Writerside/topics/SQL-Functions.md b/documentation-website/Writerside/topics/SQL-Functions.md index 4c2aa43c8d..24543fec83 100644 --- a/documentation-website/Writerside/topics/SQL-Functions.md +++ b/documentation-website/Writerside/topics/SQL-Functions.md @@ -10,16 +10,16 @@ For the function examples below, consider the following table: ## How to use functions -If you want to retrieve an SQL function result from a query using `.select()`, you should declare the function as a variable first: +To retrieve the result of an SQL function result from a query using `.select()`, declare the function as a variable first: -This function could also be aliased, in the same way that a [table or query could be aliased](DSL-Querying-data.topic#alias): +You can alias this function in the same way you [alias a table or query](DSL-Querying-data.topic#alias): -Also, functions could be chained and combined as needed. The example below generates SQL that concatenates the string values -stored in 2 columns, before wrapping the function in `TRIM()` and `LOWER()`: +SQL functions can be chained and combined as needed. The example below generates SQL that concatenates the string values +stored in two columns, before wrapping the function in `TRIM()` and `LOWER()`: @@ -72,12 +72,12 @@ respectively. These functions can be applied to any comparable expression: ### Sum/Count -You can also use SQL functions like `SUM()` and `COUNT()` directly with a column expression: +You can use SQL functions like `SUM()` and `COUNT()` directly with a column expression: ### Statistics -Some databases provide aggregate functions specifically for statistics and Exposed provides support for 4 of these: +Some databases provide aggregate functions specifically for statistics and Exposed provides support for four of these: [`.stdDevPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/stdDevPop.html), [`.stdDevSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/stdDevSamp.html), [`.varPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/varPop.html), @@ -90,14 +90,19 @@ The following example retrieves the population standard deviation of values stor If you can't find your most loved function used in your database (as Exposed provides only basic support for classic SQL functions), you can define your own functions. There are multiple options to define custom functions: -1. Functions without parameters: + +1. [Functions without parameters](#functions-without-parameters) +2. [Functions with additional parameters](#functions-with-additional-parameters) +3. [Functions that require more complex query building](#functions-that-require-more-complex-query-building) + +### Functions without parameters [`.function()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/function.html) simply wraps the column expression in parentheses with the string argument as the function name: -2. Functions with additional parameters: +### Functions with additional parameters The [`CustomFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-function/index.html) class accepts a function name as the first argument and the column type that should be used to handle its results as the second. @@ -105,7 +110,7 @@ After that, you can provide any amount of additional parameters separated by a c -There are also shortcuts for string, long, and datetime functions: +There are also shortcuts for `String`, `Long`, and `DateTime` functions: * [`CustomStringFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-string-function.html) * [`CustomLongFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-long-function.html) * [`CustomDateTimeFunction`](https://jetbrains.github.io/Exposed/api/exposed-jodatime/org.jetbrains.exposed.sql.jodatime/-custom-date-time-function.html) @@ -114,12 +119,14 @@ Using one of these shortcuts, the example above could be simplified to: -As an additional example, the following could be used in H2 to mimic its `DATEADD()` function in order to calculate a date 3 months before the current date. -This could then be chained with Exposed's built-in `.month()` function to return the month of the date found, so it can be used in a query: +In the following example, `CustomDateFunction` is used in an H2 database to mimic its `DATEADD()` function in order to +calculate a date three months before the current one. +In is then chained with Exposed's built-in `.month()` function to return the month of the date found, +so it can be used in a query: -3. Functions that require more complex query building: +### Functions that require more complex query building All functions in Exposed extend the abstract class [`Function`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-function/index.html), which takes a column type and allows overriding `toQueryBuilder()`. This is what `CustomFunction` actually does, @@ -158,11 +165,11 @@ Existing aggregate functions (like `sum()`, `avg()`) can be used, as well as new * `rowNumber()` To use a window function, include the `OVER` clause by chaining `.over()` after the function call. A `PARTITION BY` and -`ORDER BY` clause can be optionally chained using `.partitionBy()` and `.orderBy()`, which both take multiple arguments: +`ORDER BY` clause can be optionally chained using `.partitionBy()` and `.orderBy()`, taking multiple arguments: -Frame clause functions (like `rows()`, `range()`, and `groups()`) are also supported and take a `WindowFrameBound` option +Frame clause functions, such as `rows()`, `range()`, and `groups()`, are also supported and take a `WindowFrameBound` option depending on the expected result: * `WindowFrameBound.currentRow()` * `WindowFrameBound.unboundedPreceding()` From 9b636b98821225c6e890eb3f10f8eb568c1f82a5 Mon Sep 17 00:00:00 2001 From: Viktoriya Nikolova Date: Thu, 30 Jan 2025 14:19:37 +0100 Subject: [PATCH 3/4] Update examples in exposed-sql-functions to follow the Star Wars films theme --- .../src/main/kotlin/org/example/App.kt | 4 +- .../example/examples/AggregateFuncExamples.kt | 40 ++++++------ .../example/examples/CustomFuncExamples.kt | 62 +++++++++---------- .../example/examples/StringFuncExamples.kt | 60 +++++++++--------- .../example/examples/WindowFuncExamples.kt | 30 ++++----- .../org/example/tables/FilmBoxOfficeTable.kt | 16 +++++ .../kotlin/org/example/tables/SalesTable.kt | 16 ----- .../Writerside/topics/SQL-Functions.md | 27 +++++--- 8 files changed, 134 insertions(+), 121 deletions(-) create mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/FilmBoxOfficeTable.kt delete mode 100644 documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt index 4aea19ef2f..1a6bb1cc4c 100644 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/App.kt @@ -4,7 +4,7 @@ import org.example.examples.AggregateFuncExamples import org.example.examples.CustomFuncExamples import org.example.examples.StringFuncExamples import org.example.examples.WindowFuncExamples -import org.example.tables.SalesTable +import org.example.tables.FilmBoxOfficeTable import org.jetbrains.exposed.sql.Database import org.jetbrains.exposed.sql.DatabaseConfig import org.jetbrains.exposed.sql.SchemaUtils @@ -21,7 +21,7 @@ fun main() { transaction { addLogger(StdOutSqlLogger) - SchemaUtils.create(SalesTable) + SchemaUtils.create(FilmBoxOfficeTable) runStringFuncExamples() runAggregateFuncExamples() runWindowFuncExamples() diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt index beb9d27712..73399ae8ee 100644 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/AggregateFuncExamples.kt @@ -1,6 +1,6 @@ package org.example.examples -import org.example.tables.SalesTable +import org.example.tables.FilmBoxOfficeTable import org.jetbrains.exposed.sql.avg import org.jetbrains.exposed.sql.count import org.jetbrains.exposed.sql.max @@ -16,32 +16,32 @@ import org.jetbrains.exposed.sql.sum class AggregateFuncExamples { fun selectAggregateFunctions() { - val minAmount = SalesTable.amount.min() - val maxAmount = SalesTable.amount.max() - val averageAmount = SalesTable.amount.avg() - val amountStats = SalesTable - .select(minAmount, maxAmount, averageAmount, SalesTable.label) - .groupBy(SalesTable.label) + val minRevenue = FilmBoxOfficeTable.revenue.min() + val maxRevenue = FilmBoxOfficeTable.revenue.max() + val averageRevenue = FilmBoxOfficeTable.revenue.avg() + val revenueStats = FilmBoxOfficeTable + .select(minRevenue, maxRevenue, averageRevenue, FilmBoxOfficeTable.region) + .groupBy(FilmBoxOfficeTable.region) .map { - Triple(it[minAmount], it[maxAmount], it[averageAmount]) + Triple(it[minRevenue], it[maxRevenue], it[averageRevenue]) } - println(amountStats) + println(revenueStats) - val amountSum = SalesTable.amount.sum() - val amountCount = SalesTable.amount.count() - val amountReport = SalesTable - .select(amountSum, amountCount, SalesTable.label) - .groupBy(SalesTable.label) + val revenueSum = FilmBoxOfficeTable.revenue.sum() + val revenueCount = FilmBoxOfficeTable.revenue.count() + val revenueReport = FilmBoxOfficeTable + .select(revenueSum, revenueCount, FilmBoxOfficeTable.region) + .groupBy(FilmBoxOfficeTable.region) .map { - it[amountSum] to it[amountCount] + it[revenueSum] to it[revenueCount] } - println(amountReport) + println(revenueReport) - val amountStdDev = SalesTable.amount.stdDevPop() - val stdDev = SalesTable - .select(amountStdDev) + val revenueStdDev = FilmBoxOfficeTable.revenue.stdDevPop() + val stdDev = FilmBoxOfficeTable + .select(revenueStdDev) .singleOrNull() - ?.get(amountStdDev) + ?.get(revenueStdDev) println(stdDev) } } diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt index c9b894d070..e9de465d89 100644 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt @@ -1,6 +1,6 @@ package org.example.examples -import org.example.tables.SalesTable +import org.example.tables.FilmBoxOfficeTable import org.jetbrains.exposed.sql.CustomFunction import org.jetbrains.exposed.sql.CustomStringFunction import org.jetbrains.exposed.sql.TextColumnType @@ -20,33 +20,33 @@ import org.jetbrains.exposed.sql.stringLiteral line numbers in the `code-block` element of the referenced file. */ -private const val SALES_MONTH = 1 -private const val SALES_YEAR = 2025 +private const val REVENUE_MONTH = 1 +private const val REVENUE_YEAR = 1999 class CustomFuncExamples { fun selectCustomFunctions() { - val sqrtAmount = SalesTable.amount.function("SQRT") + val sqrtAmount = FilmBoxOfficeTable.revenue.function("SQRT") // generates SQL: SQRT(SALES.AMOUNT) - val sqrt = SalesTable + val sqrt = FilmBoxOfficeTable .select(sqrtAmount) .singleOrNull() ?.get(sqrtAmount) println(sqrt) - val replacedLabel = CustomFunction( + val replacedTitle = CustomFunction( functionName = "REPLACE", columnType = TextColumnType(), - SalesTable.label, stringLiteral("Label"), stringLiteral("New Label") + FilmBoxOfficeTable.title, stringLiteral("Title"), stringLiteral("New Title") ) - // generates SQL: REPLACE(SALES.LABEL, 'Label', 'New Label') - val replacedLabels = SalesTable.select(replacedLabel).map { it[replacedLabel] } - println(replacedLabels) + // generates SQL: REPLACE(FILMBOXOFFICE.TITLE, 'Title', 'New Title') + val replacedTitles = FilmBoxOfficeTable.select(replacedTitle).map { it[replacedTitle] } + println(replacedTitles) - val replacedStringLabel = CustomStringFunction( - "REPLACE", SalesTable.label, stringLiteral("Label"), stringLiteral("New Label") + val replacedStringTitle = CustomStringFunction( + "REPLACE", FilmBoxOfficeTable.title, stringLiteral("Title"), stringLiteral("New Title") ) - val replacedStringLabels = SalesTable.select(replacedStringLabel).map { it[replacedStringLabel] } - println(replacedStringLabels) + val replacedStringTitles = FilmBoxOfficeTable.select(replacedStringTitle).map { it[replacedStringTitle] } + println(replacedStringTitles) } @Suppress("MagicNumber") @@ -58,30 +58,30 @@ class CustomFuncExamples { CurrentDate ).month() // generates SQL: MONTH(DATEADD('MONTH', -3, CURRENT_DATE)) - val salesInLast3Months = SalesTable + val revenueInLast3Months = FilmBoxOfficeTable .selectAll() - .where { SalesTable.month greater threeMonthsAgo } - .map { it[SalesTable.product] } - println(salesInLast3Months) + .where { FilmBoxOfficeTable.month greater threeMonthsAgo } + .map { it[FilmBoxOfficeTable.title] } + println(revenueInLast3Months) } fun selectCustomTrimFunction() { - SalesTable.deleteAll() + FilmBoxOfficeTable.deleteAll() - SalesTable.insert { - it[label] = "xxxxLabelxxxx" - it[product] = "Product" - it[amount] = 99.toBigDecimal() - it[month] = SALES_MONTH - it[year] = SALES_YEAR + FilmBoxOfficeTable.insert { + it[title] = "Star Wars: The Phantom Menace - Episode I" + it[region] = "Spain" + it[revenue] = 99.toBigDecimal() + it[month] = REVENUE_MONTH + it[year] = REVENUE_YEAR } - val leadingXTrim = SalesTable.label.customTrim(stringLiteral("x"), TrimSpecifier.LEADING) - val labelWithoutPrefix = SalesTable.select(leadingXTrim).single()[leadingXTrim] // Labelxxxx - println(labelWithoutPrefix) + val leadingStarWarsTrim = FilmBoxOfficeTable.title.customTrim(stringLiteral("Star Wars:"), TrimSpecifier.LEADING) + val titleWithoutPrefix = FilmBoxOfficeTable.select(leadingStarWarsTrim).single()[leadingStarWarsTrim] // Episode I - The Phantom Menace + println(titleWithoutPrefix) - val trailingXTrim = SalesTable.label.customTrim(stringLiteral("x"), TrimSpecifier.TRAILING) - val labelWithoutSuffix = SalesTable.select(trailingXTrim).single()[trailingXTrim] // xxxxLabel - println(labelWithoutSuffix) + val trailingEpisodeTrim = FilmBoxOfficeTable.title.customTrim(stringLiteral("- Episode I"), TrimSpecifier.TRAILING) + val titleWithoutSuffix = FilmBoxOfficeTable.select(trailingEpisodeTrim).single()[trailingEpisodeTrim] // Star Wars: The Phantom Menace + println(titleWithoutSuffix) } } diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt index c1984374c5..26518e4409 100644 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/StringFuncExamples.kt @@ -1,6 +1,6 @@ package org.example.examples -import org.example.tables.SalesTable +import org.example.tables.FilmBoxOfficeTable import org.jetbrains.exposed.sql.Concat import org.jetbrains.exposed.sql.SqlExpressionBuilder.concat import org.jetbrains.exposed.sql.alias @@ -19,50 +19,50 @@ import org.jetbrains.exposed.sql.upperCase line numbers in the `code-block` element of the referenced file. */ -private const val SALES_MONTH = 1 -private const val SALES_YEAR = 2025 +private const val REVENUE_MONTH = 1 +private const val REVENUE_YEAR = 2019 class StringFuncExamples { fun selectStringFunctions() { - SalesTable.insert { - it[label] = "Label A" - it[product] = "Product A" - it[amount] = 99.toBigDecimal() - it[month] = SALES_MONTH - it[year] = SALES_YEAR + FilmBoxOfficeTable.insert { + it[title] = "The Rise of Skywalker" + it[region] = "Netherlands" + it[revenue] = 99.toBigDecimal() + it[month] = REVENUE_MONTH + it[year] = REVENUE_YEAR } - val lowerCaseLabel = SalesTable.label.lowerCase() - val lowerCaseLabels = SalesTable.select(lowerCaseLabel).map { it[lowerCaseLabel] } - println(lowerCaseLabels) + val lowerCaseTitle = FilmBoxOfficeTable.title.lowerCase() + val lowerCaseTitles = FilmBoxOfficeTable.select(lowerCaseTitle).map { it[lowerCaseTitle] } + println(lowerCaseTitles) - val upperCaseProduct = SalesTable.product.upperCase().alias("prd_all_caps") - val upperCaseProducts = SalesTable.select(upperCaseProduct).map { it[upperCaseProduct] } - println(upperCaseProducts) + val upperCaseRegion = FilmBoxOfficeTable.region.upperCase().alias("reg_all_caps") + val upperCaseRegions = FilmBoxOfficeTable.select(upperCaseRegion).map { it[upperCaseRegion] } + println(upperCaseRegions) - val fullProductLabel = Concat(separator = " ", SalesTable.product, stringLiteral("||"), SalesTable.label) + val fullFilmTitle = Concat(separator = " ", FilmBoxOfficeTable.region, stringLiteral("||"), FilmBoxOfficeTable.title) .trim() .lowerCase() - val fullProductLabels = SalesTable.select(fullProductLabel).map { it[fullProductLabel] } - println(fullProductLabels) + val fullFilmTitles = FilmBoxOfficeTable.select(fullFilmTitle).map { it[fullFilmTitle] } + println(fullFilmTitles) - val shortenedLabel = SalesTable.label.substring(start = 1, length = 3) - val shortenedLabels = SalesTable.select(shortenedLabel).map { it[shortenedLabel] } - println(shortenedLabels) + val shortenedTitle = FilmBoxOfficeTable.title.substring(start = 1, length = 3) + val shortenedTitles = FilmBoxOfficeTable.select(shortenedTitle).map { it[shortenedTitle] } + println(shortenedTitles) - val productName = concat( + val filmTitle = concat( separator = " - ", - expr = listOf(stringLiteral("Product"), SalesTable.product) + expr = listOf(stringLiteral("Title"), FilmBoxOfficeTable.title) ) - val productNames = SalesTable.select(productName).map { it[productName] } - println(productNames) + val filmTitles = FilmBoxOfficeTable.select(filmTitle).map { it[filmTitle] } + println(filmTitles) - val firstXSIndex = SalesTable.label.locate("XS") - val firstXSIndices = SalesTable.select(firstXSIndex).map { it[firstXSIndex] } + val firstXSIndex = FilmBoxOfficeTable.title.locate("XS") + val firstXSIndices = FilmBoxOfficeTable.select(firstXSIndex).map { it[firstXSIndex] } println(firstXSIndices) - val labelLength = SalesTable.label.charLength() - val labelLengths = SalesTable.select(labelLength).map { it[labelLength] } - println(labelLengths) + val titleLength = FilmBoxOfficeTable.title.charLength() + val titleLengths = FilmBoxOfficeTable.select(titleLength).map { it[titleLength] } + println(titleLengths) } } diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt index 16345e3f66..0e5bf25af8 100644 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/WindowFuncExamples.kt @@ -1,6 +1,6 @@ package org.example.examples -import org.example.tables.SalesTable +import org.example.tables.FilmBoxOfficeTable import org.jetbrains.exposed.sql.SortOrder import org.jetbrains.exposed.sql.SqlExpressionBuilder.rowNumber import org.jetbrains.exposed.sql.WindowFrameBound @@ -14,32 +14,32 @@ import org.jetbrains.exposed.sql.sum class WindowFuncExamples { fun selectWindowFunctions() { - val window1 = SalesTable.amount.sum() + val window1 = FilmBoxOfficeTable.revenue.sum() .over() - .partitionBy(SalesTable.year, SalesTable.product) - .orderBy(SalesTable.amount) - val result1 = SalesTable.select(window1).map { it[window1] } + .partitionBy(FilmBoxOfficeTable.year, FilmBoxOfficeTable.title) + .orderBy(FilmBoxOfficeTable.revenue) + val result1 = FilmBoxOfficeTable.select(window1).map { it[window1] } println(result1) val window2 = rowNumber() .over() - .partitionBy(SalesTable.year, SalesTable.product) - .orderBy(SalesTable.amount) - val result2 = SalesTable.select(window2).map { it[window2] } + .partitionBy(FilmBoxOfficeTable.year, FilmBoxOfficeTable.title) + .orderBy(FilmBoxOfficeTable.revenue) + val result2 = FilmBoxOfficeTable.select(window2).map { it[window2] } println(result2) - val window3 = SalesTable.amount.sum() + val window3 = FilmBoxOfficeTable.revenue.sum() .over() - .orderBy(SalesTable.year to SortOrder.DESC, SalesTable.product to SortOrder.ASC_NULLS_FIRST) - val result3 = SalesTable.select(window3).map { it[window3] } + .orderBy(FilmBoxOfficeTable.year to SortOrder.DESC, FilmBoxOfficeTable.title to SortOrder.ASC_NULLS_FIRST) + val result3 = FilmBoxOfficeTable.select(window3).map { it[window3] } println(result3) - val window4 = SalesTable.amount.sum() + val window4 = FilmBoxOfficeTable.revenue.sum() .over() - .partitionBy(SalesTable.year, SalesTable.product) - .orderBy(SalesTable.amount) + .partitionBy(FilmBoxOfficeTable.year, FilmBoxOfficeTable.title) + .orderBy(FilmBoxOfficeTable.revenue) .range(WindowFrameBound.offsetPreceding(2), WindowFrameBound.currentRow()) - val result4 = SalesTable.select(window4).map { it[window4] } + val result4 = FilmBoxOfficeTable.select(window4).map { it[window4] } println(result4) } } diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/FilmBoxOfficeTable.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/FilmBoxOfficeTable.kt new file mode 100644 index 0000000000..09f17decdd --- /dev/null +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/FilmBoxOfficeTable.kt @@ -0,0 +1,16 @@ +package org.example.tables + +import org.jetbrains.exposed.sql.Table + +const val MAX_TITLE_LENGTH = 150 +const val MAX_REGION_LENGTH = 50 +const val REVENUE_PRECISION = 12 +const val REVENUE_SCALE = 2 + +object FilmBoxOfficeTable : Table() { + val title = varchar("title", MAX_TITLE_LENGTH) + val region = varchar("region", MAX_REGION_LENGTH) + val revenue = decimal("revenue", REVENUE_PRECISION, REVENUE_SCALE) + val month = integer("month") + val year = integer("year") +} diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt deleted file mode 100644 index bb1d68cab4..0000000000 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/tables/SalesTable.kt +++ /dev/null @@ -1,16 +0,0 @@ -package org.example.tables - -import org.jetbrains.exposed.sql.Table - -const val MAX_LABEL_LENGTH = 100 -const val MAX_PRODUCT_LENGTH = 50 -const val AMOUNT_PRECISION = 8 -const val AMOUNT_SCALE = 2 - -object SalesTable : Table() { - val label = varchar("label", MAX_LABEL_LENGTH) - val product = varchar("product", MAX_PRODUCT_LENGTH) - val amount = decimal("amount", AMOUNT_PRECISION, AMOUNT_SCALE) - val month = integer("month") - val year = integer("year") -} diff --git a/documentation-website/Writerside/topics/SQL-Functions.md b/documentation-website/Writerside/topics/SQL-Functions.md index 24543fec83..89e465271e 100644 --- a/documentation-website/Writerside/topics/SQL-Functions.md +++ b/documentation-website/Writerside/topics/SQL-Functions.md @@ -7,21 +7,28 @@ usage examples. It also explains how to define [custom functions](#custom-functi For the function examples below, consider the following table: - + ## How to use functions To retrieve the result of an SQL function result from a query using `.select()`, declare the function as a variable first: - + You can alias this function in the same way you [alias a table or query](DSL-Querying-data.topic#alias): - + SQL functions can be chained and combined as needed. The example below generates SQL that concatenates the string values stored in two columns, before wrapping the function in `TRIM()` and `LOWER()`: - + ## String functions ### Lower case and upper case @@ -30,19 +37,25 @@ and [`.upperCase()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/upper-case.html) functions respectively. - + ### Substring The [`.substring()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/substring.html) function returns a substring value from the specified start and with the specified length. - + ### Concatenate The [`concat()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/concat.html) function returns a string value that concatenates the text representations of all non-null input values, separated by an optional separator. - + This concat() requires import statement import org.jetbrains.exposed.sql.SqlExpressionBuilder.concat. From 2a3d1eef5c6a2399921013be8be8c4ad7e84a6a9 Mon Sep 17 00:00:00 2001 From: Chantal Loncle <82039410+bog-walk@users.noreply.github.com> Date: Thu, 30 Jan 2025 21:28:03 -0500 Subject: [PATCH 4/4] docs: EXPOSED-715 Fix broken custom function examples & move to snippets project - Fix incorrect api links and add missing ones --- .../example/examples/CustomFuncExamples.kt | 14 ++-- .../Writerside/topics/SQL-Functions.md | 72 ++++++++++--------- 2 files changed, 47 insertions(+), 39 deletions(-) diff --git a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt index e9de465d89..f591f7bc5d 100644 --- a/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt +++ b/documentation-website/Writerside/snippets/exposed-sql-functions/src/main/kotlin/org/example/examples/CustomFuncExamples.kt @@ -25,12 +25,12 @@ private const val REVENUE_YEAR = 1999 class CustomFuncExamples { fun selectCustomFunctions() { - val sqrtAmount = FilmBoxOfficeTable.revenue.function("SQRT") - // generates SQL: SQRT(SALES.AMOUNT) + val sqrtRevenue = FilmBoxOfficeTable.revenue.function("SQRT") + // generates SQL: SQRT(SALES.REVENUE) val sqrt = FilmBoxOfficeTable - .select(sqrtAmount) + .select(sqrtRevenue) .singleOrNull() - ?.get(sqrtAmount) + ?.get(sqrtRevenue) println(sqrt) val replacedTitle = CustomFunction( @@ -58,11 +58,11 @@ class CustomFuncExamples { CurrentDate ).month() // generates SQL: MONTH(DATEADD('MONTH', -3, CURRENT_DATE)) - val revenueInLast3Months = FilmBoxOfficeTable + val filmsInLast3Months = FilmBoxOfficeTable .selectAll() .where { FilmBoxOfficeTable.month greater threeMonthsAgo } .map { it[FilmBoxOfficeTable.title] } - println(revenueInLast3Months) + println(filmsInLast3Months) } fun selectCustomTrimFunction() { @@ -77,7 +77,7 @@ class CustomFuncExamples { } val leadingStarWarsTrim = FilmBoxOfficeTable.title.customTrim(stringLiteral("Star Wars:"), TrimSpecifier.LEADING) - val titleWithoutPrefix = FilmBoxOfficeTable.select(leadingStarWarsTrim).single()[leadingStarWarsTrim] // Episode I - The Phantom Menace + val titleWithoutPrefix = FilmBoxOfficeTable.select(leadingStarWarsTrim).single()[leadingStarWarsTrim] // The Phantom Menace - Episode I println(titleWithoutPrefix) val trailingEpisodeTrim = FilmBoxOfficeTable.title.customTrim(stringLiteral("- Episode I"), TrimSpecifier.TRAILING) diff --git a/documentation-website/Writerside/topics/SQL-Functions.md b/documentation-website/Writerside/topics/SQL-Functions.md index 89e465271e..67da25780e 100644 --- a/documentation-website/Writerside/topics/SQL-Functions.md +++ b/documentation-website/Writerside/topics/SQL-Functions.md @@ -91,11 +91,11 @@ You can use SQL functions like `SUM()` and `COUNT()` directly with a column expr ### Statistics Some databases provide aggregate functions specifically for statistics and Exposed provides support for four of these: -[`.stdDevPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/stdDevPop.html), -[`.stdDevSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/stdDevSamp.html), -[`.varPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/varPop.html), -[`.varSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/varSamp.html). -The following example retrieves the population standard deviation of values stored in the `amount` column: +[`.stdDevPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/std-dev-pop.html), +[`.stdDevSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/std-dev-samp.html), +[`.varPop()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/var-pop.html), +[`.varSamp()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/var-samp.html). +The following example retrieves the population standard deviation of values stored in the `revenue` column: @@ -126,16 +126,16 @@ After that, you can provide any amount of additional parameters separated by a c There are also shortcuts for `String`, `Long`, and `DateTime` functions: * [`CustomStringFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-string-function.html) * [`CustomLongFunction`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-custom-long-function.html) -* [`CustomDateTimeFunction`](https://jetbrains.github.io/Exposed/api/exposed-jodatime/org.jetbrains.exposed.sql.jodatime/-custom-date-time-function.html) +* [`CustomDateTimeFunction`](https://jetbrains.github.io/Exposed/api/exposed-kotlin-datetime/org.jetbrains.exposed.sql.kotlin.datetime/-custom-date-time-function.html) Using one of these shortcuts, the example above could be simplified to: -In the following example, `CustomDateFunction` is used in an H2 database to mimic its `DATEADD()` function in order to -calculate a date three months before the current one. -In is then chained with Exposed's built-in `.month()` function to return the month of the date found, -so it can be used in a query: +In the following example, [`CustomDateFunction`](https://jetbrains.github.io/Exposed/api/exposed-kotlin-datetime/org.jetbrains.exposed.sql.kotlin.datetime/-custom-date-function.html) +is used in an H2 database to mimic its `DATEADD()` function in order to calculate a date three months before the current one. +In is then chained with Exposed's built-in [`.month()`](https://jetbrains.github.io/Exposed/api/exposed-kotlin-datetime/org.jetbrains.exposed.sql.kotlin.datetime/month.html) +function to return the month of the date found, so it can be used in a query: @@ -145,7 +145,8 @@ All functions in Exposed extend the abstract class [`Function`](https://jetbrain which takes a column type and allows overriding `toQueryBuilder()`. This is what `CustomFunction` actually does, which can be leveraged to create more complex queries. -For example, Exposed provides a `.trim()` function that removes leading and trailing whitespace from a String. In some databases (like H2 and MySQL), +For example, Exposed provides a [`.trim()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/trim.html) +function that removes leading and trailing whitespace from a String. In some databases (like H2 and MySQL), this is just the default behavior as specifiers can be provided to limit the trim to either leading or trailing. These databases also allow you to provide a specific substring other than spaces to remove. The custom function below supports this extended behavior: @@ -165,30 +166,37 @@ This custom function can then be used to achieve the exact trim that is needed: Window functions allow calculations across a set of table rows that are related to the current row. Existing aggregate functions (like `sum()`, `avg()`) can be used, as well as new rank and value functions: -* `cumeDist()` -* `denseRank()` -* `firstValue()` -* `lag()` -* `lastValue()` -* `lead()` -* `nthValue()` -* `nTile()` -* `percentRank()` -* `rank()` -* `rowNumber()` - -To use a window function, include the `OVER` clause by chaining `.over()` after the function call. A `PARTITION BY` and -`ORDER BY` clause can be optionally chained using `.partitionBy()` and `.orderBy()`, taking multiple arguments: +* [`cumeDist()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/cume-dist.html) +* [`denseRank()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/dense-rank.html) +* [`firstValue()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/first-value.html) +* [`lag()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/lag.html) +* [`lastValue()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/last-value.html) +* [`lead()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/lead.html) +* [`nthValue()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/nth-value.html) +* [`nTile()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/ntile.html) +* [`percentRank()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/percent-rank.html) +* [`rank()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/rank.html) +* [`rowNumber()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-i-sql-expression-builder/row-number.html) + +To use a window function, include the `OVER` clause by chaining +[`.over()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-function/over.html) after the function call. +A `PARTITION BY` and `ORDER BY` clause can be optionally chained using +[`.partitionBy()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-function-definition/partition-by.html) +and [`.orderBy()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-function-definition/order-by.html), +taking multiple arguments: -Frame clause functions, such as `rows()`, `range()`, and `groups()`, are also supported and take a `WindowFrameBound` option -depending on the expected result: -* `WindowFrameBound.currentRow()` -* `WindowFrameBound.unboundedPreceding()` -* `WindowFrameBound.unboundedFollowing()` -* `WindowFrameBound.offsetPreceding()` -* `WindowFrameBound.offsetFollowing()` +Frame clause functions, such as [`rows()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-function-definition/rows.html), +[`range()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-function-definition/range.html), +and [`groups()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-function-definition/groups.html), +are also supported and take a [`WindowFrameBound`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-frame-bound/index.html) +option depending on the expected result: +* [`WindowFrameBound.currentRow()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-frame-bound/-companion/current-row.html) +* [`WindowFrameBound.unboundedPreceding()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-frame-bound/-companion/unbounded-preceding.html) +* [`WindowFrameBound.unboundedFollowing()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-frame-bound/-companion/unbounded-following.html) +* [`WindowFrameBound.offsetPreceding()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-frame-bound/-companion/offset-preceding.html) +* [`WindowFrameBound.offsetFollowing()`](https://jetbrains.github.io/Exposed/api/exposed-core/org.jetbrains.exposed.sql/-window-frame-bound/-companion/offset-following.html)