Skip to content

Commit 49a6961

Browse files
authored
fix(server): query fixes (#15509)
1 parent 7b882b3 commit 49a6961

15 files changed

+275
-165
lines changed

server/src/entities/asset.entity.ts

Lines changed: 16 additions & 48 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
1-
import { DeduplicateJoinsPlugin, ExpressionBuilder, Kysely, Selectable, SelectQueryBuilder, sql } from 'kysely';
1+
import { DeduplicateJoinsPlugin, ExpressionBuilder, Kysely, SelectQueryBuilder, sql } from 'kysely';
22
import { jsonArrayFrom, jsonObjectFrom } from 'kysely/helpers/postgres';
3-
import { Assets, DB } from 'src/db';
3+
import { DB } from 'src/db';
44
import { AlbumEntity } from 'src/entities/album.entity';
55
import { AssetFaceEntity } from 'src/entities/asset-face.entity';
66
import { AssetFileEntity } from 'src/entities/asset-files.entity';
@@ -181,15 +181,13 @@ export class AssetEntity {
181181
}
182182

183183
export function withExif<O>(qb: SelectQueryBuilder<DB, 'assets', O>) {
184-
return qb
185-
.leftJoin('exif', 'assets.id', 'exif.assetId')
186-
.select((eb) => eb.fn('to_jsonb', [eb.table('exif')]).as('exifInfo'));
184+
return qb.leftJoin('exif', 'assets.id', 'exif.assetId').select((eb) => eb.fn.toJson(eb.table('exif')).as('exifInfo'));
187185
}
188186

189187
export function withExifInner<O>(qb: SelectQueryBuilder<DB, 'assets', O>) {
190188
return qb
191189
.innerJoin('exif', 'assets.id', 'exif.assetId')
192-
.select((eb) => eb.fn('to_jsonb', [eb.table('exif')]).as('exifInfo'));
190+
.select((eb) => eb.fn.toJson(eb.table('exif')).as('exifInfo'));
193191
}
194192

195193
export function withSmartSearch<O>(qb: SelectQueryBuilder<DB, 'assets', O>) {
@@ -268,48 +266,6 @@ export function withLibrary(eb: ExpressionBuilder<DB, 'assets'>) {
268266
);
269267
}
270268

271-
export function withStackedAssets<O>(qb: SelectQueryBuilder<DB, 'assets' | 'asset_stack', O>) {
272-
return qb
273-
.innerJoinLateral(
274-
(eb: ExpressionBuilder<DB, 'assets' | 'asset_stack'>) =>
275-
eb
276-
.selectFrom('assets as stacked')
277-
.select((eb) => eb.fn<Selectable<Assets>[]>('array_agg', [eb.table('stacked')]).as('assets'))
278-
.whereRef('asset_stack.id', '=', 'stacked.stackId')
279-
.whereRef('asset_stack.primaryAssetId', '!=', 'stacked.id')
280-
.as('s'),
281-
(join) =>
282-
join.on((eb) =>
283-
eb.or([eb('asset_stack.primaryAssetId', '=', eb.ref('assets.id')), eb('assets.stackId', 'is', null)]),
284-
),
285-
)
286-
.select('s.assets');
287-
}
288-
289-
export function withStack<O>(
290-
qb: SelectQueryBuilder<DB, 'assets', O>,
291-
{ assets, count }: { assets: boolean; count: boolean },
292-
) {
293-
return qb
294-
.leftJoinLateral(
295-
(eb) =>
296-
eb
297-
.selectFrom('asset_stack')
298-
.selectAll('asset_stack')
299-
.whereRef('assets.stackId', '=', 'asset_stack.id')
300-
.$if(assets, withStackedAssets)
301-
.$if(count, (qb) =>
302-
// There is no `selectNoFrom` method for expression builders
303-
qb.select(
304-
sql`(select count(*) as "assetCount" where "asset_stack"."id" = "assets"."stackId")`.as('assetCount'),
305-
),
306-
)
307-
.as('stacked_assets'),
308-
(join) => join.onTrue(),
309-
)
310-
.select((eb) => eb.fn('to_jsonb', [eb.table('stacked_assets')]).as('stack'));
311-
}
312-
313269
export function withAlbums<O>(qb: SelectQueryBuilder<DB, 'assets', O>, { albumId }: { albumId?: string }) {
314270
return qb
315271
.select((eb) =>
@@ -352,6 +308,18 @@ export function truncatedDate<O>(size: TimeBucketSize) {
352308
return sql<O>`date_trunc(${size}, "localDateTime" at time zone 'UTC') at time zone 'UTC'`;
353309
}
354310

311+
export function withTagId<O>(qb: SelectQueryBuilder<DB, 'assets', O>, tagId: string) {
312+
return qb.where((eb) =>
313+
eb.exists(
314+
eb
315+
.selectFrom('tags_closure')
316+
.innerJoin('tag_asset', 'tag_asset.tagsId', 'tags_closure.id_descendant')
317+
.whereRef('tag_asset.assetsId', '=', 'assets.id')
318+
.where('tags_closure.id_ancestor', '=', tagId),
319+
),
320+
);
321+
}
322+
355323
const joinDeduplicationPlugin = new DeduplicateJoinsPlugin();
356324

357325
/** TODO: This should only be used for search-related queries, not as a general purpose query builder */

server/src/interfaces/memory.interface.ts

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -7,7 +7,7 @@ export const IMemoryRepository = 'IMemoryRepository';
77

88
export interface IMemoryRepository extends IBulkAsset {
99
search(ownerId: string): Promise<MemoryEntity[]>;
10-
get(id: string): Promise<MemoryEntity | null>;
10+
get(id: string): Promise<MemoryEntity | undefined>;
1111
create(
1212
memory: Omit<Insertable<Memories>, 'data'> & { data: OnThisDayData },
1313
assetIds: Set<string>,

server/src/interfaces/person.interface.ts

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
import { Insertable, Updateable } from 'kysely';
1+
import { Insertable, Selectable, Updateable } from 'kysely';
22
import { AssetFaces, FaceSearch, Person } from 'src/db';
33
import { AssetFaceEntity } from 'src/entities/asset-face.entity';
44
import { PersonEntity } from 'src/entities/person.entity';
@@ -49,7 +49,7 @@ export interface DeleteFacesOptions {
4949

5050
export type UnassignFacesOptions = DeleteFacesOptions;
5151

52-
export type SelectFaceOptions = Partial<{ [K in keyof AssetFaceEntity]: boolean }>;
52+
export type SelectFaceOptions = (keyof Selectable<AssetFaces>)[];
5353

5454
export interface IPersonRepository {
5555
getAll(options?: Partial<PersonEntity>): AsyncIterableIterator<PersonEntity>;
@@ -74,10 +74,10 @@ export interface IPersonRepository {
7474
id: string,
7575
relations?: FindOptionsRelations<AssetFaceEntity>,
7676
select?: SelectFaceOptions,
77-
): Promise<AssetFaceEntity | null>;
77+
): Promise<AssetFaceEntity | undefined>;
7878
getFaces(assetId: string): Promise<AssetFaceEntity[]>;
7979
getFacesByIds(ids: AssetFaceId[]): Promise<AssetFaceEntity[]>;
80-
getRandomFace(personId: string): Promise<AssetFaceEntity | null>;
80+
getRandomFace(personId: string): Promise<AssetFaceEntity | undefined>;
8181
getStatistics(personId: string): Promise<PersonStatistics>;
8282
reassignFace(assetFaceId: string, newPersonId: string): Promise<number>;
8383
getNumberOfPeople(userId: string): Promise<PeopleStatistics>;

server/src/queries/album.repository.sql

Lines changed: 22 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -82,11 +82,31 @@ select
8282
where
8383
"shared_links"."albumId" = "albums"."id"
8484
) as agg
85-
) as "sharedLinks"
85+
) as "sharedLinks",
86+
(
87+
select
88+
json_agg("asset") as "assets"
89+
from
90+
(
91+
select
92+
"assets".*,
93+
to_json("exif") as "exifInfo"
94+
from
95+
"assets"
96+
inner join "exif" on "assets"."id" = "exif"."assetId"
97+
inner join "albums_assets_assets" on "albums_assets_assets"."assetsId" = "assets"."id"
98+
where
99+
"albums_assets_assets"."albumsId" = "albums"."id"
100+
and "assets"."deletedAt" is null
101+
and "assets"."isArchived" = $1
102+
order by
103+
"assets"."fileCreatedAt" desc
104+
) as "asset"
105+
) as "assets"
86106
from
87107
"albums"
88108
where
89-
"albums"."id" = $1
109+
"albums"."id" = $2
90110
and "albums"."deletedAt" is null
91111

92112
-- AlbumRepository.getByAssetId

server/src/queries/asset.repository.sql

Lines changed: 56 additions & 47 deletions
Original file line numberDiff line numberDiff line change
@@ -23,7 +23,7 @@ with
2323
)
2424
select
2525
"a".*,
26-
to_jsonb("exif") as "exifInfo"
26+
to_json("exif") as "exifInfo"
2727
from
2828
"today"
2929
inner join lateral (
@@ -56,7 +56,7 @@ select
5656
(
5757
(now() at time zone 'UTC')::date - ("localDateTime" at time zone 'UTC')::date
5858
) / 365 as "yearsAgo",
59-
jsonb_agg("res") as "assets"
59+
json_agg("res") as "assets"
6060
from
6161
"res"
6262
group by
@@ -109,34 +109,28 @@ select
109109
"assets"."id" = "tag_asset"."assetsId"
110110
) as agg
111111
) as "tags",
112-
to_jsonb("exif") as "exifInfo",
113-
to_jsonb("stacked_assets") as "stack"
112+
to_json("exif") as "exifInfo",
113+
to_json("stacked_assets") as "stack"
114114
from
115115
"assets"
116116
left join "exif" on "assets"."id" = "exif"."assetId"
117+
left join "asset_stack" on "asset_stack"."id" = "assets"."stackId"
117118
left join lateral (
118119
select
119120
"asset_stack".*,
120-
"s"."assets"
121+
array_agg("stacked") as "assets"
121122
from
122-
"asset_stack"
123-
inner join lateral (
124-
select
125-
array_agg("stacked") as "assets"
126-
from
127-
"assets" as "stacked"
128-
where
129-
"asset_stack"."id" = "stacked"."stackId"
130-
and "asset_stack"."primaryAssetId" != "stacked"."id"
131-
) as "s" on (
132-
"asset_stack"."primaryAssetId" = "assets"."id"
133-
or "assets"."stackId" is null
134-
)
123+
"assets" as "stacked"
135124
where
136-
"assets"."stackId" = "asset_stack"."id"
137-
) as "stacked_assets" on true
125+
"stacked"."stackId" = "asset_stack"."id"
126+
and "stacked"."id" != "asset_stack"."primaryAssetId"
127+
and "stacked"."deletedAt" is null
128+
and "stacked"."isArchived" = $1
129+
group by
130+
"asset_stack"."id"
131+
) as "stacked_assets" on "asset_stack"."id" is not null
138132
where
139-
"assets"."id" = any ($1::uuid [])
133+
"assets"."id" = any ($2::uuid [])
140134

