mirror of
https://github.com/ajayyy/SponsorBlockServer.git
synced 2025-12-07 03:57:06 +03:00
Fix distinct query on postgres
This commit is contained in:
@@ -124,9 +124,9 @@ CREATE INDEX IF NOT EXISTS "titles_timeSubmitted"
|
||||
("timeSubmitted" ASC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "titles_votes_timeSubmitted"
|
||||
CREATE INDEX IF NOT EXISTS "titles_userID_timeSubmitted"
|
||||
ON public."titles" USING btree
|
||||
("videoID" COLLATE pg_catalog."default" ASC NULLS LAST, "service" COLLATE pg_catalog."default" ASC NULLS LAST, "votes" DESC NULLS LAST, "timeSubmitted" DESC NULLS LAST)
|
||||
("videoID" COLLATE pg_catalog."default" ASC NULLS LAST, "service" COLLATE pg_catalog."default" ASC NULLS LAST, "userID" COLLATE pg_catalog."default" DESC NULLS LAST, "timeSubmitted" DESC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "titles_videoID"
|
||||
@@ -139,6 +139,13 @@ CREATE INDEX IF NOT EXISTS "titles_hashedVideoID"
|
||||
("hashedVideoID" COLLATE pg_catalog."default" ASC NULLS LAST, "service" COLLATE pg_catalog."default" ASC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
-- titleVotes
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "titleVotes_votes"
|
||||
ON public."titleVotes" USING btree
|
||||
("UUID" COLLATE pg_catalog."default" ASC NULLS LAST, "votes" DESC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
-- thumbnails
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "thumbnails_timeSubmitted"
|
||||
@@ -148,7 +155,7 @@ CREATE INDEX IF NOT EXISTS "thumbnails_timeSubmitted"
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "thumbnails_votes_timeSubmitted"
|
||||
ON public."thumbnails" USING btree
|
||||
("videoID" COLLATE pg_catalog."default" ASC NULLS LAST, "service" COLLATE pg_catalog."default" ASC NULLS LAST, "votes" DESC NULLS LAST, "timeSubmitted" DESC NULLS LAST)
|
||||
("videoID" COLLATE pg_catalog."default" ASC NULLS LAST, "service" COLLATE pg_catalog."default" ASC NULLS LAST, "userID" COLLATE pg_catalog."default" DESC NULLS LAST, "timeSubmitted" DESC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "thumbnails_videoID"
|
||||
@@ -159,4 +166,11 @@ CREATE INDEX IF NOT EXISTS "thumbnails_videoID"
|
||||
CREATE INDEX IF NOT EXISTS "thumbnails_hashedVideoID"
|
||||
ON public."thumbnails" USING btree
|
||||
("hashedVideoID" COLLATE pg_catalog."default" ASC NULLS LAST, "service" COLLATE pg_catalog."default" ASC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
-- thumbnailVotes
|
||||
|
||||
CREATE INDEX IF NOT EXISTS "thumbnailVotes_votes"
|
||||
ON public."thumbnailVotes" USING btree
|
||||
("UUID" COLLATE pg_catalog."default" ASC NULLS LAST, "votes" DESC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
@@ -72,6 +72,15 @@ export class Sqlite implements IDatabase {
|
||||
}
|
||||
|
||||
private static processQuery(query: string): string {
|
||||
if (query.includes("DISTINCT ON")) {
|
||||
const column = query.match(/DISTINCT ON \((.*)\) (.*)/)[1];
|
||||
query = query.replace(/DISTINCT ON \((.*)\)/g, "");
|
||||
|
||||
const parts = query.split("ORDER BY");
|
||||
|
||||
query = `${parts[0]} GROUP BY ${column} ORDER BY ${parts[1]}`;
|
||||
}
|
||||
|
||||
return query.replace(/ ~\* /g, " REGEXP ");
|
||||
}
|
||||
|
||||
|
||||
@@ -24,22 +24,20 @@ enum BrandingSubmissionType {
|
||||
export async function getVideoBranding(res: Response, videoID: VideoID, service: Service, ip: IPAddress, returnUserID: boolean): Promise<BrandingResult> {
|
||||
const getTitles = () => db.prepare(
|
||||
"all",
|
||||
`SELECT "titles"."title", "titles"."original", "titleVotes"."votes", "titleVotes"."locked", "titleVotes"."shadowHidden", "titles"."UUID", "titles"."videoID", "titles"."hashedVideoID", "titleVotes"."verification", "titles"."userID"
|
||||
`SELECT DISTINCT ON ("titles"."userID") "titles"."title", "titles"."original", "titleVotes"."votes", "titleVotes"."locked", "titleVotes"."shadowHidden", "titles"."UUID", "titles"."videoID", "titles"."hashedVideoID", "titleVotes"."verification", "titles"."userID"
|
||||
FROM "titles" JOIN "titleVotes" ON "titles"."UUID" = "titleVotes"."UUID"
|
||||
WHERE "titles"."videoID" = ? AND "titles"."service" = ? AND "titleVotes"."votes" > -2
|
||||
GROUP BY "titles"."userID"
|
||||
ORDER BY "titleVotes"."votes", "titles"."timeSubmitted" DESC`,
|
||||
ORDER BY "titles"."userID", "titleVotes"."votes", "titles"."timeSubmitted" DESC`,
|
||||
[videoID, service],
|
||||
{ useReplica: true }
|
||||
) as Promise<TitleDBResult[]>;
|
||||
|
||||
const getThumbnails = () => db.prepare(
|
||||
"all",
|
||||
`SELECT "thumbnailTimestamps"."timestamp", "thumbnails"."original", "thumbnailVotes"."votes", "thumbnailVotes"."locked", "thumbnailVotes"."shadowHidden", "thumbnails"."UUID", "thumbnails"."videoID", "thumbnails"."hashedVideoID", "thumbnails"."userID"
|
||||
`SELECT DISTINCT ON ("thumbnails"."userID") "thumbnailTimestamps"."timestamp", "thumbnails"."original", "thumbnailVotes"."votes", "thumbnailVotes"."locked", "thumbnailVotes"."shadowHidden", "thumbnails"."UUID", "thumbnails"."videoID", "thumbnails"."hashedVideoID", "thumbnails"."userID"
|
||||
FROM "thumbnails" LEFT JOIN "thumbnailVotes" ON "thumbnails"."UUID" = "thumbnailVotes"."UUID" LEFT JOIN "thumbnailTimestamps" ON "thumbnails"."UUID" = "thumbnailTimestamps"."UUID"
|
||||
WHERE "thumbnails"."videoID" = ? AND "thumbnails"."service" = ? AND "thumbnailVotes"."votes" > -2
|
||||
GROUP BY "thumbnails"."userID"
|
||||
ORDER BY "thumbnailVotes"."votes", "thumbnails"."timeSubmitted" DESC`,
|
||||
ORDER BY "thumbnails"."userID", "thumbnailVotes"."votes", "thumbnails"."timeSubmitted" DESC`,
|
||||
[videoID, service],
|
||||
{ useReplica: true }
|
||||
) as Promise<ThumbnailDBResult[]>;
|
||||
|
||||
Reference in New Issue
Block a user