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

qe: support _count in joined queries #4678

Merged
merged 27 commits into from
Feb 5, 2024
Merged

qe: support _count in joined queries #4678

merged 27 commits into from
Feb 5, 2024

Conversation

aqrln
Copy link
Member

@aqrln aqrln commented Jan 29, 2024

Description

Implement relation aggregations support for the join strategy:

  • Build relation aggregation queries in the new query builder
  • Add new methods to the abstractions that represent selections to account for differences in representation in queries that use or don't use JSON objects
  • Implement coercion and serialization logic

Next step: https://github.com/prisma/team-orm/issues/903

Part of: https://github.com/prisma/team-orm/issues/700
Closes: https://github.com/prisma/team-orm/issues/902

Examples

Schema

model User {
  id         Int       @id @default(autoincrement())
  login      String    @unique
  profile    Profile?
  posts      Post[]
  comments   Comment[]
  followedBy User[]    @relation("UserFollows")
  follows    User[]    @relation("UserFollows")
}

model Profile {
  id      Int     @id @default(autoincrement())
  user    User    @relation(fields: [userId], references: [id])
  userId  Int     @unique
  name    String?
  address String?
}

model Post {
  id       Int       @id @default(autoincrement())
  user     User      @relation(fields: [userId], references: [id])
  userId   Int
  title    String
  content  String
  comments Comment[]
}

model Comment {
  id     Int    @id @default(autoincrement())
  body   String
  post   Post   @relation(fields: [postId], references: [id])
  postId Int
  user   User   @relation(fields: [userId], references: [id])
  userId Int
}

1:m, top-level

query {
  findManyUser {
    _count {
      comments(where: { postId: 1 })
    }
  }
}
SELECT
  "t1"."id",
  JSONB_BUILD_OBJECT(
    'comments',
    COALESCE(
      "aggr_count_User_comments"."_aggr_count_comments",
      0
    )
  ) AS "_count"
FROM
  "public"."User" AS "t1"
  LEFT JOIN LATERAL (
    SELECT
      COUNT(*) AS "_aggr_count_comments"
    FROM
      "public"."Comment" AS "t2"
    WHERE
      (
        "t1"."id" = "t2"."userId"
        AND "t2"."postId" = $1
      )
  ) AS "aggr_count_User_comments" ON true

m:n, top-level

query {
  findManyUser {
    _count {
      follows(where: { profile: { isNot: null } })
    }
  }
}
SELECT
  "t1"."id",
  JSONB_BUILD_OBJECT(
    'follows',
    COALESCE(
      "aggr_count_User_follows"."_aggr_count_follows",
      0
    )
  ) AS "_count"
FROM
  "public"."User" AS "t1"
  LEFT JOIN LATERAL (
    SELECT
      COUNT(*) AS "_aggr_count_follows"
    FROM
      "public"."User" AS "t2"
      LEFT JOIN "public"."_UserFollows" AS "t3" ON "t3"."A" = "t2"."id"
      LEFT JOIN "public"."Profile" AS "j1" ON ("j1"."userId") = ("t2"."id")
    WHERE
      (
        "t3"."B" = "t1"."id"
        AND (NOT ("j1"."userId" IS NULL))
      )
  ) AS "aggr_count_User_follows" ON true

1:m, nested

query {
  findManyUser {
    posts {
      _count {
        comments
      }
    }
  }
}
SELECT
  "t1"."id",
  "User_posts"."__prisma_data__" AS "posts"
