The database interface type. Keys of this type must be table names in the database and values must be interfaces that describe the rows in those tables. See the examples above.
Returns a the DynamicModule module.
The DynamicModule module can be used to bypass strict typing and passing in dynamic values for the queries.
Returns a FunctionModule that can be used to write somewhat type-safe function calls.
const { count } = db.fn
await db.selectFrom('person')
.innerJoin('pet', 'pet.owner_id', 'person.id')
.select([
'id',
count('pet.id').as('person_count'),
])
.groupBy('person.id')
.having(count('pet.id'), '>', 10)
.execute()
The generated SQL (PostgreSQL):
select "person"."id", count("pet"."id") as "person_count"
from "person"
inner join "pet" on "pet"."owner_id" = "person"."id"
group by "person"."id"
having count("pet"."id") > $1
Why "somewhat" type-safe? Because the function calls are not bound to the
current query context. They allow you to reference columns and tables that
are not in the current query. E.g. remove the innerJoin
from the previous
query and TypeScript won't even complain.
If you want to make the function calls fully type-safe, you can use the ExpressionBuilder.fn getter for a query context-aware, stricter FunctionModule.
await db.selectFrom('person')
.innerJoin('pet', 'pet.owner_id', 'person.id')
.select((eb) => [
'person.id',
eb.fn.count('pet.id').as('pet_count')
])
.groupBy('person.id')
.having((eb) => eb.fn.count('pet.id'), '>', 10)
.execute()
Returns a database introspector.
Returns true if this Kysely
instance is a transaction.
You can also use db instanceof Transaction
.
Returns the SchemaModule module for building database schema.
Creates a case
statement/operator.
See ExpressionBuilder.case for more information.
Creates a case
statement/operator.
See ExpressionBuilder.case for more information.
Commits the transaction.
See rollback.
import type { Kysely } from 'kysely'
import type { Database } from 'type-editor' // imaginary module
const trx = await db.startTransaction().execute()
try {
await doSomething(trx)
await trx.commit().execute()
} catch (error) {
await trx.rollback().execute()
}
async function doSomething(kysely: Kysely<Database>) {}
Provides a kysely instance bound to a single database connection.
await db
.connection()
.execute(async (db) => {
// `db` is an instance of `Kysely` that's bound to a single
// database connection. All queries executed through `db` use
// the same connection.
await doStuff(db)
})
async function doStuff(kysely: typeof db) {
// ...
}
Creates a delete query.
See the DeleteQueryBuilder.where method for examples on how to specify a where clause for the delete operation.
The return value of the query is an instance of DeleteResult.
Delete a single row:
const result = await db
.deleteFrom('person')
.where('person.id', '=', 1)
.executeTakeFirst()
console.log(result.numDeletedRows)
The generated SQL (PostgreSQL):
delete from "person" where "person"."id" = $1
Some databases such as MySQL support deleting from multiple tables:
const result = await db
.deleteFrom(['person', 'pet'])
.using('person')
.innerJoin('pet', 'pet.owner_id', 'person.id')
.where('person.id', '=', 1)
.executeTakeFirst()
The generated SQL (MySQL):
delete from `person`, `pet`
using `person`
inner join `pet` on `pet`.`owner_id` = `person`.`id`
where `person`.`id` = ?
Releases all resources and disconnects from the database.
You need to call this when you are done using the Kysely
instance.
Executes a given compiled query or query builder.
See splitting build, compile and execute code recipe for more information.
Creates an insert query.
The return value of this query is an instance of InsertResult. InsertResult has the insertId field that holds the auto incremented id of the inserted row if the db returned one.
See the values method for more info and examples. Also see the returning method for a way to return columns on supported databases like PostgreSQL.
const result = await db
.insertInto('person')
.values({
first_name: 'Jennifer',
last_name: 'Aniston'
})
.executeTakeFirst()
console.log(result.insertId)
Some databases like PostgreSQL support the returning
method:
const { id } = await db
.insertInto('person')
.values({
first_name: 'Jennifer',
last_name: 'Aniston'
})
.returning('id')
.executeTakeFirstOrThrow()
Creates a merge query.
The return value of the query is a MergeResult.
See the MergeQueryBuilder.using method for examples on how to specify the other table.
Update a target column based on the existence of a source row:
const result = await db
.mergeInto('person as target')
.using('pet as source', 'source.owner_id', 'target.id')
.whenMatchedAnd('target.has_pets', '!=', 'Y')
.thenUpdateSet({ has_pets: 'Y' })
.whenNotMatchedBySourceAnd('target.has_pets', '=', 'Y')
.thenUpdateSet({ has_pets: 'N' })
.executeTakeFirstOrThrow()
console.log(result.numChangedRows)
The generated SQL (PostgreSQL):
merge into "person"
using "pet"
on "pet"."owner_id" = "person"."id"
when matched and "has_pets" != $1
then update set "has_pets" = $2
when not matched by source and "has_pets" = $3
then update set "has_pets" = $4
Merge new entries from a temporary changes table:
const result = await db
.mergeInto('wine as target')
.using(
'wine_stock_change as source',
'source.wine_name',
'target.name',
)
.whenNotMatchedAnd('source.stock_delta', '>', 0)
.thenInsertValues(({ ref }) => ({
name: ref('source.wine_name'),
stock: ref('source.stock_delta'),
}))
.whenMatchedAnd(
(eb) => eb('target.stock', '+', eb.ref('source.stock_delta')),
'>',
0,
)
.thenUpdateSet('stock', (eb) =>
eb('target.stock', '+', eb.ref('source.stock_delta')),
)
.whenMatched()
.thenDelete()
.executeTakeFirstOrThrow()
The generated SQL (PostgreSQL):
merge into "wine" as "target"
using "wine_stock_change" as "source"
on "source"."wine_name" = "target"."name"
when not matched and "source"."stock_delta" > $1
then insert ("name", "stock") values ("source"."wine_name", "source"."stock_delta")
when matched and "target"."stock" + "source"."stock_delta" > $2
then update set "stock" = "target"."stock" + "source"."stock_delta"
when matched
then delete
Releases a savepoint with a given name.
See savepoint and rollbackToSavepoint.
You must use the same instance returned by savepoint, or
escape the type-check by using as any
.
import type { Kysely } from 'kysely'
import type { Database } from 'type-editor' // imaginary module
const trx = await db.startTransaction().execute()
await insertJennifer(trx)
const trxAfterJennifer = await trx.savepoint('after_jennifer').execute()
try {
await doSomething(trxAfterJennifer)
} catch (error) {
await trxAfterJennifer.rollbackToSavepoint('after_jennifer').execute()
}
await trxAfterJennifer.releaseSavepoint('after_jennifer').execute()
await doSomethingElse(trx)
async function insertJennifer(kysely: Kysely<Database>) {}
async function doSomething(kysely: Kysely<Database>) {}
async function doSomethingElse(kysely: Kysely<Database>) {}
Creates a "replace into" query.
This is only supported by some dialects like MySQL or SQLite.
Similar to MySQL's InsertQueryBuilder.onDuplicateKeyUpdate that deletes and inserts values on collision instead of updating existing rows.
An alias of SQLite's InsertQueryBuilder.orReplace.
The return value of this query is an instance of InsertResult. InsertResult has the insertId field that holds the auto incremented id of the inserted row if the db returned one.
See the values method for more info and examples.
const result = await db
.replaceInto('person')
.values({
first_name: 'Jennifer',
last_name: 'Aniston'
})
.executeTakeFirstOrThrow()
console.log(result.insertId)
The generated SQL (MySQL):
replace into `person` (`first_name`, `last_name`) values (?, ?)
Rolls back the transaction.
See commit and rollbackToSavepoint.
import type { Kysely } from 'kysely'
import type { Database } from 'type-editor' // imaginary module
const trx = await db.startTransaction().execute()
try {
await doSomething(trx)
await trx.commit().execute()
} catch (error) {
await trx.rollback().execute()
}
async function doSomething(kysely: Kysely<Database>) {}
Rolls back to a savepoint with a given name.
See savepoint and releaseSavepoint.
You must use the same instance returned by savepoint, or
escape the type-check by using as any
.
import type { Kysely } from 'kysely'
import type { Database } from 'type-editor' // imaginary module
const trx = await db.startTransaction().execute()
await insertJennifer(trx)
const trxAfterJennifer = await trx.savepoint('after_jennifer').execute()
try {
await doSomething(trxAfterJennifer)
} catch (error) {
await trxAfterJennifer.rollbackToSavepoint('after_jennifer').execute()
}
async function insertJennifer(kysely: Kysely<Database>) {}
async function doSomething(kysely: Kysely<Database>) {}
Creates a savepoint with a given name.
See rollbackToSavepoint and releaseSavepoint.
For a type-safe experience, you should use the returned instance from now on.
import type { Kysely } from 'kysely'
import type { Database } from 'type-editor' // imaginary module
const trx = await db.startTransaction().execute()
await insertJennifer(trx)
const trxAfterJennifer = await trx.savepoint('after_jennifer').execute()
try {
await doSomething(trxAfterJennifer)
} catch (error) {
await trxAfterJennifer.rollbackToSavepoint('after_jennifer').execute()
}
async function insertJennifer(kysely: Kysely<Database>) {}
async function doSomething(kysely: Kysely<Database>) {}
Creates a select
query builder for the given table or tables.
The tables passed to this method are built as the query's from
clause.
Create a select query for one table:
db.selectFrom('person').selectAll()
The generated SQL (PostgreSQL):
select * from "person"
Create a select query for one table with an alias:
const persons = await db.selectFrom('person as p')
.select(['p.id', 'first_name'])
.execute()
console.log(persons[0].id)
The generated SQL (PostgreSQL):
select "p"."id", "first_name" from "person" as "p"
Create a select query from a subquery:
const persons = await db.selectFrom(
(eb) => eb.selectFrom('person').select('person.id as identifier').as('p')
)
.select('p.identifier')
.execute()
console.log(persons[0].identifier)
The generated SQL (PostgreSQL):
select "p"."identifier",
from (
select "person"."id" as "identifier" from "person"
) as p
Create a select query from raw sql:
import { sql } from 'kysely'
const items = await db
.selectFrom(sql<{ one: number }>`(select 1 as one)`.as('q'))
.select('q.one')
.execute()
console.log(items[0].one)
The generated SQL (PostgreSQL):
select "q"."one",
from (
select 1 as one
) as q
When you use the sql
tag you need to also provide the result type of the
raw snippet / query so that Kysely can figure out what columns are
available for the rest of the query.
The selectFrom
method also accepts an array for multiple tables. All
the above examples can also be used in an array.
import { sql } from 'kysely'
const items = await db.selectFrom([
'person as p',
db.selectFrom('pet').select('pet.species').as('a'),
sql<{ one: number }>`(select 1 as one)`.as('q')
])
.select(['p.id', 'a.species', 'q.one'])
.execute()
The generated SQL (PostgreSQL):
select "p".id, "a"."species", "q"."one"
from
"person" as "p",
(select "pet"."species" from "pet") as a,
(select 1 as one) as "q"
Creates a select
query builder without a from
clause.
If you want to create a select from
query, use the selectFrom
method instead.
This one can be used to create a plain select
statement without a from
clause.
This method accepts the same inputs as SelectQueryBuilder.select. See its documentation for more examples.
const result = await db.selectNoFrom((eb) => [
eb.selectFrom('person')
.select('id')
.where('first_name', '=', 'Jennifer')
.limit(1)
.as('jennifer_id'),
eb.selectFrom('pet')
.select('id')
.where('name', '=', 'Doggo')
.limit(1)
.as('doggo_id')
])
.executeTakeFirstOrThrow()
console.log(result.jennifer_id)
console.log(result.doggo_id)
The generated SQL (PostgreSQL):
select (
select "id"
from "person"
where "first_name" = $1
limit $2
) as "jennifer_id", (
select "id"
from "pet"
where "name" = $3
limit $4
) as "doggo_id"
Creates a select
query builder without a from
clause.
If you want to create a select from
query, use the selectFrom
method instead.
This one can be used to create a plain select
statement without a from
clause.
This method accepts the same inputs as SelectQueryBuilder.select. See its documentation for more examples.
const result = await db.selectNoFrom((eb) => [
eb.selectFrom('person')
.select('id')
.where('first_name', '=', 'Jennifer')
.limit(1)
.as('jennifer_id'),
eb.selectFrom('pet')
.select('id')
.where('name', '=', 'Doggo')
.limit(1)
.as('doggo_id')
])
.executeTakeFirstOrThrow()
console.log(result.jennifer_id)
console.log(result.doggo_id)
The generated SQL (PostgreSQL):
select (
select "id"
from "person"
where "first_name" = $1
limit $2
) as "jennifer_id", (
select "id"
from "pet"
where "name" = $3
limit $4
) as "doggo_id"
Creates a select
query builder without a from
clause.
If you want to create a select from
query, use the selectFrom
method instead.
This one can be used to create a plain select
statement without a from
clause.
This method accepts the same inputs as SelectQueryBuilder.select. See its documentation for more examples.
const result = await db.selectNoFrom((eb) => [
eb.selectFrom('person')
.select('id')
.where('first_name', '=', 'Jennifer')
.limit(1)
.as('jennifer_id'),
eb.selectFrom('pet')
.select('id')
.where('name', '=', 'Doggo')
.limit(1)
.as('doggo_id')
])
.executeTakeFirstOrThrow()
console.log(result.jennifer_id)
console.log(result.doggo_id)
The generated SQL (PostgreSQL):
select (
select "id"
from "person"
where "first_name" = $1
limit $2
) as "jennifer_id", (
select "id"
from "pet"
where "name" = $3
limit $4
) as "doggo_id"
Creates a ControlledTransactionBuilder that can be used to run queries inside a controlled transaction.
The returned ControlledTransactionBuilder can be used to configure the transaction. The ControlledTransactionBuilder.execute method can then be called to start the transaction and return a ControlledTransaction.
A ControlledTransaction allows you to commit and rollback manually, execute savepoint commands. It extends Transaction which extends Kysely, so you can run queries inside the transaction. Once the transaction is committed, or rolled back, it can't be used anymore - all queries will throw an error. This is to prevent accidentally running queries outside the transaction - where atomicity is not guaranteed anymore.
A controlled transaction allows you to commit and rollback manually, execute savepoint commands, and queries in general.
In this example we start a transaction, use it to insert two rows and then commit the transaction. If an error is thrown, we catch it and rollback the transaction.
const trx = await db.startTransaction().execute()
try {
const jennifer = await trx.insertInto('person')
.values({
first_name: 'Jennifer',
last_name: 'Aniston',
age: 40,
})
.returning('id')
.executeTakeFirstOrThrow()
const catto = await trx.insertInto('pet')
.values({
owner_id: jennifer.id,
name: 'Catto',
species: 'cat',
is_favorite: false,
})
.returningAll()
.executeTakeFirstOrThrow()
await trx.commit().execute()
// ...
} catch (error) {
await trx.rollback().execute()
}
A controlled transaction allows you to commit and rollback manually, execute savepoint commands, and queries in general.
In this example we start a transaction, insert a person, create a savepoint, try inserting a toy and a pet, and if an error is thrown, we rollback to the savepoint. Eventually we release the savepoint, insert an audit record and commit the transaction. If an error is thrown, we catch it and rollback the transaction.
const trx = await db.startTransaction().execute()
try {
const jennifer = await trx
.insertInto('person')
.values({
first_name: 'Jennifer',
last_name: 'Aniston',
age: 40,
})
.returning('id')
.executeTakeFirstOrThrow()
const trxAfterJennifer = await trx.savepoint('after_jennifer').execute()
try {
const catto = await trxAfterJennifer
.insertInto('pet')
.values({
owner_id: jennifer.id,
name: 'Catto',
species: 'cat',
})
.returning('id')
.executeTakeFirstOrThrow()
await trxAfterJennifer
.insertInto('toy')
.values({ name: 'Bone', price: 1.99, pet_id: catto.id })
.execute()
} catch (error) {
await trxAfterJennifer.rollbackToSavepoint('after_jennifer').execute()
}
await trxAfterJennifer.releaseSavepoint('after_jennifer').execute()
await trx.insertInto('audit').values({ action: 'added Jennifer' }).execute()
await trx.commit().execute()
} catch (error) {
await trx.rollback().execute()
}
Creates a TransactionBuilder that can be used to run queries inside a transaction.
The returned TransactionBuilder can be used to configure the transaction. The TransactionBuilder.execute method can then be called to run the transaction. TransactionBuilder.execute takes a function that is run inside the transaction. If the function throws an exception,
The callback function passed to the execute method gets the transaction object as its only argument. The transaction is of type Transaction which inherits Kysely. Any query started through the transaction object is executed inside the transaction.
To run a controlled transaction, allowing you to commit and rollback manually, use startTransaction instead.
This example inserts two rows in a transaction. If an exception is thrown inside
the callback passed to the execute
method,
const catto = await db.transaction().execute(async (trx) => {
const jennifer = await trx.insertInto('person')
.values({
first_name: 'Jennifer',
last_name: 'Aniston',
age: 40,
})
.returning('id')
.executeTakeFirstOrThrow()
return await trx.insertInto('pet')
.values({
owner_id: jennifer.id,
name: 'Catto',
species: 'cat',
is_favorite: false,
})
.returningAll()
.executeTakeFirst()
})
Setting the isolation level:
import type { Kysely } from 'kysely'
await db
.transaction()
.setIsolationLevel('serializable')
.execute(async (trx) => {
await doStuff(trx)
})
async function doStuff(kysely: typeof db) {
// ...
}
Creates an update query.
See the UpdateQueryBuilder.where method for examples on how to specify a where clause for the update operation.
See the UpdateQueryBuilder.set method for examples on how to specify the updates.
The return value of the query is an UpdateResult.
const result = await db
.updateTable('person')
.set({ first_name: 'Jennifer' })
.where('person.id', '=', 1)
.executeTakeFirst()
console.log(result.numUpdatedRows)
Creates a with
query (Common Table Expression).
Common table expressions (CTE) are a great way to modularize complex queries. Essentially they allow you to run multiple separate queries within a single roundtrip to the DB.
Since CTEs are a part of the main query, query optimizers inside DB engines are able to optimize the overall query. For example, postgres is able to inline the CTEs inside the using queries if it decides it's faster.
const result = await db
// Create a CTE called `jennifers` that selects all
// persons named 'Jennifer'.
.with('jennifers', (db) => db
.selectFrom('person')
.where('first_name', '=', 'Jennifer')
.select(['id', 'age'])
)
// Select all rows from the `jennifers` CTE and
// further filter it.
.with('adult_jennifers', (db) => db
.selectFrom('jennifers')
.where('age', '>', 18)
.select(['id', 'age'])
)
// Finally select all adult jennifers that are
// also younger than 60.
.selectFrom('adult_jennifers')
.where('age', '<', 60)
.selectAll()
.execute()
Some databases like postgres also allow you to run other queries than selects in CTEs. On these databases CTEs are extremely powerful:
const result = await db
.with('new_person', (db) => db
.insertInto('person')
.values({
first_name: 'Jennifer',
age: 35,
})
.returning('id')
)
.with('new_pet', (db) => db
.insertInto('pet')
.values({
name: 'Doggo',
species: 'dog',
is_favorite: true,
// Use the id of the person we just inserted.
owner_id: db
.selectFrom('new_person')
.select('id')
})
.returning('id')
)
.selectFrom(['new_person', 'new_pet'])
.select([
'new_person.id as person_id',
'new_pet.id as pet_id'
])
.execute()
The CTE name can optionally specify column names in addition to a name. In that case Kysely requires the expression to retun rows with the same columns.
await db
.with('jennifers(id, age)', (db) => db
.selectFrom('person')
.where('first_name', '=', 'Jennifer')
// This is ok since we return columns with the same
// names as specified by `jennifers(id, age)`.
.select(['id', 'age'])
)
.selectFrom('jennifers')
.selectAll()
.execute()
The first argument can also be a callback. The callback is passed
a CTEBuilder
instance that can be used to configure the CTE:
await db
.with(
(cte) => cte('jennifers').materialized(),
(db) => db
.selectFrom('person')
.where('first_name', '=', 'Jennifer')
.select(['id', 'age'])
)
.selectFrom('jennifers')
.selectAll()
.execute()
Returns a copy of this Kysely instance without any plugins.
Returns a copy of this Kysely instance with the given plugin installed.
Creates a recursive with
query (Common Table Expression).
Note that recursiveness is a property of the whole with
statement.
You cannot have recursive and non-recursive CTEs in a same with
statement.
Therefore the recursiveness is determined by the first with
or
withRecusive
call you make.
See the with method for examples and more documentation.
Returns a copy of this Kysely instance with tables added to its database type.
This method only modifies the types and doesn't affect any of the executed queries in any way.
The following example adds and uses a temporary table:
await db.schema
.createTable('temp_table')
.temporary()
.addColumn('some_column', 'integer')
.execute()
const tempDb = db.withTables<{
temp_table: {
some_column: number
}
}>()
await tempDb
.insertInto('temp_table')
.values({ some_column: 100 })
.execute()
The main Kysely class.
You should create one instance of
Kysely
per database using the Kysely constructor. EachKysely
instance maintains its own connection pool.Examples
This example assumes your database has a "person" table: