Michael Manganiello 5f6bd4ae7e
fix(server): Reduce number of bound parameters in Access queries (#6015)
* fix(server): Reduce number of bound parameters in Access queries

According to https://github.com/typeorm/typeorm/issues/7565, the
introduction of bulk queries for permission checks could quickly reach
the limit of 65536 bound parameters allowed by the PostgreSQL
connection.

To avoid reaching that limit, this first change refactors the Access
queries that are expanding the set of ids multiple times. For example,
`asset.checkSharedLinkAccess` expands the ids 4 times, so providing just
~16400 ids is enough to break the query.

Refactored queries:

* activity.checkCreateAccess

```sql
-- Before
SELECT "AlbumEntity"."id" AS "AlbumEntity_id"
FROM "albums" "AlbumEntity"
    LEFT JOIN "albums_shared_users_users" "AlbumEntity_AlbumEntity__AlbumEntity_sharedUsers"
        ON "AlbumEntity_AlbumEntity__AlbumEntity_sharedUsers"."albumsId"="AlbumEntity"."id"
    LEFT JOIN "users" "AlbumEntity__AlbumEntity_sharedUsers"
        ON "AlbumEntity__AlbumEntity_sharedUsers"."id"="AlbumEntity_AlbumEntity__AlbumEntity_sharedUsers"."usersId"
        AND ("AlbumEntity__AlbumEntity_sharedUsers"."deletedAt" IS NULL)
WHERE
    (
        (
            "AlbumEntity"."id" IN ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
            AND "AlbumEntity"."isActivityEnabled" = $11
            AND "AlbumEntity__AlbumEntity_sharedUsers"."id" = $12
        )
        OR (
            "AlbumEntity"."id" IN ($13, $14, $15, $16, $17, $18, $19, $20, $21, $22)
            AND "AlbumEntity"."isActivityEnabled" = $23
            AND "AlbumEntity"."ownerId" = $24
        )
    )
    AND "AlbumEntity"."deletedAt" IS NULL

-- After
SELECT "album"."id" AS "album_id"
FROM "albums" "album"
    LEFT JOIN "albums_shared_users_users" "album_sharedUsers"
        ON "album_sharedUsers"."albumsId"="album"."id"
    LEFT JOIN "users" "sharedUsers"
        ON "sharedUsers"."id"="album_sharedUsers"."usersId"
        AND "sharedUsers"."deletedAt" IS NULL
WHERE
    "album"."id" IN ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
    AND "album"."isActivityEnabled" = true
    AND (
        "album"."ownerId" = $11
        OR "sharedUsers"."id" = $12
    )
    AND "album"."deletedAt" IS NULL
```

* asset.checkAlbumAccess

```sql
-- Before
SELECT
    "asset"."id" AS "assetId",
    "asset"."livePhotoVideoId" AS "livePhotoVideoId"
FROM "albums" "album"
    INNER JOIN "albums_assets_assets" "album_asset"
        ON "album_asset"."albumsId"="album"."id"
    INNER JOIN "assets" "asset"
        ON "asset"."id"="album_asset"."assetsId"
        AND "asset"."deletedAt" IS NULL
    LEFT JOIN "albums_shared_users_users" "album_sharedUsers"
        ON "album_sharedUsers"."albumsId"="album"."id"
    LEFT JOIN "users" "sharedUsers"
        ON "sharedUsers"."id"="album_sharedUsers"."usersId"
        AND "sharedUsers"."deletedAt" IS NULL
WHERE
    (
        "album"."ownerId" = $1
        OR "sharedUsers"."id" = $2
    )
    AND (
        "asset"."id" IN ($3, $4, $5, $6, $7, $8, $9, $10, $11, $12)
        OR "asset"."livePhotoVideoId" IN ($13, $14, $15, $16, $17, $18, $19, $20, $21, $22)
    )
    AND "album"."deletedAt" IS NULL

-- After
WITH "assetIds" AS (
    SELECT unnest(array[$1, $2, $3, $4, $5, $6, $7, $8, $9, $10])::uuid AS "id"
    FROM (SELECT 1 AS dummy_column) "dummy_table"
)
SELECT
    "asset"."id" AS "assetId",
    "asset"."livePhotoVideoId" AS "livePhotoVideoId"
FROM "albums" "album"
    INNER JOIN "albums_assets_assets" "album_asset"
        ON "album_asset"."albumsId"="album"."id"
    INNER JOIN "assets" "asset"
        ON "asset"."id"="album_asset"."assetsId"
        AND "asset"."deletedAt" IS NULL
    LEFT JOIN "albums_shared_users_users" "album_sharedUsers"
        ON "album_sharedUsers"."albumsId"="album"."id"
    LEFT JOIN "users" "sharedUsers"
        ON "sharedUsers"."id"="album_sharedUsers"."usersId"
        AND "sharedUsers"."deletedAt" IS NULL
WHERE
    (
        "album"."ownerId" = $11
        OR "sharedUsers"."id" = $12
    )
    AND (
        "asset"."id" IN (SELECT id FROM "assetIds")
        OR "asset"."livePhotoVideoId" IN (SELECT id FROM "assetIds")
    )
    AND "album"."deletedAt" IS NULL
```

* asset.checkSharedLinkAccess

```sql
-- Before
SELECT
    "assets"."id" AS "assetId",
    "assets"."livePhotoVideoId" AS "assetLivePhotoVideoId",
    "albumAssets"."id" AS "albumAssetId",
    "albumAssets"."livePhotoVideoId" AS "albumAssetLivePhotoVideoId"
FROM "shared_links" "sharedLink"
    LEFT JOIN "albums" "album"
        ON "album"."id"="sharedLink"."albumId"
        AND "album"."deletedAt" IS NULL
    LEFT JOIN "shared_link__asset" "assets_sharedLink"
        ON "assets_sharedLink"."sharedLinksId"="sharedLink"."id"
    LEFT JOIN "assets" "assets"
        ON "assets"."id"="assets_sharedLink"."assetsId"
        AND "assets"."deletedAt" IS NULL
    LEFT JOIN "albums_assets_assets" "album_albumAssets"
        ON "album_albumAssets"."albumsId"="album"."id"
    LEFT JOIN "assets" "albumAssets"
        ON "albumAssets"."id"="album_albumAssets"."assetsId"
        AND "albumAssets"."deletedAt" IS NULL
WHERE
    "sharedLink"."id" = $1
    AND (
        "assets"."id" IN ($2, $3, $4, $5, $6, $7, $8, $9, $10, $11)
        OR "albumAssets"."id" IN ($12, $13, $14, $15, $16, $17, $18, $19, $20, $21)
        OR "assets"."livePhotoVideoId" IN ($22, $23, $24, $25, $26, $27, $28, $29, $30, $31)
        OR "albumAssets"."livePhotoVideoId" IN ($32, $33, $34, $35, $36, $37, $38, $39, $40, $41)
    )

-- After
WITH "assetIds" AS (
    SELECT unnest(array[$1, $2, $3, $4, $5, $6, $7, $8, $9, $10])::uuid AS "id"
    FROM (SELECT 1 AS dummy_column) "dummy_table"
)
SELECT
    "assets"."id" AS "assetId",
    "assets"."livePhotoVideoId" AS "assetLivePhotoVideoId",
    "albumAssets"."id" AS "albumAssetId",
    "albumAssets"."livePhotoVideoId" AS "albumAssetLivePhotoVideoId"
FROM "shared_links" "sharedLink"
    LEFT JOIN "albums" "album"
        ON "album"."id"="sharedLink"."albumId"
        AND "album"."deletedAt" IS NULL
    LEFT JOIN "shared_link__asset" "assets_sharedLink"
        ON "assets_sharedLink"."sharedLinksId"="sharedLink"."id"
    LEFT JOIN "assets" "assets"
        ON "assets"."id"="assets_sharedLink"."assetsId"
        AND "assets"."deletedAt" IS NULL
    LEFT JOIN "albums_assets_assets" "album_albumAssets"
        ON "album_albumAssets"."albumsId"="album"."id"
    LEFT JOIN "assets" "albumAssets"
        ON "albumAssets"."id"="album_albumAssets"."assetsId"
        AND "albumAssets"."deletedAt" IS NULL
    WHERE
        "sharedLink"."id" = $11
        AND (
            "assets"."id" IN (SELECT id FROM "assetIds")
            OR "albumAssets"."id" IN (SELECT id FROM "assetIds")
            OR "assets"."livePhotoVideoId" IN (SELECT id FROM "assetIds")
            OR "albumAssets"."livePhotoVideoId" IN (SELECT id FROM "assetIds")
        )
```

* fix: Use array overlapping instead of CTEs
2023-12-27 23:50:54 -06:00
..
2023-12-19 03:34:19 +00:00
2023-12-19 03:34:19 +00:00
2023-08-16 22:50:01 -05:00
2023-08-16 22:50:01 -05:00
2023-11-30 14:59:47 -06:00