FROM
  "public"."User" AS "t1"
  LEFT JOIN LATERAL (
    SELECT
      COALESCE(JSONB_AGG("__prisma_data__"), '[]') AS "__prisma_data__"
    FROM
      (
        SELECT
          "t4"."__prisma_data__"
        FROM
          (
            SELECT
              JSONB_BUILD_OBJECT(
                '_count',
                JSONB_BUILD_OBJECT(
                  'comments',
                  COALESCE(
                    "aggr_count_Post_comments"."_aggr_count_comments",
                    0
                  )
                )
              ) AS "__prisma_data__"
            FROM
              (
                SELECT
                  "t2".*
                FROM
                  "public"."Post" AS "t2"
                WHERE
                  "t1"."id" = "t2"."userId"
                  /* root select */
              ) AS "t3"
              LEFT JOIN LATERAL (
                SELECT
                  COUNT(*) AS "_aggr_count_comments"
                FROM
                  "public"."Comment" AS "t6"
                WHERE
                  "t3"."id" = "t6"."postId"
              ) AS "aggr_count_Post_comments" ON true
              /* inner select */
          ) AS "t4"
          /* middle select */
      ) AS "t5"
      /* outer select */
  ) AS "User_posts" ON true

@aqrln aqrln added this to the 5.9.0 milestone Jan 29, 2024
@aqrln aqrln self-assigned this Jan 29, 2024
Copy link
Contributor

github-actions bot commented Jan 29, 2024

WASM Size

Engine This PR Base branch Diff
WASM 2.165MiB 2.150MiB 15.586KiB
WASM (gzip) 836.677KiB 831.097KiB 5.581KiB

Copy link

codspeed-hq bot commented Jan 29, 2024

CodSpeed Performance Report

Merging #4678 will not alter performance

Comparing relation-count-join (b0de214) with main (2db61cf)

Summary

✅ 11 untouched benchmarks

Copy link
Contributor

github-actions bot commented Jan 29, 2024

🚀 WASM query-engine performance will improve by 2.44%

Full benchmark report
DATABASE_URL="postgresql://postgres:postgres@localhost:5432/bench?schema=imdb_bench&sslmode=disable" \
node --experimental-wasm-modules query-engine/driver-adapters/executor/dist/bench.mjs
cpu: AMD EPYC 7763 64-Core Processor
runtime: node v18.19.0 (x64-linux)

benchmark                   time (avg)             (min … max)       p75       p99      p999
-------------------------------------------------------------- -----------------------------
• movies.findMany() (all - 25000)
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline  303.54 ms/iter (302.79 ms … 304.41 ms) 304.14 ms 304.41 ms 304.41 ms
Web Assembly: Latest    389.95 ms/iter  (389.1 ms … 393.19 ms) 390.35 ms 393.19 ms 393.19 ms
Web Assembly: Current   381.09 ms/iter (379.25 ms … 384.34 ms) 383.45 ms 384.34 ms 384.34 ms
Node API: Current       226.37 ms/iter (221.23 ms … 229.82 ms) 229.41 ms 229.82 ms 229.82 ms

summary for movies.findMany() (all - 25000)
  Web Assembly: Current
   1.68x slower than Node API: Current
   1.26x slower than Web Assembly: Baseline
   1.02x faster than Web Assembly: Latest

• movies.findMany({ take: 2000 })
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline   12.18 ms/iter   (12.05 ms … 12.63 ms)  12.21 ms  12.63 ms  12.63 ms
Web Assembly: Latest     16.35 ms/iter   (16.21 ms … 16.83 ms)  16.39 ms  16.83 ms  16.83 ms
Web Assembly: Current    15.79 ms/iter   (15.53 ms … 17.43 ms)  15.76 ms  17.43 ms  17.43 ms
Node API: Current        8,808 µs/iter   (8,600 µs … 9,265 µs)  8,836 µs  9,265 µs  9,265 µs

summary for movies.findMany({ take: 2000 })
  Web Assembly: Current
   1.79x slower than Node API: Current
   1.3x slower than Web Assembly: Baseline
   1.04x faster than Web Assembly: Latest