141135
-- AssetRepository.deleteAll
142136
delete from "assets"
@@ -278,14 +272,33 @@ order by
278272
-- AssetRepository.getTimeBucket
279273
select
280274
"assets".*,
281-
to_jsonb("exif") as "exifInfo"
275+
to_json("exif") as "exifInfo",
276+
to_json("stacked_assets") as "stack"
282277
from
283278
"assets"
284279
left join "exif" on "assets"."id" = "exif"."assetId"
280+
left join "asset_stack" on "asset_stack"."id" = "assets"."stackId"
281+
left join lateral (
282+
select
283+
"asset_stack".*,
284+
count("stacked") as "assetCount"
285+
from
286+
"assets" as "stacked"
287+
where
288+
"stacked"."stackId" = "asset_stack"."id"
289+
and "stacked"."deletedAt" is null
290+
and "stacked"."isArchived" = $1
291+
group by
292+
"asset_stack"."id"
293+
) as "stacked_assets" on "asset_stack"."id" is not null
285294
where
286-
"assets"."deletedAt" is null
287-
and "assets"."isVisible" = $1
288-
and date_trunc($2, "localDateTime" at time zone 'UTC') at time zone 'UTC' = $3
295+
(
296+
"asset_stack"."primaryAssetId" = "assets"."id"
297+
or "assets"."stackId" is null
298+
)
299+
and "assets"."deletedAt" is null
300+
and "assets"."isVisible" = $2
301+
and date_trunc($3, "localDateTime" at time zone 'UTC') at time zone 'UTC' = $4
289302
order by
290303
"assets"."localDateTime" desc
291304

