Skip to content

Commit

Permalink
Add mysql json helpers
Browse files Browse the repository at this point in the history
  • Loading branch information
koskimas committed Mar 30, 2023
1 parent b5ffb79 commit 717e340
Show file tree
Hide file tree
Showing 7 changed files with 460 additions and 198 deletions.
7 changes: 6 additions & 1 deletion package.json
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{
"name": "kysely",
"version": "0.24.0",
"version": "0.24.1",
"description": "Type safe SQL query builder",
"repository": {
"type": "git",
Expand All @@ -21,6 +21,11 @@
"import": "./dist/esm/helpers/postgres.js",
"require": "./dist/cjs/helpers/postgres.js",
"default": "./dist/cjs/helpers/postgres.js"
},
"./helpers/mysql": {
"import": "./dist/esm/helpers/mysql.js",
"require": "./dist/cjs/helpers/mysql.js",
"default": "./dist/cjs/helpers/mysql.js"
}
},
"scripts": {
Expand Down
38 changes: 22 additions & 16 deletions site/docs/recipes/relations.md
Original file line number Diff line number Diff line change
Expand Up @@ -8,25 +8,25 @@ Kysely IS a query builder. Kysely DOES build the SQL you tell it to, nothing mor
Phew, glad we got that out the way..

All that was said above doesn't mean there's no way to nest related rows in your queries.
You just have to do it with the tools SQL and the underlying dialect (e.g. PostgreSQL) you're using provide.
In this recipe we show one way to do that when using the PostgreSQL built-in dialect.
You just have to do it with the tools SQL and the underlying dialect (e.g. PostgreSQL or MySQL) you're using provide.
In this recipe we show one way to do that when using the built-in PostgreSQL and MySQL dialects.

## PostgreSQL `jsonb` data type and functions
## The `json` data type and functions

PostgreSQL has rich JSON support through its `json` and `jsonb` data types and functions. `pg`, the node PostgreSQL driver, automatically parses returned `json` and `jsonb` columns as json objects. With the combination of these two things, we can write some super efficient queries with nested relations.
Both PostgreSQL and MySQL have rich JSON support through their `json` data types and functions. `pg` and `mysql2`, the node drivers, automatically parse returned `json` columns as json objects. With the combination of these two things, we can write some super efficient queries with nested relations.

Let's start with some raw SQL, and then see how we can write the query using Kysely in a nice type-safe way.
Let's start with some raw postgres SQL, and then see how we can write the query using Kysely in a nice type-safe way.

In the following query, we fetch a list of people (from "person" table) and for each person, we nest the person's pets, and mother, into the returned objects:

```sql
SELECT
person.*,

-- Select person's pets as a jsonb array
-- Select person's pets as a json array
(
SELECT
COALESCE(JSONB_AGG(pets), '[]')
COALESCE(JSON_AGG(pets), '[]')
FROM
(
SELECT
Expand All @@ -40,14 +40,14 @@ SELECT
) pets
) pets,

-- Select person's mother as a jsonb object
-- Select person's mother as a json object
(
SELECT
TO_JSONB(mother)
TO_JSON(mother)
FROM
(
SELECT
mother.*
mother.id, mother.first_name
FROM
person as mother
WHERE
Expand All @@ -66,13 +66,13 @@ Fortunately we can improve and simplify this a lot using Kysely. First let's def
function jsonArrayFrom<O>(
expr: Expression<O>
): RawBuilder<Simplify<O>[]> {
return sql`(select coalesce(jsonb_agg(agg), '[]') from ${expr} as agg)`
return sql`(select coalesce(json_agg(agg), '[]') from ${expr} as agg)`
}

export function jsonObjectFrom<O>(
expr: Expression<O>
): RawBuilder<Simplify<O>> {
return sql`(select to_jsonb(obj) from ${expr} as obj)`
return sql`(select to_json(obj) from ${expr} as obj)`
}
```

Expand All @@ -82,6 +82,12 @@ These helpers are included in Kysely and you can import them from the `helpers`
import { jsonArrayFrom, jsonObjectFrom } from 'kysely/helpers/postgres'
```

For MySQL the helpers are slightly different but you can use them the same way. You can import them like this:

```ts
import { jsonArrayFrom, jsonObjectFrom } from 'kysely/helpers/mysql'
```

With these helpers, our example query already becomes a little more bearable to look at:

```ts
Expand All @@ -100,13 +106,13 @@ const persons = await db
// mother
jsonObjectFrom(
eb.selectFrom('person as mother')
.selectAll('mother')
.select(['mother.id', 'mother.first_name'])
.whereRef('mother.id', '=', 'person.mother_id')
).as('mother')
])

console.log(persons[0].pets[0].name)
console.log(persons[0].mother.last_name)
console.log(persons[0].mother.first_name)
```

That's better right? If you need to do this over and over in your codebase, you can create some helpers like these:
Expand All @@ -124,7 +130,7 @@ function withPets(eb: ExpressionBuilder<DB, 'person'>) {
function withMom(eb: ExpressionBuilder<DB, 'person'>) {
return jsonObjectFrom(
eb.selectFrom('person as mother')
.selectAll('mother')
.select(['mother.id', 'mother.first_name'])
.whereRef('mother.id', '=', 'person.mother_id')
).as('mother')
}
Expand All @@ -142,5 +148,5 @@ const persons = await db
])

console.log(persons[0].pets[0].name)
console.log(persons[0].mother.last_name)
console.log(persons[0].mother.first_name)
```
191 changes: 191 additions & 0 deletions src/helpers/mysql.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,191 @@
import { Expression } from '../expression/expression.js'
import { AliasNode } from '../operation-node/alias-node.js'
import { ColumnNode } from '../operation-node/column-node.js'
import { IdentifierNode } from '../operation-node/identifier-node.js'
import { ReferenceNode } from '../operation-node/reference-node.js'
import { SelectQueryNode } from '../operation-node/select-query-node.js'
import { SelectQueryBuilder } from '../query-builder/select-query-builder.js'
import { RawBuilder } from '../raw-builder/raw-builder.js'
import { sql } from '../raw-builder/sql.js'
import { Simplify } from '../util/type-utils.js'

/**
* A MySQL helper for aggregating a subquery (or other expression) into a JSON array.
*
* NOTE: This helper is only guaranteed to fully work with the built-in `MysqlDialect`.
* While the produced SQL is compatibe with all MySQL databases, some 3rd party dialects
* may not parse the nested results into arrays.
*
* ### Examples
*
* ```ts
* const result = await db
* .selectFrom('person')
* .select((eb) => [
* 'id',
* jsonArrayFrom(
* eb.selectFrom('pet')
* .select(['pet.id as pet_id', 'pet.name'])
* .where('pet.owner_id', '=', 'person.id')
* .orderBy('pet.name')
* ).as('pets')
* ])
* .execute()
*
* result[0].id
* result[0].pets[0].pet_id
* result[0].pets[0].name
* ```
*
* The generated SQL (MySQL):
*
* ```sql
* select `id`, (
* select cast(coalesce(json_arrayagg(json_object(
* 'pet_id', `agg`.`pet_id`,
* 'name', `agg`.`name`
* )), '[]') as json) from (
* select `pet`.`id` as `pet_id`, `pet`.`name`
* from `pet`
* where `pet`.`owner_id` = `person`.`id`
* order by `pet`.`name`
* ) as `agg`
* ) as `pets`
* from `person`
* ```
*/
export function jsonArrayFrom<O>(
expr: SelectQueryBuilder<any, any, O>
): RawBuilder<Simplify<O>[]> {
return sql`(select cast(coalesce(json_arrayagg(json_object(${sql.join(
getJsonObjectArgs(expr.toOperationNode(), 'agg')
)})), '[]') as json) from ${expr} as agg)`
}