• movies.findMany({ where: {...}, take: 2000 })
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline   1,908 µs/iter   (1,830 µs … 2,952 µs)  1,901 µs  2,343 µs  2,952 µs
Web Assembly: Latest     2,555 µs/iter   (2,461 µs … 3,674 µs)  2,544 µs  3,452 µs  3,674 µs
Web Assembly: Current    2,497 µs/iter   (2,390 µs … 3,872 µs)  2,481 µs  3,579 µs  3,872 µs
Node API: Current        1,510 µs/iter   (1,441 µs … 1,894 µs)  1,524 µs  1,717 µs  1,894 µs

summary for movies.findMany({ where: {...}, take: 2000 })
  Web Assembly: Current
   1.65x slower than Node API: Current
   1.31x slower than Web Assembly: Baseline
   1.02x faster than Web Assembly: Latest

• movies.findMany({ include: { cast: true } take: 2000 }) (m2m)
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline   12.16 ms/iter   (12.04 ms … 12.46 ms)  12.18 ms  12.46 ms  12.46 ms
Web Assembly: Latest     16.18 ms/iter   (16.11 ms … 16.34 ms)   16.2 ms  16.34 ms  16.34 ms
Web Assembly: Current    15.69 ms/iter    (15.6 ms … 15.86 ms)  15.72 ms  15.86 ms  15.86 ms
Node API: Current        9,074 µs/iter      (8,627 µs … 12 ms)  9,016 µs     12 ms     12 ms

summary for movies.findMany({ include: { cast: true } take: 2000 }) (m2m)
  Web Assembly: Current
   1.73x slower than Node API: Current
   1.29x slower than Web Assembly: Baseline
   1.03x faster than Web Assembly: Latest

• movies.findMany({ where: {...}, include: { cast: true } take: 2000 }) (m2m)
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline   1,914 µs/iter   (1,830 µs … 2,718 µs)  1,901 µs  2,439 µs  2,718 µs
Web Assembly: Latest     2,531 µs/iter   (2,444 µs … 3,047 µs)  2,544 µs  2,985 µs  3,047 µs
Web Assembly: Current    2,505 µs/iter   (2,384 µs … 3,928 µs)  2,484 µs  3,349 µs  3,928 µs
Node API: Current        1,509 µs/iter   (1,440 µs … 1,792 µs)  1,523 µs  1,700 µs  1,792 µs

summary for movies.findMany({ where: {...}, include: { cast: true } take: 2000 }) (m2m)
  Web Assembly: Current
   1.66x slower than Node API: Current
   1.31x slower than Web Assembly: Baseline
   1.01x faster than Web Assembly: Latest

• movies.findMany({ take: 2000, include: { cast: { include: { person: true } } } })
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline   12.12 ms/iter   (12.03 ms … 12.25 ms)  12.16 ms  12.25 ms  12.25 ms
Web Assembly: Latest     16.05 ms/iter    (15.95 ms … 16.2 ms)  16.09 ms   16.2 ms   16.2 ms
Web Assembly: Current    15.57 ms/iter    (15.48 ms … 15.7 ms)  15.59 ms   15.7 ms   15.7 ms
Node API: Current        9,002 µs/iter   (8,706 µs … 9,375 µs)  9,124 µs  9,375 µs  9,375 µs

summary for movies.findMany({ take: 2000, include: { cast: { include: { person: true } } } })
  Web Assembly: Current
   1.73x slower than Node API: Current
   1.28x slower than Web Assembly: Baseline
   1.03x faster than Web Assembly: Latest

• movie.findMany({ where: { ... }, take: 2000, include: { cast: { include: { person: true } } } })
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline   1,860 µs/iter   (1,804 µs … 2,151 µs)  1,877 µs  2,061 µs  2,151 µs
Web Assembly: Latest     2,492 µs/iter   (2,428 µs … 2,886 µs)  2,500 µs  2,709 µs  2,886 µs
Web Assembly: Current    2,445 µs/iter   (2,362 µs … 2,919 µs)  2,441 µs  2,813 µs  2,919 µs
Node API: Current        1,494 µs/iter   (1,409 µs … 1,735 µs)  1,512 µs  1,726 µs  1,735 µs