@@ -368,25 +381,23 @@ limit
368381
-- AssetRepository.getAllForUserFullSync
369382
select
370383
"assets".*,
371-
to_jsonb("exif") as "exifInfo",
372-
to_jsonb("stacked_assets") as "stack"
384+
to_json("exif") as "exifInfo",
385+
to_json("stacked_assets") as "stack"
373386
from
374387
"assets"
375388
left join "exif" on "assets"."id" = "exif"."assetId"
389+
left join "asset_stack" on "asset_stack"."id" = "assets"."stackId"
376390
left join lateral (
377391
select
378392
"asset_stack".*,
379-
(
380-
select
381-
count(*) as "assetCount"
382-
where
383-
"asset_stack"."id" = "assets"."stackId"
384-
) as "assetCount"
393+
count("stacked") as "assetCount"
385394
from
386-
"asset_stack"
395+
"assets" as "stacked"
387396
where
388-
"assets"."stackId" = "asset_stack"."id"
389-
) as "stacked_assets" on true
397+
"stacked"."stackId" = "asset_stack"."id"
398+
group by
399+
"asset_stack"."id"
400+
) as "stacked_assets" on "asset_stack"."id" is not null
390401
where
391402
"assets"."ownerId" = $1::uuid
392403
and "isVisible" = $2
@@ -400,25 +411,23 @@ limit
400411
-- AssetRepository.getChangedDeltaSync
401412
select
402413
"assets".*,
403-
to_jsonb("exif") as "exifInfo",
404-
to_jsonb("stacked_assets") as "stack"
414+
to_json("exif") as "exifInfo",
415+
to_json("stacked_assets") as "stack"
405416
from
406417
"assets"
407418
left join "exif" on "assets"."id" = "exif"."assetId"
419+
left join "asset_stack" on "asset_stack"."id" = "assets"."stackId"
408420
left join lateral (
409421
select
410422
"asset_stack".*,
411-
(
412-
select
413-
count(*) as "assetCount"
414-
where
415-
"asset_stack"."id" = "assets"."stackId"
416-
) as "assetCount"
423+
count("stacked") as "assetCount"
417424
from
418-
"asset_stack"
425+
"assets" as "stacked"
419426
where
420-
"assets"."stackId" = "asset_stack"."id"
421-
) as "stacked_assets" on true
427+
"stacked"."stackId" = "asset_stack"."id"
428+
group by
429+
"asset_stack"."id"
430+
) as "stacked_assets" on "asset_stack"."id" is not null
422431
where
423432
"assets"."ownerId" = any ($1::uuid [])
424433
and "isVisible" = $2

