Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Improve cursor performance #3661

Merged
merged 1 commit into from
Feb 9, 2023
Merged

Improve cursor performance #3661

merged 1 commit into from
Feb 9, 2023

Conversation

KhooHaoYit
Copy link
Contributor

@KhooHaoYit KhooHaoYit commented Feb 1, 2023

This PR fixes prisma/prisma#11138, and fixes prisma/prisma#12650
Might be related to prisma/prisma#16235, prisma/prisma#17328, and probably more

The implementation of how cursor is implemented before is to create a subquery, store it as a temporary table, and to be used to compare with the values in the table

But the issue with that is that the database would try to use nested loop to join the temporary table and the main table, which causes it to scan through everything before it until it found a match
The explanation can be found in this stackoverflow question and in prisma/prisma#12650+issuecomment-1099064362 you can see that Index Only Scan fetched 999,504 rows and Join Filter removed 999,500 rows

This PR fixes this issue by fetching the individual column to be compared direclty without creating a temporary table

Here's the difference between the generated query:

SELECT "public"."User"."id"
-FROM "public"."User",
-  (
-    SELECT "public"."User"."id" AS "User_id_0"
-    FROM "public"."User"
-    WHERE ("public"."User"."id") = ($1)
-  ) AS "order_cmp"
+FROM "public"."User"
-WHERE "public"."User"."id" >= "order_cmp"."User_id_0"
+WHERE "public"."User"."id" >= (
+    SELECT "public"."User"."id"
+    FROM "public"."User"
+    WHERE ("public"."User"."id") = ($1)
+  )
ORDER BY "public"."User"."id" ASC
LIMIT $2 OFFSET $3

And here's the difference running these queries with explain (analyze,verbose) running postgres using HDD:

// Before patch
Limit  (cost=0.85..1.08 rows=1 width=4) (actual time=0.583..0.584 rows=1 loops=1)
  Output: "User".id
  ->  Nested Loop  (cost=0.85..120627.11 rows=525676 width=4) (actual time=0.583..0.583 rows=1 loops=1)
        Output: "User".id
        Inner Unique: true
        Join Filter: ("User".id >= "User_1".id)
        Rows Removed by Join Filter: 999
        ->  Index Only Scan using "User_id_key" on public."User"  (cost=0.43..96963.22 rows=1577029 width=4) (actual time=0.014..0.408 rows=1000 loops=1)
              Output: "User".id
              Heap Fetches: 136
        ->  Materialize  (cost=0.43..8.45 rows=1 width=4) (actual time=0.000..0.000 rows=1 loops=1000)
              Output: "User_1".id
              ->  Index Only Scan using "User_id_key" on public."User" "User_1"  (cost=0.43..8.45 rows=1 width=4) (actual time=0.018..0.018 rows=1 loops=1)
                    Output: "User_1".id
                    Index Cond: ("User_1".id = 462273)
                    Heap Fetches: 0
Planning Time: 0.081 ms
Execution Time: 0.597 ms
// After patch
Limit  (cost=8.87..9.00 rows=1 width=4) (actual time=0.040..0.040 rows=1 loops=1)
  Output: "User".id
  InitPlan 1 (returns $0)
    ->  Index Only Scan using "User_id_key" on public."User" "User_1"  (cost=0.43..8.45 rows=1 width=4) (actual time=0.031..0.032 rows=1 loops=1)
          Output: "User_1".id
          Index Cond: ("User_1".id = 462273)
          Heap Fetches: 0
  ->  Index Only Scan using "User_id_key" on public."User"  (cost=0.43..67597.62 rows=525676 width=4) (actual time=0.039..0.039 rows=1 loops=1)
        Output: "User".id
        Index Cond: ("User".id >= $0)
        Heap Fetches: 0
Planning Time: 0.059 ms
Execution Time: 0.051 ms

On a more complex query, it might fetch the same column multiple times, but that's still faster than trying to scan through everything before it

@KhooHaoYit KhooHaoYit requested a review from a team February 1, 2023 08:39
@CLAassistant
Copy link

CLAassistant commented Feb 1, 2023

CLA assistant check
All committers have signed the CLA.

@tomhoule
Copy link
Contributor

tomhoule commented Feb 1, 2023

Thanks for the PR! We'll give it a proper review as soon as possible.

@tomhoule tomhoule self-requested a review February 9, 2023 14:05
Copy link
Contributor

@tomhoule tomhoule left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Sorry the review took so long!

This looks great, the description is really helpful and with a bit of focused reading, I think I understand all the changes. Let's merge this, see if it breaks any typescript-side tests but I think it won't.

Thanks again for the PR.

@tomhoule tomhoule added this to the 4.11.0 milestone Feb 9, 2023
@tomhoule tomhoule merged commit ff426a5 into prisma:main Feb 9, 2023
@KhooHaoYit
Copy link
Contributor Author

You're welcome, the wait is worth it for me

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
3 participants