/**
* A MySQL helper for turning a subquery (or other expression) into a JSON object.
*
* The subquery must only return one row.
*
* NOTE: This helper is only guaranteed to fully work with the built-in `MysqlDialect`.
* While the produced SQL is compatibe with all MySQL databases, some 3rd party dialects
* may not parse the nested results into objects.
*
* ### Examples
*
* ```ts
* const result = await db
* .selectFrom('person')
* .select((eb) => [
* 'id',
* jsonObjectFrom(
* eb.selectFrom('pet')
* .select(['pet.id as pet_id', 'pet.name'])
* .where('pet.owner_id', '=', 'person.id')
* .where('pet.is_favorite', '=', true)
* ).as('favorite_pet')
* ])
* .execute()
*
* result[0].id
* result[0].favorite_pet.pet_id
* result[0].favorite_pet.name
* ```
*
* The generated SQL (MySQL):
*
* ```sql
* select `id`, (
* select json_object(
* 'pet_id', `obj`.`pet_id`,
* 'name', `obj`.`name`
* ) from (
* select `pet`.`id` as `pet_id`, `pet`.`name`
* from `pet`
* where `pet`.`owner_id` = `person`.`id`
* and `pet`.`is_favorite` = ?
* ) as obj
* ) as `favorite_pet`
* from `person`
* ```
*/
export function jsonObjectFrom<O>(
expr: SelectQueryBuilder<any, any, O>
): RawBuilder<Simplify<O>> {
return sql`(select json_object(${sql.join(
getJsonObjectArgs(expr.toOperationNode(), 'obj')
)}) from ${expr} as obj)`
}

/**
* The MySQL `json_object` function.
*
* NOTE: This helper is only guaranteed to fully work with the built-in `MysqlDialect`.
* While the produced SQL is compatibe with all MySQL databases, some 3rd party dialects
* may not parse the nested results into objects.
*
* ### Examples
*
* ```ts
* const result = await db
* .selectFrom('person')
* .select((eb) => [
* 'id',
* jsonBuildObject({
* first: eb.ref('first_name'),
* last: eb.ref('last_name'),
* full: eb.fn('concat', ['first_name', eb.val(' '), 'last_name'])
* }).as('name')
* ])
* .execute()
*
* result[0].id
* result[0].name.first
* result[0].name.last
* result[0].name.full
* ```
*
* The generated SQL (MySQL):
*
* ```sql
* select "id", json_object(
* 'first', first_name,
* 'last', last_name,
* 'full', concat(`first_name`, ?, `last_name`)
* ) as "name"
* from "person"
* ```
*/
export function jsonBuildObject<O extends Record<string, Expression<unknown>>>(
obj: O
): RawBuilder<
Simplify<{
[K in keyof O]: O[K] extends Expression<infer V> ? V : never
}>
> {
return sql`json_object(${sql.join(
Object.keys(obj).flatMap((k) => [sql.lit(k), obj[k]])
)})`
}

function getJsonObjectArgs(
node: SelectQueryNode,
table: string
): RawBuilder<unknown>[] {
return node.selections!.flatMap(({ selection: s }) => {
if (ReferenceNode.is(s) && ColumnNode.is(s.column)) {
return [
sql.lit(s.column.column.name),
sql.id(table, s.column.column.name),
]
} else if (ColumnNode.is(s)) {
return [sql.lit(s.column.name), sql.id(table, s.column.name)]
} else if (AliasNode.is(s) && IdentifierNode.is(s.alias)) {
return [sql.lit(s.alias.name), sql.id(table, s.alias.name)]
} else {
throw new Error(
'MySQL jsonArrayFrom and jsonObjectFrom functions can only handle explicit selections due to limitations of the json_object function. selectAll() is not allowed in the subquery.'
)
}
})
}
Loading

0 comments on commit 717e340

Please sign in to comment.