diff --git a/documentation-website/Writerside/hi.tree b/documentation-website/Writerside/hi.tree index 47ca3b1763..8382b1166a 100644 --- a/documentation-website/Writerside/hi.tree +++ b/documentation-website/Writerside/hi.tree @@ -8,11 +8,19 @@ - - - - - + + + + + + + + + + + + + diff --git a/documentation-website/Writerside/redirection-rules.xml b/documentation-website/Writerside/redirection-rules.xml index 548c5f7a06..4cce403462 100644 --- a/documentation-website/Writerside/redirection-rules.xml +++ b/documentation-website/Writerside/redirection-rules.xml @@ -8,4 +8,37 @@ Created after removal of "Introduction" from Exposed Documentation Introduction.html + + Created after removal of "Working with Database" from Exposed Documentation + Working-with-databases.html + + + Created after removal of "Working with DataSource" from Exposed Documentation + Working-with-data-sources.html + + + Created after removal of "Working with Transaction" from Exposed Documentation + Working-with-transactions.html + + + " from Exposed Documentation]]> + Samples-md.html + + + Created after removal of "Transactions" from Exposed Documentation + Transactions.html + + + + " from Exposed Documentation]]> + Working-with-Coroutines.html + + + Created after removal of "DAO API" from Exposed Documentation + DAO-API.html + + + Created after removal of "DSL API" from Exposed Documentation + DSL-API.html + diff --git a/documentation-website/Writerside/topics/Asynchronous-Support.md b/documentation-website/Writerside/topics/Asynchronous-Support.md new file mode 100644 index 0000000000..ed06fe1b31 --- /dev/null +++ b/documentation-website/Writerside/topics/Asynchronous-Support.md @@ -0,0 +1,60 @@ +# Asynchronous Support + +## Working with Coroutines + +In the modern world, non-blocking and asynchronous code is popular. Kotlin +has [Coroutines](https://kotlinlang.org/docs/reference/coroutines-overview.html) that give you an imperative way of writing asynchronous code. Most +Kotlin frameworks (like [ktor](https://ktor.io)) have built-in support for Coroutines while Exposed is mostly blocking. Why? Because Exposed uses JDBC API to interact +with databases that was designed in an era of blocking APIs. Moreover, Exposed stores some values in +thread-local variables while coroutines could (and will) be executed in different threads. + +Since Exposed 0.15.1, there are bridge functions that will give you a safe way to interact with Exposed within `suspend` +blocks: `newSuspendedTransaction/Transaction.withSuspendTransaction` have the same parameters as a blocking `transaction` function but will allow you to +provide a `CoroutineDispatcher` in which the function will be executed. If context is not provided, your code will be executed within the current `coroutineContext`. + +Sample usage looks like: + +```kotlin +runBlocking { + transaction { + SchemaUtils.create(FooTable) // Table will be created on a current thread + + newSuspendedTransaction(Dispatchers.Default) { + FooTable.insert { it[id] = 1 } // This insert will be executed in one of Default dispatcher threads + + withSuspendTransaction { + val id = FooTable.select { FooTable.id eq 1 } + .single()()[FooTable.id] // This select also will be executed on some thread from Default dispatcher using the same transaction + } + } + + val result = newSuspendedTransaction(Dispatchers.IO) { + FooTable.select { FooTable.id eq 1 } + .single()[H2Tests.Testing.id] // This select will be executed on some thread from IO dispatcher using the same transaction + } + } +} + +``` + +Please note that such code remains blocking (as it still uses JDBC) and you should not try to share a transaction between multiple threads as it will +lead to undefined behaviour. + +If you want to execute some code asynchronously and use the result later in your code, take a look at `suspendedTransactionAsync` function. + +```kotlin +val launchResult = suspendedTransactionAsync(Dispatchers.IO, db = db) { + FooTable.insert {} + + FooTable.select { FooTable.id eq 1 }.singleOrNull()?.getOrNull(Testing.id) +} + +println("Result: " + (launchResult.await() ?: - 1)) + +``` + +This function will accept the same parameters as `newSuspendedTransaction` above, but returns `Deferred` which you could call `await` on to achieve your +result. + +`suspendedTransactionAsync` is always executed in a new transaction to prevent concurrency issues when queries execution order could be changed +by `CoroutineDispatcher`. diff --git a/documentation-website/Writerside/topics/Database-and-DataSource.md b/documentation-website/Writerside/topics/Database-and-DataSource.md deleted file mode 100644 index b2e1b91bce..0000000000 --- a/documentation-website/Writerside/topics/Database-and-DataSource.md +++ /dev/null @@ -1,177 +0,0 @@ -# Database and DataSource - -## Working with Database and DataSource -Every database access using Exposed is starting by obtaining a connection and creating a transaction. -First of all, you have to tell Exposed how to connect to a database by using `Database.connect` function. -It won't create a real database connection but only provide a descriptor for future usage. - -A real connection will be instantiated later by calling `transaction` lambda (see [Transaction](Transactions.md) for more details). - -To get a Database instance by simple providing connection parameters: -```kotlin -val db = Database.connect("jdbc:h2:mem:test", driver = "org.h2.Driver") -``` -It is also possible to provide `javax.sql.DataSource` for advanced behaviors such as connection pooling: -```kotlin -val db = Database.connect(dataSource) -``` -* Note: Starting Exposed 0.10 executing this code more than once per db will create leaks in your application, hence it is recommended to store it for later use. - For example: -```kotlin -object DbSettings { - val db by lazy { - Database.connect(/* setup connection */) - } -} -``` -## DataSource - - -### PostgreSQL -Add dependency: -```kotlin -implementation("org.postgresql:postgresql:42.2.2") -``` - -Connect to database: -```kotlin -Database.connect( - "jdbc:postgresql://localhost:12346/test", - driver = "org.postgresql.Driver", - user = "user", - password = "password" -) -``` - -### PostgreSQL using the pgjdbc-ng JDBC driver - -Add dependency: -```kotlin -implementation("com.impossibl.pgjdbc-ng", "pgjdbc-ng", "0.8.3") -``` - -Connect to database: -```kotlin -Database.connect( - "jdbc:pgsql://localhost:12346/test", - driver = "com.impossibl.postgres.jdbc.PGDriver", - user = "user", - password = "password" -) -``` -### MySQL/MariaDB - -Add dependency: -```kotlin -implementation("mysql:mysql-connector-java:8.0.2") -``` - -Connect to database: -```kotlin -Database.connect( - "jdbc:mysql://localhost:3306/test", - driver = "com.mysql.cj.jdbc.Driver", - user = "user", - password = "password" -) -``` - -### MySQL/MariaDB with latest JDBC driver + Hikari pooling - -Add dependency: -```kotlin -implementation("mysql:mysql-connector-java:8.0.19") -implementation("com.zaxxer:HikariCP:3.4.2") -``` - -Connect to database: -```kotlin -val config = HikariConfig().apply { - jdbcUrl = "jdbc:mysql://localhost/dbname" - driverClassName = "com.mysql.cj.jdbc.Driver" - username = "user" - password = "password" - maximumPoolSize = 10 -} -val dataSource = HikariDataSource(config) -Database.connect(dataSource) -``` - -### Oracle - -Add Dependency: -```kotlin -implementation("com.oracle.database.jdbc:ojdbc8:12.2.0.1") -``` - -Then connect to database: -```kotlin -Database.connect( - "jdbc:oracle:thin:@//localhost:1521/test", - driver = "oracle.jdbc.OracleDriver", - user = "user", - password = "password" -) -``` - -### SQLite - -In order to use SQLite, you need to add the dependency to the SQLite JDBC driver. -```kotlin -implementation("org.xerial:sqlite-jdbc:3.30.1") -``` - -Then connect to file-database: -```kotlin -Database.connect("jdbc:sqlite:/data/data.db", "org.sqlite.JDBC") -``` - -Or in-memory database: -```kotlin -Database.connect("jdbc:sqlite:file:test?mode=memory&cache=shared", "org.sqlite.JDBC") -``` - -For both: set SQLite compatible isolation level: [FAQ](Frequently-Asked-Questions.md). -```kotlin -TransactionManager.manager.defaultIsolationLevel = Connection.TRANSACTION_SERIALIZABLE - // or Connection.TRANSACTION_READ_UNCOMMITTED -``` - -### H2 - -In order to use H2, you need to add the dependency to the H2 driver: -```kotlin -implementation("com.h2database:h2:2.1.214") -``` - -Then connect to database in file: -```kotlin -Database.connect("jdbc:h2:./myh2file", "org.h2.Driver") -``` - -Or in memory: -```kotlin -Database.connect("jdbc:h2:mem:regular", "org.h2.Driver") -``` - -By default, H2 closes the database when the last connection is closed. If you want to keep the database open, you can use the DB_CLOSE_DELAY=-1 option: -```kotlin -Database.connect("jdbc:h2:mem:regular;DB_CLOSE_DELAY=-1;", "org.h2.Driver") -``` - -### MSSQL Server - -Add dependency: -```kotlin -implementation("com.microsoft.sqlserver:mssql-jdbc:6.4.0.jre7") -``` - -Connect to database: -```kotlin -Database.connect( - "jdbc:sqlserver://localhost:32768;databaseName=test", - "com.microsoft.sqlserver.jdbc.SQLServerDriver", - user = "user", - password = "password" -) -``` diff --git a/documentation-website/Writerside/topics/Databases.md b/documentation-website/Writerside/topics/Databases.md new file mode 100644 index 0000000000..c1b8d356f4 --- /dev/null +++ b/documentation-website/Writerside/topics/Databases.md @@ -0,0 +1,7 @@ +# Databases + +[Working with Database](Working-with-Database.md) + +[Working with DataSource](Working-with-DataSource.md) + +[Working with Transaction](Working-with-Transaction.md) diff --git a/documentation-website/Writerside/topics/DAO-API.md b/documentation-website/Writerside/topics/Deep-Dive-into-DAO.md similarity index 99% rename from documentation-website/Writerside/topics/DAO-API.md rename to documentation-website/Writerside/topics/Deep-Dive-into-DAO.md index e3dff473a1..328035b3c8 100644 --- a/documentation-website/Writerside/topics/DAO-API.md +++ b/documentation-website/Writerside/topics/Deep-Dive-into-DAO.md @@ -1,4 +1,4 @@ -# DAO API +# Deep Dive into DAO ## Overview The DAO (Data Access Object) API of Exposed, is similar to ORM frameworks like Hibernate with a Kotlin-specific API. diff --git a/documentation-website/Writerside/topics/DSL-API.md b/documentation-website/Writerside/topics/Deep-Dive-into-DSL.md similarity index 59% rename from documentation-website/Writerside/topics/DSL-API.md rename to documentation-website/Writerside/topics/Deep-Dive-into-DSL.md index ad47fe8f86..5e9b8fd152 100644 --- a/documentation-website/Writerside/topics/DSL-API.md +++ b/documentation-website/Writerside/topics/Deep-Dive-into-DSL.md @@ -1,84 +1,151 @@ -# DSL API +# Deep Dive into DSL ## Overview -The DSL (Domain Specific Language) API of Exposed, is similar to actual SQL statements with type safety that Kotlin offers. -A DB table is represented by an `object` inherited from `org.jetbrains.exposed.sql.Table` like this: + +The DSL (Domain-Specific Language) API of Exposed is similar to actual SQL statements, but with the type safety that Kotlin offers. + +A database table is represented by an `object` inherited from `org.jetbrains.exposed.sql.Table` like this: + ```kotlin object StarWarsFilms : Table() { - val id: Column = integer("id").autoIncrement() - val sequelId: Column = integer("sequel_id").uniqueIndex() - val name: Column = varchar("name", 50) - val director: Column = varchar("director", 50) - override val primaryKey = PrimaryKey(id, name = "PK_StarWarsFilms_Id") // PK_StarWarsFilms_Id is optional here + val id: Column = integer("id").autoIncrement() + val sequelId: Column = integer("sequel_id").uniqueIndex() + val name: Column = varchar("name", 50) + val director: Column = varchar("director", 50) + override val primaryKey = PrimaryKey(id, name = "PK_StarWarsFilms_Id") // PK_StarWarsFilms_Id is optional here } ``` + Tables that contains `Int` id with the name `id` can be declared like this: + ```kotlin object StarWarsFilms : IntIdTable() { - val sequelId: Column = integer("sequel_id").uniqueIndex() - val name: Column = varchar("name", 50) - val director: Column = varchar("director", 50) + val sequelId: Column = integer("sequel_id").uniqueIndex() + val name: Column = varchar("name", 50) + val director: Column = varchar("director", 50) } ``` -## Basic CRUD operations + +## CRUD operations + +CRUD stands for Create Read Update Delete, which are four basic operations for a database to support. This section shows how to perform SQL CRUD operations +using Kotlin DSL. + ### Create + +To create a new table row, you use the `insert` query. Exposed provides several functions to insert rows into a table: + +* `insert` adds a new row. If the same row already exists in the table, it throws an exception. + ```kotlin + // SQL: INSERT INTO CITIES (COUNTRY, "NAME", POPULATION) + // VALUES ('RUSSIA', 'St. Petersburg', 300) + Cities.insert { + it[name] = "St. Petersburg" + it[country] = Country.RUSSIA + it[population] = 500 + } + ``` +* `insertAndGetId` adds a new row and returns its ID. If the same row already exists in the table, it throws an exception. Works only with IntIdTable() tables. + ```kotlin + // SQL: INSERT INTO CITIES (COUNTRY, "NAME", POPULATION) + // VALUES ('RUSSIA', 'St. Petersburg', 300) + val id = Cities.insertAndGetId { + it[name] = "St. Petersburg" + it[country] = Country.RUSSIA + it[population] = 500 + } + ``` +* `insertIgnore` adds a new row. If the same row already exists in the table, it ignores it and doesn't throw an exception. This function is supported only for MySQL. + ```kotlin + // SQL: INSERT IGNORE INTO CITIES (COUNTRY, "NAME", POPULATION) + // VALUES ('RUSSIA', 'St. Petersburg', 300) + val id = Cities.insertIgnore { + it[name] = "St. Petersburg" + it[country] = Country.RUSSIA + it[population] = 500 + } + ``` +* `insertIgnoreAndGetId` adds a new row and returns its ID. If the same row already exists in the table, it ignores it and doesn't throw an exception. This function + is supported only for MySQL. Works only with IntIdTable() tables. + ```kotlin + // SQL: INSERT IGNORE INTO CITIES (COUNTRY, "NAME", POPULATION) + // VALUES ('RUSSIA', 'St. Petersburg', 300) + val id = Cities.insertIgnoreAndGetId { + it[name] = "St. Petersburg" + it[country] = Country.RUSSIA + it[population] = 500 + } + ``` + ```kotlin val id = StarWarsFilms.insertAndGetId { - it[name] = "The Last Jedi" - it[sequelId] = 8 - it[director] = "Rian Johnson" + it[name] = "The Last Jedi" + it[sequelId] = 8 + it[director] = "Rian Johnson" } ``` + ### Read + ```kotlin val query: Query = StarWarsFilms.select { StarWarsFilms.sequelId eq 8 } ``` + `Query` inherit `Iterable` so it is possible to traverse it with map/foreach etc'. For example: + ```kotlin StarWarsFilms.select { StarWarsFilms.sequelId eq 8 }.forEach { - println(it[StarWarsFilms.name]) + println(it[StarWarsFilms.name]) } ``` + There is `slice` function which allows you to select specific columns or/and expressions. + ```kotlin -val filmAndDirector = StarWarsFilms. - slice(StarWarsFilms.name, StarWarsFilms.director). - selectAll().map { - it[StarWarsFilms.name] to it[StarWarsFilms.director] - } +val filmAndDirector = StarWarsFilms.slice(StarWarsFilms.name, StarWarsFilms.director).selectAll().map { + it[StarWarsFilms.name] to it[StarWarsFilms.director] +} ``` + If you want to select only distinct value then use `withDistinct()` function: + ```kotlin -val directors = StarWarsFilms. - slice(StarWarsFilms.director). - select { StarWarsFilms.sequelId less 5 }. - withDistinct().map { - it[StarWarsFilms.director] - } +val directors = StarWarsFilms.slice(StarWarsFilms.director).select { StarWarsFilms.sequelId less 5 }.withDistinct().map { + it[StarWarsFilms.director] +} ``` + ### Update + ```kotlin -StarWarsFilms.update ({ StarWarsFilms.sequelId eq 8 }) { - it[StarWarsFilms.name] = "Episode VIII – The Last Jedi" +StarWarsFilms.update({ StarWarsFilms.sequelId eq 8 }) { + it[StarWarsFilms.name] = "Episode VIII – The Last Jedi" } ``` + If you want to update column value with some expression like increment use `update` function or setter: + ```kotlin StarWarsFilms.update({ StarWarsFilms.sequelId eq 8 }) { with(SqlExpressionBuilder) { - it.update(StarWarsFilms.sequelId, StarWarsFilms.sequelId + 1) - // or - it[StarWarsFilms.sequelId] = StarWarsFilms.sequelId + 1 + it.update(StarWarsFilms.sequelId, StarWarsFilms.sequelId + 1) + // or + it[StarWarsFilms.sequelId] = StarWarsFilms.sequelId + 1 } } ``` + ### Delete + ```kotlin StarWarsFilms.deleteWhere { StarWarsFilms.sequelId eq 8 } ``` + ## Where expression + Query expression (where) expects a boolean operator (ie: `Op`). Allowed conditions are: + ``` eq - (==) neq - (!=) @@ -99,42 +166,52 @@ notInList between match (MySQL MATCH AGAINST) ``` + Allowed logical conditions are: + ``` not and or ``` + ## Conditional where -It rather common case when your query's `where` condition depends on some other code conditions. Moreover, it could be independent or nested conditions what make it more complicated to prepare such `where`. + +It rather common case when your query's `where` condition depends on some other code conditions. Moreover, it could be independent or nested conditions what make it +more complicated to prepare such `where`. Let's imagine that we have a form on a website where a user can optionally filter "Star Wars" films by a director and/or a sequel. In Exposed version before 0.8.1 you had to code it like: + ```Kotlin val condition = when { - directorName != null && sequelId != null -> + directorName!=null && sequelId!=null -> Op.build { StarWarsFilms.director eq directorName and (StarWarsFilms.sequelId eq sequelId) } - directorName != null -> + directorName!=null -> Op.build { StarWarsFilms.director eq directorName } - sequelId != null -> + sequelId!=null -> Op.build { StarWarsFilms.sequelId eq sequelId } else -> null } val query = condition?.let { StarWarsFilms.select(condition) } ?: StarWarsFilms.selectAll() ``` + or + ```Kotlin val query = when { - directorName != null && sequelId != null -> + directorName!=null && sequelId!=null -> StarWarsFilms.select { StarWarsFilms.director eq directorName and (StarWarsFilms.sequelId eq sequelId) } - directorName != null -> + directorName!=null -> StarWarsFilms.select { StarWarsFilms.director eq directorName } - sequelId != null -> + sequelId!=null -> StarWarsFilms.select { StarWarsFilms.sequelId eq sequelId } else -> StarWarsFilms.selectAll() } ``` + This is a very primitive example, but you should get the main idea about the problem. Now let's try to write the same query in a more simple way (`andWhere` function available since 0.10.5): + ```Kotlin val query = StarWarsFilms.selectAll() directorName?.let { @@ -144,35 +221,49 @@ sequelId?.let { query.andWhere { StarWarsFilms.sequelId eq it } } ``` + But what if we want to conditionally select from another table and join it only when a condition is true? -You have to use `adjustColumnSet` and `adjustSlice` functions (available since 0.8.1) which allows to extend and modify `join` and `slice` parts of a query (see kdoc on that functions): +You have to use `adjustColumnSet` and `adjustSlice` functions (available since 0.8.1) which allows to extend and modify `join` and `slice` parts of a query (see kdoc +on that functions): + ```Kotlin actorName?.let { - query.adjustColumnSet { innerJoin(Actors, {StarWarsFilms.sequelId}, {Actors.sequelId}) } + query.adjustColumnSet { innerJoin(Actors, { StarWarsFilms.sequelId }, { Actors.sequelId }) } .adjustSlice { slice(fields + Actors.columns) } .andWhere { Actors.name eq actorName } } ``` + ## Count + `count()` is a method of `Query` that is used like below example: + ```kotlin -val count = StarWarsFilms.select { StarWarsFilms.sequelId eq 8 }.count() +val count = StarWarsFilms.select { StarWarsFilms.sequelId eq 8 }.count() ``` + ## Order-by + Order-by accepts a list of columns mapped to boolean indicates if sorting should be ascending or descending. Example: + ```kotlin StarWarsFilms.selectAll().orderBy(StarWarsFilms.sequelId to SortOrder.ASC) ``` + ## Group-by + In group-by, define fields and their functions (such as `count`) by the `slice()` method. + ```kotlin StarWarsFilms - .slice(StarWarsFilms.sequelId.count(), StarWarsFilms.director) - .selectAll() - .groupBy(StarWarsFilms.director) + .slice(StarWarsFilms.sequelId.count(), StarWarsFilms.director) + .selectAll() + .groupBy(StarWarsFilms.director) ``` + Available functions are: + ``` count sum @@ -181,84 +272,108 @@ min average ... ``` + ## Limit + You can use limit function to prevent loading large data sets or use it for pagination with second `offset` parameter. + ```kotlin // Take 2 films after the first one. StarWarsFilms.select { StarWarsFilms.sequelId eq Actors.sequelId }.limit(2, offset = 1) ``` + ## Join + For the join examples below, consider the following tables: + ```kotlin object StarWarsFilms : IntIdTable() { - val sequelId: Column = integer("sequel_id").uniqueIndex() - val name: Column = varchar("name", 50) - val director: Column = varchar("director", 50) + val sequelId: Column = integer("sequel_id").uniqueIndex() + val name: Column = varchar("name", 50) + val director: Column = varchar("director", 50) } object Actors : IntIdTable() { - val sequelId: Column = integer("sequel_id").uniqueIndex() - val name: Column = varchar("name", 50) + val sequelId: Column = integer("sequel_id").uniqueIndex() + val name: Column = varchar("name", 50) } object Roles : Table() { - val sequelId: Column = integer("sequel_id") - val actorId: Column> = reference("actor_id", Actors) - val characterName: Column = varchar("name", 50) + val sequelId: Column = integer("sequel_id") + val actorId: Column> = reference("actor_id", Actors) + val characterName: Column = varchar("name", 50) } ``` + Join to count how many actors star in each movie: + ```kotlin Actors.join(StarWarsFilms, JoinType.INNER, onColumn = Actors.sequelId, otherColumn = StarWarsFilms.sequelId) - .slice(Actors.name.count(), StarWarsFilms.name) - .selectAll() - .groupBy(StarWarsFilms.name) + .slice(Actors.name.count(), StarWarsFilms.name) + .selectAll() + .groupBy(StarWarsFilms.name) ``` + Instead of specifying `onColumn` and `otherColumn`, `additionalConstraint` can be used (and allows specifying other types of join conditions). + ```kotlin -Actors.join(StarWarsFilms, JoinType.INNER, additionalConstraint = {StarWarsFilms.sequelId eq Actors.sequelId}) - .slice(Actors.name.count(), StarWarsFilms.name) - .selectAll() - .groupBy(StarWarsFilms.name) +Actors.join(StarWarsFilms, JoinType.INNER, additionalConstraint = { StarWarsFilms.sequelId eq Actors.sequelId }) + .slice(Actors.name.count(), StarWarsFilms.name) + .selectAll() + .groupBy(StarWarsFilms.name) ``` + When joining on a foreign key, the more concise `innerJoin` can be used: + ```kotlin (Actors innerJoin Roles) - .slice(Roles.characterName.count(), Actors.name) - .selectAll() - .groupBy(Actors.name) - .toList() + .slice(Roles.characterName.count(), Actors.name) + .selectAll() + .groupBy(Actors.name) + .toList() ``` + This is equivalent to the following: + ```kotlin Actors.join(Roles, JoinType.INNER, onColumn = Actors.id, otherColumn = Roles.actorId) - .slice(Roles.characterName.count(), Actors.name) - .selectAll() - .groupBy(Actors.name) - .toList() + .slice(Roles.characterName.count(), Actors.name) + .selectAll() + .groupBy(Actors.name) + .toList() ``` + ## Union + You can combine the results of multiple queries using using `.union(...)`. Per the SQL specification, the queries must have the same number of columns, and not be marked for update. Subqueries may be combined when supported by the database. + ```kotlin val lucasDirectedQuery = StarWarsFilms.slice(StarWarsFilms.name).select { StarWarsFilms.director eq "George Lucas" } val abramsDirectedQuery = StarWarsFilms.slice(StarWarsFilms.name).select { StarWarsFilms.director eq "J.J. Abrams" } val filmNames = lucasDirectedQuery.union(abramsDirectedQuery).map { it[StarWarsFilms.name] } ``` + Only unique rows are returned by default. Duplicates may be returned using `.unionAll()`. + ```kotlin val lucasDirectedQuery = StarWarsFilms.slice(StarWarsFilms.name).select { StarWarsFilms.director eq "George Lucas" } val originalTrilogyQuery = StarWarsFilms.slice(StarWarsFilms.name).select { StarWarsFilms.sequelId inList (3..5) } val filmNames = lucasDirectedQuery.unionAll(originalTrilogyQuery).map { it[StarWarsFilms.name] } ``` + ## Alias + Aliases allow preventing ambiguity between field names and table names. Use the aliased var instead of original one: + ```Kotlin val filmTable1 = StarWarsFilms.alias("ft1") filmTable1.selectAll() // can be used in joins etc' ``` + Also, aliases allow you to use the same table in a join multiple times: + ```Kotlin val sequelTable = StarWarsFilms.alias("sql") val originalAndSequelNames = StarWarsFilms @@ -267,7 +382,9 @@ val originalAndSequelNames = StarWarsFilms .selectAll() .map { it[StarWarsFilms.name] to it[sequelTable[StarWarsFilms.name]] } ``` + And they can be used when selecting from sub-queries: + ```kotlin val starWarsFilms = StarWarsFilms .slice(StarWarsFilms.id, StarWarsFilms.name) @@ -280,8 +397,11 @@ starWarsFilms .selectAll() .map { it[id] to it[name] } ``` + ## Schema + You can create a schema or drop an existing one: + ```Kotlin val schema = Schema("my_schema") // my_schema is the schema name. // Creates a Schema @@ -289,75 +409,106 @@ SchemaUtils.createSchema(schema) // Drops a Schema SchemaUtils.dropSchema(schema) ``` + Also, you can specify the schema owner like this (some databases require the explicit owner) : + ```Kotlin val schema = Schema("my_schema", authorization = "owner") ``` + If you have many schemas and you want to set a default one, you can use: + ```Kotlin SchemaUtils.setSchema(schema) ``` + ## Sequence + If you want to use Sequence, Exposed allows you to: + ### Define a Sequence + ```Kotlin val myseq = Sequence("my_sequence") // my_sequence is the sequence name. ``` + Several parameters can be specified to control the properties of the sequence: + ```Kotlin private val myseq = Sequence( - name = "my_sequence", - startWith = 4, - incrementBy = 2, - minValue = 1, - maxValue = 10, - cycle = true, - cache = 20 - ) + name = "my_sequence", + startWith = 4, + incrementBy = 2, + minValue = 1, + maxValue = 10, + cycle = true, + cache = 20 +) ``` + ### Create and Drop a Sequence + ```Kotlin // Creates a sequence SchemaUtils.createSequence(myseq) // Drops a sequence SchemaUtils.dropSequence(myseq) ``` + ### Use the NextVal function + You can use the nextVal function like this: + ```Kotlin val nextVal = myseq.nextVal() val id = StarWarsFilms.insertAndGetId { - it[id] = nextVal - it[name] = "The Last Jedi" - it[sequelId] = 8 - it[director] = "Rian Johnson" + it[id] = nextVal + it[name] = "The Last Jedi" + it[sequelId] = 8 + it[director] = "Rian Johnson" } ``` + ```Kotlin val firstValue = StarWarsFilms.slice(nextVal).selectAll().single()[nextVal] ``` + ## Batch Insert -Batch Insert allow mapping a list of entities into DB raws in one sql statement. It is more efficient than inserting one by one as it initiates only one statement. Here is an example: + +Batch Insert allow mapping a list of entities into DB raws in one sql statement. It is more efficient than inserting one by one as it initiates only one statement. +Here is an example: + ```kotlin val cityNames = listOf("Paris", "Moscow", "Helsinki") val allCitiesID = cities.batchInsert(cityNames) { name -> - this[cities.name] = name + this[cities.name] = name } ``` -*NOTE:* The `batchInsert` function will still create multiple `INSERT` statements when interacting with your database. You most likely want to couple this with the `rewriteBatchedInserts=true` (or `rewriteBatchedStatements=true`) option of your relevant JDBC driver, which will convert those into a single bulkInsert. -You can find the documentation for this option for MySQL [here](https://dev.mysql.com/doc/connector-j/5.1/en/connector-j-reference-configuration-properties.html) and PostgreSQL [here](https://jdbc.postgresql.org/documentation/use/). -If you don't need to get the newly generated values (example: auto incremented ID), set the `shouldReturnGeneratedValues` parameter to false, this increases the performance of batch inserts by batching them in chunks, instead of always waiting for the database to synchronize the newly inserted object state. +*NOTE:* The `batchInsert` function will still create multiple `INSERT` statements when interacting with your database. You most likely want to couple this with +the `rewriteBatchedInserts=true` (or `rewriteBatchedStatements=true`) option of your relevant JDBC driver, which will convert those into a single bulkInsert. +You can find the documentation for this option for MySQL [here](https://dev.mysql.com/doc/connector-j/5.1/en/connector-j-reference-configuration-properties.html) and +PostgreSQL [here](https://jdbc.postgresql.org/documentation/use/). -If you want to check if the `rewriteBatchedInserts` + `batchInsert` is working correctly, check how to enable JDBC logging for your driver because Exposed will always show the non-rewritten multiple inserts. You can find the documentation for how to enable logging in PostgreSQL [here](https://jdbc.postgresql.org/documentation/logging/). +If you don't need to get the newly generated values (example: auto incremented ID), set the `shouldReturnGeneratedValues` parameter to false, this increases the +performance of batch inserts by batching them in chunks, instead of always waiting for the database to synchronize the newly inserted object state. + +If you want to check if the `rewriteBatchedInserts` + `batchInsert` is working correctly, check how to enable JDBC logging for your driver because Exposed will always +show the non-rewritten multiple inserts. You can find the documentation for how to enable logging in +PostgreSQL [here](https://jdbc.postgresql.org/documentation/logging/). ## Insert From Select + If you want to use `INSERT INTO ... SELECT ` SQL clause try Exposed analog `Table.insert(Query)`. + ```kotlin val substring = users.name.substring(1, 2) cities.insert(users.slice(substring).selectAll().orderBy(users.id).limit(2)) ``` -By default it will try to insert into all non auto-increment `Table` columns in order they defined in Table instance. If you want to specify columns or change the order, provide list of columns as second parameter: + +By default it will try to insert into all non auto-increment `Table` columns in order they defined in Table instance. If you want to specify columns or change the +order, provide list of columns as second parameter: + ```kotlin val userCount = users.selectAll().count() users.insert(users.slice(stringParam("Foo"), Random().castTo(VarCharColumnType()).substring(1, 10)).selectAll(), columns = listOf(users.name, users.id)) diff --git a/documentation-website/Writerside/topics/Getting-Started.md b/documentation-website/Writerside/topics/Getting-Started.md index 8a40fd19da..e8a0bb4407 100644 --- a/documentation-website/Writerside/topics/Getting-Started.md +++ b/documentation-website/Writerside/topics/Getting-Started.md @@ -1,6 +1,6 @@ # Getting Started -## Adding Dependency +## Adding the Exposed dependency @@ -32,7 +32,7 @@ ]]> - + @@ -40,16 +40,16 @@ val exposedVersion: String = "0.40.1" dependencies { - implementation("org.jetbrains.exposed:exposed-core", exposedVersion) - implementation("org.jetbrains.exposed:exposed-dao", exposedVersion) - implementation("org.jetbrains.exposed:exposed-jdbc", exposedVersion) +implementation("org.jetbrains.exposed:exposed-core", exposedVersion) +implementation("org.jetbrains.exposed:exposed-dao", exposedVersion) +implementation("org.jetbrains.exposed:exposed-jdbc", exposedVersion) } ]]> - + -- Note: There are another modules. Detailed information located in [Modules Documentation](Modules-Documentation.md) section. +- Note: There are other modules. Detailed information is located in [Modules Documentation](Modules-Documentation.md) section. ## Starting a transaction @@ -67,100 +67,203 @@ It is also possible to provide `javax.sql.DataSource` for advanced behaviors suc Database.connect(dataSource) ``` -More details on [Database and DataSource](Database-and-DataSource.md) +More details in [Databases](Databases.md) -After obtaining a connection all SQL statements should be placed inside a transaction: +After obtaining a connection, all SQL statements should be placed inside a transaction: ```kotlin transaction { - // Statements here + // Statements here } ``` -To see the actual DB calls, add a logger: +To see the actual database calls, add a logger: ```kotlin transaction { - // print sql to std-out - addLogger(StdOutSqlLogger) + // print SQL to stdout + addLogger(StdOutSqlLogger) } ``` -### DSL & DAO - -Exposed comes in two flavors: DSL (Domain Specific Language) and DAO (Data Access Object). -On a high level, DSL means type-safe syntax that is similar to SQL whereas DAO means doing CRUD operations on entities. -Observe the below examples and head on to the specific section of each API for more details. +## Access Layers -### Your first Exposed DSL +Exposed comes in two flavors: DSL and DAO. -```kotlin +- DSL stands for Domain-Specific Language, and for Exposed it means type-safe syntax similar to SQL statements to access a database. For more + information, see [Deep Dive into DSL](Deep-Dive-into-DSL.md). +- DAO means Data Access Object, and it allows treating the data from database as entities and performing CRUD operations. For more information, see + [Deep Dive into DAO](Deep-Dive-into-DAO.md). -fun main(args: Array) { - //an example connection to H2 DB - Database.connect("jdbc:h2:mem:test", driver = "org.h2.Driver") - - transaction { - // print sql to std-out - addLogger(StdOutSqlLogger) +To get an idea of the difference, compare the following code samples and corresponding SQL outputs: - SchemaUtils.create (Cities) - - // insert new city. SQL: INSERT INTO Cities (name) VALUES ('St. Petersburg') - val stPeteId = Cities.insert { - it[name] = "St. Petersburg" - } get Cities.id - - // 'select *' SQL: SELECT Cities.id, Cities.name FROM Cities - println("Cities: ${Cities.selectAll()}") - } + + + + + + + + + = integer("population").uniqueIndex() +val country = Cities.customEnumeration( +"country", +"ENUM('RUSSIA', 'CHINA', 'USA', 'UNKNOWN')", +{ Country.values()[it as Int] }, +{ it.name } +).default(Country.UNKNOWN) +override val primaryKey = PrimaryKey(id, name = "Cities_ID") +} +class City(id: EntityID) : IntEntity(id) { +companion object : IntEntityClass(Cities) -fun main(args: Array) { - //an example connection to H2 DB - Database.connect("jdbc:h2:mem:test", driver = "org.h2.Driver") + var name by Cities.name + var country by Cities.country + var population by Cities.population - transaction { - // print sql to std-out - addLogger(StdOutSqlLogger) +} - SchemaUtils.create (Cities) +enum class Country { +RUSSIA, CHINA, USA, UNKNOWN +} - // insert new city. SQL: INSERT INTO Cities (name) VALUES ('St. Petersburg') - val stPete = City.new { +fun init() { +Database.connect( +"jdbc:h2:mem:test;DB_CLOSE_DELAY=-1", +driver = "org.h2.Driver" +) + + transaction { + // print sql calls to stdout + addLogger(StdOutSqlLogger) + + // create a table Cities + SchemaUtils.create(Cities) + + // insert a new city + val ny = City.new { + name = "New York" + country = Country.USA + population = 1000 + } + + // insert a new city + val mos = City.new { + name = "Moscow" + country = Country.RUSSIA + population = 500 + } + + // insert a new city + val stPet = City.new { name = "St. Petersburg" + country = Country.RUSSIA + population = 300 + } } - // 'select *' SQL: SELECT Cities.id, Cities.name FROM Cities - println("Cities: ${City.all()}") - } -} - -object Cities: IntIdTable() { - val name = varchar("name", 50) } -class City(id: EntityID) : IntEntity(id) { - companion object : IntEntityClass(Cities) - - var name by Cities.name +fun main() { +init() } -``` - -More information: [DAO API](DAO-API.md) +]]> + + + -Read Next [Database and DataSource](Database-and-DataSource.md) +SQL output: + + +SQL: SELECT VALUE FROM INFORMATION_SCHEMA.SETTINGS WHERE NAME = 'MODE' +SQL: CREATE TABLE IF NOT EXISTS CITIES ( + ID INT AUTO_INCREMENT, + "NAME" VARCHAR(50) DEFAULT 'Unknown' NOT NULL, + POPULATION INT NULL, + COUNTRY ENUM('RUSSIA', 'CHINA', 'USA') NULL, + CONSTRAINT Cities_ID PRIMARY KEY (ID) +) +SQL: INSERT INTO CITIES (COUNTRY, "NAME", POPULATION) VALUES ('USA', 'New York', 1000) +SQL: INSERT INTO CITIES (COUNTRY, "NAME", POPULATION) VALUES ('RUSSIA', 'Moscow', 500) +SQL: INSERT INTO CITIES (COUNTRY, "NAME", POPULATION) VALUES ('RUSSIA', 'St. Petersburg', 300) + + +More on [DSL](Deep-Dive-into-DSL.md) and [DAO](Deep-Dive-into-DAO.md). diff --git a/documentation-website/Writerside/topics/Introduction.md b/documentation-website/Writerside/topics/Introduction.md index 065b066c6e..6f331aed8e 100644 --- a/documentation-website/Writerside/topics/Introduction.md +++ b/documentation-website/Writerside/topics/Introduction.md @@ -1,18 +1,24 @@ # Introduction -Welcome to the Exposed Documentation! +Welcome to the Exposed documentation! -Exposed is a lightweight SQL library on top of JDBC driver for Kotlin language. -Exposed has two flavors of database access: typesafe SQL wrapping DSL and lightweight Data Access Objects (DAO) +Exposed is a lightweight SQL library on top of JDBC driver for Kotlin. +It has two flavors of database access: type-safe SQL wrapping DSL (Domain-Specific Language) and lightweight DAO (Data Access Object). -Currently, supported database dialects are: +Exposed supports the following databases: -* PostgreSQL +* H2 +* MariaDB * MySQL * Oracle -* SQLite -* H2 +* PostgreSQL * SQL Server -* MariaDB +* SQLite + +Exposed requires Java 6 or later versions. To check the version of Java you have installed, run the following command from the terminal: + +```shell +java -version +``` -Read Next [Getting Started](Getting-Started.md) +Exposed is an open-source project and is available on GitHub. diff --git a/documentation-website/Writerside/topics/Modules-Documentation.md b/documentation-website/Writerside/topics/Modules-Documentation.md index 41e8336ad4..9ed1d0ad7d 100644 --- a/documentation-website/Writerside/topics/Modules-Documentation.md +++ b/documentation-website/Writerside/topics/Modules-Documentation.md @@ -134,7 +134,7 @@ exposedVersion=0.40.1 ``` ### JDBC driver and logging -You also need a JDBC driver for the database system you are using (see [Database and DataSource](Database-and-DataSource.md)) and a logger for `addLogger(StdOutSqlLogger)`. Example (Gradle syntax): +You also need a JDBC driver for the database system you are using (see [Databases](Databases.md)) and a logger for `addLogger(StdOutSqlLogger)`. Example (Gradle syntax): ```kotlin dependencies { // for H2 diff --git a/documentation-website/Writerside/topics/Samples.md b/documentation-website/Writerside/topics/Samples.md new file mode 100644 index 0000000000..49d4c8e5b8 --- /dev/null +++ b/documentation-website/Writerside/topics/Samples.md @@ -0,0 +1,3 @@ +# Samples + +Samples can be found [here](https://github.com/JetBrains/Exposed/tree/main/samples). diff --git a/documentation-website/Writerside/topics/Transactions.md b/documentation-website/Writerside/topics/Transactions.md deleted file mode 100644 index 57b0e628cd..0000000000 --- a/documentation-website/Writerside/topics/Transactions.md +++ /dev/null @@ -1,156 +0,0 @@ -# Transactions - -## Overview - -CRUD operations in Exposed must be called from within a _transaction._ Transactions encapsulate a set of DSL operations. To create and execute a transaction with default parameters, simply pass a function block to the `transaction` function: -```kotlin -transaction { - // DSL/DAO operations go here -} -``` -Transactions are executed synchronously on the current thread, so they _will block_ other parts of your application! If you need to execute a transaction asynchronously, consider running it on a separate `Thread`. - -### Accessing returned values - -Although you can modify variables from your code within the transaction block, `transaction` supports returning a value directly, enabling immutability: - -```kotlin -val jamesList = transaction { - Users.select { Users.firstName eq "James" }.toList() -} -// jamesList is now a List containing Users data -``` -*Note:* `Blob` and `text` fields won't be available outside of a transaction if you don't load them directly. For `text` fields you can also use the `eagerLoading` param when defining the Table to make the text fields available outside of the transaction. -```kotlin -// without eagerLoading -val idsAndContent = transaction { - Documents.selectAll().limit(10).map { it[Documents.id] to it[Documents.content] } -} - -// with eagerLoading for text fields -object Documents : Table() { - val content = text("content", eagerLoading = true) -} - -val documentsWithContent = transaction { - Documents.selectAll().limit(10) -} -``` - -### Working with a multiple databases - -When you want to work with different databases then you have to store database reference returned by `Database.connect()` and provide it to `transaction` function as first parameter. -```kotlin -val db1 = connect("jdbc:h2:mem:db1;DB_CLOSE_DELAY=-1;", "org.h2.Driver", "root", "") -val db2 = connect("jdbc:h2:mem:db2;DB_CLOSE_DELAY=-1;", "org.h2.Driver", "root", "") -transaction(db1) { - val result = transaction(db2) { - Table1.select{ }.map { it[Table1.name] } - } - - val count = Table2.select { Table2.name inList result }.count() -} -``` - -Entities (see [DAO](DAO-API.md) page) `stick` to a transaction that was used to load that entity. That means that all changes persist to the same database and what cross-database references are prohibited and will throw exceptions. - -### Setting default database -`transaction` block without parameters will use the default database. -As before 0.10.1 this will be the latest _connected_ database. -It is also possible to set the default database explicitly. -```kotlin -val db = Database.connect() -TransactionManager.defaultDatabase = db -``` - -### Using nested transactions -Since Exposed 0.16.1 it is possible to use nested transactions. To enable this feature you should set `useNestedTransactions` on desire `Database` instance to `true`. - -After that any exception that happens within `transaction` block will not rollback the whole transaction but only the code inside current `transaction`. -Exposed uses SQL `SAVEPOINT` functionality to mark current transaction at the begining of `transaction` block and release it on exit from it. - -Using savepoint could affect performance, so please read documentation on DBMS you use for more details. - -```kotlin -val db = Database.connect() -db.useNestedTransactions = true - -transaction { - FooTable.insert{ it[id] = 1 } - - var idToInsert = 0 - transaction { // nested transaction - idToInsert++ - // On the first insert it will fail with unique constraint exception and will rollback to the `nested transaction` and then insert a new record with id = 2 - FooTable.insert{ it[id] = idToInsert } - } -} -``` - -### Working with Coroutines -In the modern world non-blocking and asynchronous code is popular. Kotlin has [Coroutines](https://kotlinlang.org/docs/reference/coroutines-overview.html) that give you an imperative way of asynchronous code writing. Most of Kotlin frameworks (like [ktor](https://ktor.io)) have built-in support for Coroutines while Exposed is mostly blocking. - -Why? - -Because Exposed uses JDBC-api to interact with databases that was designed in an era of blocking apis. What's more, Exposed store some values in thread-local variables while Coroutines could (and will) be executed in different threads. - -Since Exposed 0.15.1 there are bridge functions that will give you a safe way to interact with Exposed within `suspend` blocks: `newSuspendedTransaction/Transaction.suspendedTransaction` have same parameters as a blocking `transaction` function but will allow you to provide `CoroutineDispatcher` in which function will be executed. If context is not provided your code will be executed within current `coroutineContext`. - -Sample usage looks like: -```kotlin -runBlocking { - transaction { - SchemaUtils.create(FooTable) // Table will be created on a current thread - - newSuspendedTransaction(Dispatchers.Default) { - FooTable.insert { it[id] = 1 } // This insert will be executed in one of Default dispatcher threads - - suspendedTransaction { - val id = FooTable.select { FooTable.id eq 1 }.single()()[FooTable.id] // This select also will be executed on some thread from Default dispatcher using the same transaction - } - } - - val result = newSuspendedTransaction(Dispatchers.IO) { - FooTable.select { FooTable.id eq 1 }.single()[H2Tests.Testing.id] // This select will be executed on some thread from IO dispatcher using the same transaction - } - } -} - -``` - -Please note what such code remains blocking (as it still uses JDBC) and you should not try to share a transaction between multiple threads as it will lead to undefined behaviour. - -If you desire to execute some code asynchronously and use the result later in your code take a look at `suspendedTransactionAsync` function. - -```kotlin -val launchResult = suspendedTransactionAsync(Dispatchers.IO, db = db) { - FooTable.insert{} - - FooTable.select { FooTable.id eq 1 }.singleOrNull()?.getOrNull(Testing.id) -} - -println("Result: " + (launchResult.await() ?: -1)) - -``` - -This function will accept the same parameters as `newSuspendedTransaction` above but returns `Deferred` which you could `await` on to achieve your result. - -`suspendedTransactionAsync` is always executed in new transaction to prevent concurrency issues when queries execution order could be changed by `CoroutineDispatcher`. - -### Advanced parameters and usage - -For specific functionality, transactions can be created with the additional parameters: `transactionIsolation`, `repetitionAttempts` and `db`: - -```kotlin -transaction (Connection.TRANSACTION_SERIALIZABLE, 2) { - // DSL/DAO operations go here -} -``` -**Transaction Isolation:** This parameter, defined in the SQL standard, specifies what is supposed to happen when multiple transactions execute concurrently on the database. This value does NOT affect Exposed operation directly, but is sent to the database, where it is expected to be obeyed. Allowable values are defined in `java.sql.Connection` and are as follows: -* **TRANSACTION_NONE**: Transactions are not supported. -* **TRANSACTION_READ_UNCOMMITTED**: The most lenient setting. Allows uncommitted changes from one transaction to affect a read in another transaction (a "dirty read"). -* **TRANSACTION_READ_COMMITTED**: This setting prevents dirty reads from occurring, but still allows non-repeatable reads to occur. A _non-repeatable read_ is when a transaction ("Transaction A") reads a row from the database, another transaction ("Transaction B") changes the row, and Transaction A reads the row again, resulting in an inconsistency. -* **TRANSACTION_REPEATABLE_READ**: The default setting for Exposed transactions. Prevents both dirty and non-repeatable reads, but still allows for phantom reads. A _phantom read_ is when a transaction ("Transaction A") selects a list of rows through a `WHERE` clause, another transaction ("Transaction B") performs an `INSERT` or `DELETE` with a row that satisfies Transaction A's `WHERE` clause, and Transaction A selects using the same WHERE clause again, resulting in an inconsistency. -* **TRANSACTION_SERIALIZABLE**: The strictest setting. Prevents dirty reads, non-repeatable reads, and phantom reads. - -**db** parameter is optional and used to select database where transaction should be settled (see section above). diff --git a/documentation-website/Writerside/topics/Tutorials-and-Samples.md b/documentation-website/Writerside/topics/Tutorials-and-Samples.md new file mode 100644 index 0000000000..aef50b7579 --- /dev/null +++ b/documentation-website/Writerside/topics/Tutorials-and-Samples.md @@ -0,0 +1,7 @@ +# Tutorials and Samples + +This section will demonstrate how to get started with Exposed. + +[Getting Started](Getting-Started.md) + +[Samples](Samples.md) diff --git a/documentation-website/Writerside/topics/Working-with-DataSource.md b/documentation-website/Writerside/topics/Working-with-DataSource.md new file mode 100644 index 0000000000..58bdb4bfe1 --- /dev/null +++ b/documentation-website/Writerside/topics/Working-with-DataSource.md @@ -0,0 +1,31 @@ +# Working with DataSource + +It is also possible to provide a `javax.sql.DataSource` to the `Database.connect` function. This allows you to use more advanced features like +connection pooling, and lets you set configuration options like maximum number of connections, connection timeouts, etc. + +```kotlin +val db = Database.connect(dataSource) +``` + +## MariaDB/MySQL with latest JDBC driver + Hikari pooling + +Add dependency: + +```kotlin +implementation("mysql:mysql-connector-java:8.0.19") +implementation("com.zaxxer:HikariCP:3.4.2") +``` + +Connect to database: + +```kotlin +val config = HikariConfig().apply { + jdbcUrl = "jdbc:mysql://localhost/dbname" + driverClassName = "com.mysql.cj.jdbc.Driver" + username = "user" + password = "password" + maximumPoolSize = 10 +} +val dataSource = HikariDataSource(config) +Database.connect(dataSource) +``` diff --git a/documentation-website/Writerside/topics/Working-with-Database.md b/documentation-website/Writerside/topics/Working-with-Database.md new file mode 100644 index 0000000000..16c8d8a1e2 --- /dev/null +++ b/documentation-website/Writerside/topics/Working-with-Database.md @@ -0,0 +1,181 @@ +# Working with Database + +In Exposed, the `Database` class represents a database instance, and encapsulates the necessary connection +details and configuration required to interact with a specific database. + +## Connecting to a Database + +To connect to a database using `Database`, you need to provide the appropriate JDBC driver and connection URL. Here's an example of how to establish a +connection: + +```kotlin +val db = Database.connect("jdbc:h2:mem:test", driver = "org.h2.Driver") +``` + +The `Database.connect` function tells Exposed _how_ to connect to a database, but won't _create_ a database connection. It only provides a +descriptor for future usage. A connection will be created later by calling the `transaction` lambda (see [Transaction](Working-with-Transaction.md) for more +details). + + +Starting from Exposed 0.10, executing this code more than once per database will create leaks in your application; hence, it is recommended to + store it for later use. + + +Creating a database only when it is accessed for the first time can be done like this: + +```kotlin +object DbSettings { + val db by lazy { + Database.connect(/* setup connection */) + } +} +``` + +### H2 + +In order to use H2, you need to add the H2 driver dependency: + +```kotlin +implementation("com.h2database:h2:2.1.214") +``` + +Then connect to a database: + +```kotlin +Database.connect("jdbc:h2:./myh2file", "org.h2.Driver") +``` + +Or in-memory database: + +```kotlin +Database.connect("jdbc:h2:mem:regular", "org.h2.Driver") +``` + +By default, H2 closes the database when the last connection is closed. If you want to keep the database open, you can use the `DB_CLOSE_DELAY=-1` +option: + +```kotlin +Database.connect("jdbc:h2:mem:regular;DB_CLOSE_DELAY=-1;", "org.h2.Driver") +``` + +### MariaDB/MySQL + +Add dependency: + +```kotlin +implementation("mysql:mysql-connector-java:8.0.2") +``` + +Connect to database: + +```kotlin +Database.connect( + "jdbc:mysql://localhost:3306/test", + driver = "com.mysql.cj.jdbc.Driver", + user = "user", + password = "password" +) +``` + +### Oracle + +Add dependency: + +```kotlin +implementation("com.oracle.database.jdbc:ojdbc8:12.2.0.1") +``` + +Connect to database: + +```kotlin +Database.connect( + "jdbc:oracle:thin:@//localhost:1521/test", + driver = "oracle.jdbc.OracleDriver", + user = "user", + password = "password" +) +``` + +### PostgreSQL + +Add dependency: + +```kotlin +implementation("org.postgresql:postgresql:42.2.2") +``` + +Connect to database: + +```kotlin +Database.connect( + "jdbc:postgresql://localhost:12346/test", + driver = "org.postgresql.Driver", + user = "user", + password = "password" +) +``` + +### PostgreSQL using the pgjdbc-ng JDBC driver + +Add dependency: + +```kotlin +implementation("com.impossibl.pgjdbc-ng", "pgjdbc-ng", "0.8.3") +``` + +Connect to database: + +```kotlin +Database.connect( + "jdbc:pgsql://localhost:12346/test", + driver = "com.impossibl.postgres.jdbc.PGDriver", + user = "user", + password = "password" +) +``` + +### SQL Server + +Add dependency: + +```kotlin +implementation("com.microsoft.sqlserver:mssql-jdbc:6.4.0.jre7") +``` + +Connect to database: + +```kotlin +Database.connect( + "jdbc:sqlserver://localhost:32768;databaseName=test", + "com.microsoft.sqlserver.jdbc.SQLServerDriver", + user = "user", + password = "password" +) +``` + +### SQLite + +Add the dependency: + +```kotlin +implementation("org.xerial:sqlite-jdbc:3.30.1") +``` + +Connect to database: + +```kotlin +Database.connect("jdbc:sqlite:/data/data.db", "org.sqlite.JDBC") +``` + +Or in-memory database: + +```kotlin +Database.connect("jdbc:sqlite:file:test?mode=memory&cache=shared", "org.sqlite.JDBC") +``` + +For both: set SQLite compatible isolation level: [FAQ](Frequently-Asked-Questions.md). + +```kotlin +TransactionManager.manager.defaultIsolationLevel = Connection.TRANSACTION_SERIALIZABLE +// or Connection.TRANSACTION_READ_UNCOMMITTED +``` diff --git a/documentation-website/Writerside/topics/Working-with-Transaction.md b/documentation-website/Writerside/topics/Working-with-Transaction.md new file mode 100644 index 0000000000..a294bcbc2c --- /dev/null +++ b/documentation-website/Writerside/topics/Working-with-Transaction.md @@ -0,0 +1,140 @@ +# Working with Transaction + +## Overview + +CRUD operations in Exposed must be called from within a _transaction._ Transactions encapsulate a set of DSL operations. To create and execute a +transaction with default parameters, simply pass a function block to the `transaction` function: + +```kotlin +transaction { + // DSL/DAO operations go here +} +``` + +Transactions are executed synchronously on the current thread, so they _will block_ other parts of your application! If you need to execute a +transaction asynchronously, consider running it on a [separate thread](Asynchronous-Support.md). + +### Accessing returned values + +Although you can modify variables from your code within the `transaction` block, `transaction` supports returning a value directly, enabling +immutability: + +```kotlin +val jamesList = transaction { + Users.select { Users.firstName eq "James" }.toList() +} +// jamesList is now a List containing Users data +``` + + +`Blob` and `text` fields won't be available outside of a transaction if you don't load them directly. For `text` fields you can also use +the `eagerLoading` param when defining the Table to make the text fields available outside of the transaction. + + +```kotlin +// without eagerLoading +val idsAndContent = transaction { + Documents.selectAll().limit(10).map { it[Documents.id] to it[Documents.content] } +} + +// with eagerLoading for text fields +object Documents : Table() { + val content = text("content", eagerLoading = true) +} + +val documentsWithContent = transaction { + Documents.selectAll().limit(10) +} +``` + +### Working with multiple databases + +If you want to work with different databases, you have to store the database reference returned by `Database.connect()` and provide it +to `transaction` function as the first parameter. The `transaction` block without parameters will work with the latest connected database. + +```kotlin +val db1 = connect("jdbc:h2:mem:db1;DB_CLOSE_DELAY=-1;", "org.h2.Driver", "root", "") +val db2 = connect("jdbc:h2:mem:db2;DB_CLOSE_DELAY=-1;", "org.h2.Driver", "root", "") +transaction(db1) { + val result = transaction(db2) { + Table1.select { }.map { it[Table1.name] } + } + + val count = Table2.select { Table2.name inList result }.count() +} +``` + +Entities (see [DAO](Deep-Dive-into-DAO.md) page) _stick_ to the transaction that was used to load that entity. That means that all changes persist to the same +database and cross-database references are prohibited and will throw exceptions. + +### Setting default database + +The `transaction` block without parameters will use the default database. +Before 0.10.1, this will be the latest _connected_ database. +It is also possible to set the default database explicitly. + +```kotlin +val db = Database.connect() +TransactionManager.defaultDatabase = db +``` + +### Using nested transactions + +Since Exposed 0.16.1, it is possible to use nested transactions. To enable this feature, you should set `useNestedTransactions` on the desired `Database` +instance to `true`. + +After that, any exception that happens within the `transaction` block will not rollback the whole transaction but only the code inside the +current `transaction`. +Exposed uses SQL `SAVEPOINT` functionality to mark the current transaction at the beginning of the `transaction` block and release it on exit from it. + +Using `SAVEPOINT` could affect performance, so please read the documentation of the DBMS you use for more details. + +```kotlin +val db = Database.connect() +db.useNestedTransactions = true + +transaction { + FooTable.insert { it[id] = 1 } + + var idToInsert = 0 + transaction { // nested transaction + idToInsert ++ + // On the first insert it will fail with unique constraint exception and will rollback to the `nested transaction` and then insert a new record with id = 2 + FooTable.insert { it[id] = idToInsert } + } +} +``` + +### Advanced parameters and usage + +For specific functionality, transactions can be created with additional parameters: `transactionIsolation` and `db`. +The following properties can be set inside the `transaction` lambda: + +* `repetitionAttempts`: The number of retries that will be made inside this `transaction` block if SQLException happens +* `minRepetitionDelay`: The minimum number of milliseconds to wait before retrying this `transaction` if SQLException happens +* `maxRepetitionDelay`: The maximum number of milliseconds to wait before retrying this `transaction` if SQLException happens + +```kotlin +transaction(Connection.TRANSACTION_SERIALIZABLE, db) { + repetitionAttempts = 2 + // DSL/DAO operations go here +} +``` + +**Transaction Isolation**: This parameter, defined in the SQL standard, specifies what is supposed to happen when multiple transactions execute +concurrently on the database. This value does NOT affect Exposed operations directly, but is sent to the database, where it is expected to be obeyed. +Allowable values are defined in `java.sql.Connection` and are as follows: + +* **TRANSACTION_NONE**: Transactions are not supported. +* **TRANSACTION_READ_UNCOMMITTED**: The most lenient setting. Allows uncommitted changes from one transaction to affect a read in another + transaction (a "dirty read"). +* **TRANSACTION_READ_COMMITTED**: This setting prevents dirty reads from occurring, but still allows non-repeatable reads to occur. A _non-repeatable + read_ is when a transaction ("Transaction A") reads a row from the database, another transaction ("Transaction B") changes the row, and Transaction + A reads the row again, resulting in an inconsistency. +* **TRANSACTION_REPEATABLE_READ**: The default setting for Exposed transactions. Prevents both dirty and non-repeatable reads, but still allows for + phantom reads. A _phantom read_ is when a transaction ("Transaction A") selects a list of rows through a `WHERE` clause, another transaction (" + Transaction B") performs an `INSERT` or `DELETE` with a row that satisfies Transaction A's `WHERE` clause, and Transaction A selects using the same + WHERE clause again, resulting in an inconsistency. +* **TRANSACTION_SERIALIZABLE**: The strictest setting. Prevents dirty reads, non-repeatable reads, and phantom reads. + +**db** parameter is optional and used to select the database where the transaction should be settled (see section above).