server/src/queries/library.repository.sql

Lines changed: 11 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -112,7 +112,7 @@ order by
112112

113113
-- LibraryRepository.getStatistics
114114
select
115-
count("assets"."id") filter (
115+
count(*) filter (
116116
where
117117
(
118118
"assets"."type" = $1
@@ -130,8 +130,17 @@ select
130130
from
131131
"libraries"
132132
inner join "assets" on "assets"."libraryId" = "libraries"."id"
133-
inner join "exif" on "exif"."assetId" = "assets"."id"
133+
left join "exif" on "exif"."assetId" = "assets"."id"
134134
where
135135
"libraries"."id" = $6
136136
group by
137137
"libraries"."id"
138+
select
139+
0::int as "photos",
140+
0::int as "videos",
141+
0::int as "usage",
142+
0::int as "total"
143+
from
144+
"libraries"
145+
where
146+
"libraries"."id" = $1

server/src/queries/view.repository.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -14,7 +14,7 @@ where
1414
-- ViewRepository.getAssetsByOriginalPath
1515
select
1616
"assets".*,
17-
to_jsonb("exif") as "exifInfo"
17+
to_json("exif") as "exifInfo"
1818
from
1919
"assets"
2020
left join "exif" on "assets"."id" = "exif"."assetId"

0 commit comments

Comments
 (0)