summary for movie.findMany({ where: { ... }, take: 2000, include: { cast: { include: { person: true } } } })
  Web Assembly: Current
   1.64x slower than Node API: Current
   1.31x slower than Web Assembly: Baseline
   1.02x faster than Web Assembly: Latest

• movie.findMany({ where: { reviews: { author: { ... } }, take: 100 }) (to-many -> to-one)
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline  910.23 µs/iter  (855.29 µs … 1,476 µs)  906.2 µs  1,406 µs  1,476 µs
Web Assembly: Latest     1,238 µs/iter   (1,188 µs … 1,849 µs)  1,240 µs  1,607 µs  1,849 µs
Web Assembly: Current    1,209 µs/iter   (1,168 µs … 1,601 µs)  1,215 µs  1,419 µs  1,601 µs
Node API: Current       802.61 µs/iter  (742.36 µs … 1,017 µs) 821.07 µs 936.52 µs  1,017 µs

summary for movie.findMany({ where: { reviews: { author: { ... } }, take: 100 }) (to-many -> to-one)
  Web Assembly: Current
   1.51x slower than Node API: Current
   1.33x slower than Web Assembly: Baseline
   1.02x faster than Web Assembly: Latest

• movie.findMany({ where: { cast: { person: { ... } }, take: 100 }) (m2m -> to-one)
-------------------------------------------------------------- -----------------------------
Web Assembly: Baseline  930.08 µs/iter  (883.74 µs … 1,512 µs) 923.62 µs  1,456 µs  1,512 µs
Web Assembly: Latest     1,241 µs/iter   (1,190 µs … 1,834 µs)  1,244 µs  1,553 µs  1,834 µs
Web Assembly: Current    1,206 µs/iter   (1,145 µs … 2,036 µs)  1,208 µs  1,647 µs  2,036 µs
Node API: Current       801.92 µs/iter  (743.09 µs … 1,448 µs)  822.2 µs 919.75 µs  1,448 µs

summary for movie.findMany({ where: { cast: { person: { ... } }, take: 100 }) (m2m -> to-one)
  Web Assembly: Current
   1.5x slower than Node API: Current
   1.3x slower than Web Assembly: Baseline
   1.03x faster than Web Assembly: Latest

After changes in b0de214

@aqrln aqrln modified the milestones: 5.9.0, 5.10.0 Jan 31, 2024
@aqrln aqrln force-pushed the relation-count-join branch 2 times, most recently from 7d7c9b9 to 11d6ea7 Compare February 1, 2024 11:05
}

fn relation_count_alias_name(rf: &RelationField) -> String {
format!("aggr_count_{}_{}", rf.model().name(), rf.name())
Copy link
Member Author

@aqrln aqrln Feb 1, 2024

Choose a reason for hiding this comment

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

Won't technically be necessary once https://github.com/prisma/team-orm/issues/903 is done, we could then replace it with a sequential alias if we want.

@aqrln aqrln requested a review from Weakky February 1, 2024 14:37
@aqrln aqrln marked this pull request as ready for review February 1, 2024 14:41
@aqrln aqrln requested a review from a team as a code owner February 1, 2024 14:41
@aqrln aqrln requested review from jkomyno and removed request for a team February 1, 2024 14:41
Copy link
Contributor

@Weakky Weakky left a comment

Choose a reason for hiding this comment

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

Looks good to me. Could you please update the main PR comment with examples of the generated SQL queries, for one2m and m2m? This is useful to get a concrete idea of the change.

Nice work 👍

@janpio janpio changed the title qe: support _count in joined queries qe: support _count in joined queries Feb 1, 2024
@aqrln aqrln merged commit 16a6fe5 into main Feb 5, 2024
114 checks passed
@aqrln aqrln deleted the relation-count-join branch February 5, 2024 10:52
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants