-
-
Notifications
You must be signed in to change notification settings - Fork 655
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #981 from drizzle-team:improve-types-performance
Add type performance improvements
- Loading branch information
Showing
143 changed files
with
2,770 additions
and
2,841 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1 +1 @@ | ||
19 | ||
18 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,174 @@ | ||
## Breaking changes | ||
|
||
### Removed support for filtering by nested relations | ||
|
||
Current example won't work in `0.28.0`: | ||
|
||
```ts | ||
const usersWithPosts = await db.query.users.findMany({ | ||
where: (table, { sql }) => (sql`json_array_length(${table.posts}) > 0`), | ||
with: { | ||
posts: true, | ||
}, | ||
}); | ||
``` | ||
|
||
The `table` object in the `where` callback won't have fields from `with` and `extras`. We removed them to be able to build more efficient relational queries, which improved row reads and performance. | ||
|
||
If you have used those fields in the `where` callback before, there are several workarounds: | ||
|
||
1. Applying those filters manually on the code level after the rows are fetched; | ||
2. Using the core API. | ||
|
||
### Added Relational Queries `mode` config for `mysql2` driver | ||
|
||
Drizzle relational queries always generate exactly one SQL statement to run on the database and it has certain caveats. To have best in class support for every database out there we've introduced modes. | ||
|
||
Drizzle relational queries use lateral joins of subqueries under the hood and for now PlanetScale does not support them. | ||
|
||
When using `mysql2` driver with regular MySQL database - you should specify mode: "default". | ||
When using `mysql2` driver with PlanetScale - you need to specify mode: "planetscale". | ||
|
||
```ts | ||
import { drizzle } from 'drizzle-orm/mysql2'; | ||
import mysql from 'mysql2/promise'; | ||
import * as schema from './schema'; | ||
|
||
const connection = await mysql.createConnection({ | ||
uri: process.env.PLANETSCALE_DATABASE_URL, | ||
}); | ||
|
||
const db = drizzle(connection, { schema, mode: 'planetscale' }); | ||
``` | ||
|
||
## Improved IntelliSense performance for large schemas | ||
|
||
We've run the diagnostics on a database schema with 85 tables, 666 columns, 26 enums, 172 indexes and 133 foreign keys. We've optimized internal types which resulted in **430%** speed up in IntelliSense. | ||
|
||
## Improved Relational Queries Permormance and Read Usage | ||
|
||
In this release we've fully changed a way query is generated for Relational Queri API. | ||
|
||
As a summary we've made current set of changes in query generation startegy: | ||
|
||
1. Lateral Joins: In the new version we're utilizing lateral joins, denoted by the "LEFT JOIN LATERAL" clauses, to retrieve specific data from related tables efficiently For MySQL in PlanetScale and SQLite, we've used simple subquery selects, which improved a query plan and overall performance | ||
|
||
2. Selective Data Retrieval: In the new version we're retrieving only the necessary data from tables. This targeted data retrieval reduces the amount of unnecessary information fetched, resulting in a smaller dataset to process and faster execution. | ||
|
||
3. Reduced Aggregations: In the new version we've reduced the number of aggregation functions (e.g., COUNT, json_agg). By using json_build_array directly within the lateral joins, drizzle is aggregating the data in a more streamlined manner, leading to improved query performance. | ||
|
||
4. Simplified Grouping: In the new version the GROUP BY clause is removed, as the lateral joins and subqueries already handle data aggregation more efficiently. | ||
|
||
For this drizzle query | ||
|
||
```ts | ||
const items = await db.query.comments.findMany({ | ||
limit, | ||
orderBy: comments.id, | ||
with: { | ||
user: { | ||
columns: { name: true }, | ||
}, | ||
post: { | ||
columns: { title: true }, | ||
with: { | ||
user: { | ||
columns: { name: true }, | ||
}, | ||
}, | ||
}, | ||
}, | ||
}); | ||
``` | ||
|
||
Query that Drizzle generates now | ||
|
||
```sql | ||
select "comments"."id", | ||
"comments"."user_id", | ||
"comments"."post_id", | ||
"comments"."content", | ||
"comments_user"."data" as "user", | ||
"comments_post"."data" as "post" | ||
from "comments" | ||
left join lateral (select json_build_array("comments_user"."name") as "data" | ||
from (select * | ||
from "users" "comments_user" | ||
where "comments_user"."id" = "comments"."user_id" | ||
limit 1) "comments_user") "comments_user" on true | ||
left join lateral (select json_build_array("comments_post"."title", "comments_post_user"."data") as "data" | ||
from (select * | ||
from "posts" "comments_post" | ||
where "comments_post"."id" = "comments"."post_id" | ||
limit 1) "comments_post" | ||
left join lateral (select json_build_array("comments_post_user"."name") as "data" | ||
from (select * | ||
from "users" "comments_post_user" | ||
where "comments_post_user"."id" = "comments_post"."user_id" | ||
limit 1) "comments_post_user") "comments_post_user" | ||
on true) "comments_post" on true | ||
order by "comments"."id" | ||
limit 1 | ||
``` | ||
|
||
Query generated before: | ||
|
||
```sql | ||
SELECT "id", | ||
"user_id", | ||
"post_id", | ||
"content", | ||
"user"::JSON, | ||
"post"::JSON | ||
FROM | ||
(SELECT "comments".*, | ||
CASE | ||
WHEN count("comments_post"."id") = 0 THEN '[]' | ||
ELSE json_agg(json_build_array("comments_post"."title", "comments_post"."user"::JSON))::text | ||
END AS "post" | ||
FROM | ||
(SELECT "comments".*, | ||
CASE | ||
WHEN count("comments_user"."id") = 0 THEN '[]' | ||
ELSE json_agg(json_build_array("comments_user"."name"))::text | ||
END AS "user" | ||
FROM "comments" | ||
LEFT JOIN | ||
(SELECT "comments_user".* | ||
FROM "users" "comments_user") "comments_user" ON "comments"."user_id" = "comments_user"."id" | ||
GROUP BY "comments"."id", | ||
"comments"."user_id", | ||
"comments"."post_id", | ||
"comments"."content") "comments" | ||
LEFT JOIN | ||
(SELECT "comments_post".* | ||
FROM | ||
(SELECT "comments_post".*, | ||
CASE | ||
WHEN count("comments_post_user"."id") = 0 THEN '[]' | ||
ELSE json_agg(json_build_array("comments_post_user"."name")) | ||
END AS "user" | ||
FROM "posts" "comments_post" | ||
LEFT JOIN | ||
(SELECT "comments_post_user".* | ||
FROM "users" "comments_post_user") "comments_post_user" ON "comments_post"."user_id" = "comments_post_user"."id" | ||
GROUP BY "comments_post"."id") "comments_post") "comments_post" ON "comments"."post_id" = "comments_post"."id" | ||
GROUP BY "comments"."id", | ||
"comments"."user_id", | ||
"comments"."post_id", | ||
"comments"."content", | ||
"comments"."user") "comments" | ||
LIMIT 1 | ||
``` | ||
|
||
## Possibility to insert rows with default values for all columns | ||
|
||
You can now provide an empty object or an array of empty objects, and Drizzle will insert all defaults into the database. | ||
|
||
```ts | ||
// Insert 1 row with all defaults | ||
await db.insert(usersTable).values({}); | ||
|
||
// Insert 2 rows with all defaults | ||
await db.insert(usersTable).values([{}, {}]); | ||
``` |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
- Added compatibility with Drizzle 0.28.0 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.