From 912b28563bb98ed02b4a8b128adab9ea6a6c07ae Mon Sep 17 00:00:00 2001 From: InfiniteStash <117855276+InfiniteStash@users.noreply.github.com> Date: Thu, 15 Feb 2024 10:20:38 +0000 Subject: [PATCH 1/4] Normalize fingerprint table --- .../postgres/31_fingerprints.up.sql | 58 +++++++ pkg/models/model_scene.go | 29 +++- pkg/sqlx/querybuilder_scene.go | 154 +++++++++++++----- 3 files changed, 200 insertions(+), 41 deletions(-) create mode 100644 pkg/database/migrations/postgres/31_fingerprints.up.sql diff --git a/pkg/database/migrations/postgres/31_fingerprints.up.sql b/pkg/database/migrations/postgres/31_fingerprints.up.sql new file mode 100644 index 000000000..32d65f1ed --- /dev/null +++ b/pkg/database/migrations/postgres/31_fingerprints.up.sql @@ -0,0 +1,58 @@ +CREATE TABLE "fingerprints" ( + "id" SERIAL PRIMARY KEY, + "hash" VARCHAR(255) NOT NULL, + "algorithm" VARCHAR(20) NOT NULL, + UNIQUE ("hash", "algorithm") +); + +INSERT INTO "fingerprints" (hash, algorithm) +SELECT hash, algorithm +FROM "scene_fingerprints" +GROUP BY hash, algorithm; + +ALTER TABLE "scene_fingerprints" RENAME TO "_scene_fingerprints"; + +CREATE TABLE "scene_fingerprints" ( + "fingerprint_id" INT NOT NULL, + "scene_id" UUID NOT NULL, + "user_id" UUID NOT NULL, + "duration" INT NOT NULL, + "created_at" TIMESTAMP NOT NULL DEFAULT now(), + FOREIGN KEY("fingerprint_id") REFERENCES "fingerprints"("id") ON DELETE CASCADE, + FOREIGN KEY("scene_id") REFERENCES "scenes"("id") ON DELETE CASCADE, + FOREIGN KEY("user_id") REFERENCES "users"("id") ON DELETE CASCADE, + UNIQUE ("scene_id", "fingerprint_id", "user_id") +); + +INSERT INTO "scene_fingerprints" +SELECT F.id, scene_id, user_id, duration, created_at +FROM "_scene_fingerprints" SF +JOIN "fingerprints" F ON SF.hash = F.hash AND SF.algorithm = F.algorithm; + +DROP TABLE "_scene_fingerprints"; + +CREATE INDEX "scenes_deleted_idx" ON "scenes" (id, deleted); +CREATE INDEX "scene_fingerprints_fingerprint_idx" ON "scene_fingerprints" (fingerprint_id); +CREATE INDEX "scene_fingerprints_user_idx" on "scene_fingerprints" (user_id); +CREATE INDEX "scene_fingerprints_created_at" on "scene_fingerprints" (created_at); + + +-- Create phash index if bktree is available +DO $$ +DECLARE + extension pg_extension%rowtype; +BEGIN + + SELECT * + INTO extension + FROM pg_extension + WHERE extname='bktree'; + + IF found THEN + CREATE INDEX fingerprints_phash_idx + ON fingerprints + USING spgist ((('x' || hash)::bit(64)::bigint) bktree_ops) + WHERE algorithm = 'PHASH'; + END IF; + +END$$; diff --git a/pkg/models/model_scene.go b/pkg/models/model_scene.go index 2c59cce1d..1467172ca 100644 --- a/pkg/models/model_scene.go +++ b/pkg/models/model_scene.go @@ -105,9 +105,6 @@ type SceneFingerprint struct { Algorithm string `db:"algorithm" json:"algorithm"` Duration int `db:"duration" json:"duration"` CreatedAt time.Time `db:"created_at" json:"created_at"` - // unused fields - Submissions int `db:"submissions" json:"submissions"` - UpdatedAt time.Time `db:"updated_at" json:"updated_at"` } type SceneFingerprints []*SceneFingerprint @@ -128,6 +125,32 @@ func (f *SceneFingerprints) Add(o interface{}) { *f = append(*f, o.(*SceneFingerprint)) } +type DBSceneFingerprint struct { + SceneID uuid.UUID `db:"scene_id" json:"scene_id"` + UserID uuid.UUID `db:"user_id" json:"user_id"` + FingerprintID int `db:"fingerprint_id" json:"fingerprint_id"` + Duration int `db:"duration" json:"duration"` + CreatedAt time.Time `db:"created_at" json:"created_at"` +} + +type DBSceneFingerprints []*DBSceneFingerprint + +func (f DBSceneFingerprints) Each(fn func(interface{})) { + for _, v := range f { + fn(*v) + } +} + +func (f DBSceneFingerprints) EachPtr(fn func(interface{})) { + for _, v := range f { + fn(v) + } +} + +func (f *DBSceneFingerprints) Add(o interface{}) { + *f = append(*f, o.(*DBSceneFingerprint)) +} + func CreateSceneFingerprints(sceneID uuid.UUID, fingerprints []*FingerprintEditInput) SceneFingerprints { var ret SceneFingerprints diff --git a/pkg/sqlx/querybuilder_scene.go b/pkg/sqlx/querybuilder_scene.go index dff89954c..8248320a6 100644 --- a/pkg/sqlx/querybuilder_scene.go +++ b/pkg/sqlx/querybuilder_scene.go @@ -1,6 +1,7 @@ package sqlx import ( + "database/sql" "fmt" "strconv" "strings" @@ -8,6 +9,7 @@ import ( "github.com/gofrs/uuid" "github.com/jmoiron/sqlx" + "github.com/pkg/errors" "github.com/stashapp/stash-box/pkg/edit" "github.com/stashapp/stash-box/pkg/manager/config" "github.com/stashapp/stash-box/pkg/models" @@ -25,7 +27,7 @@ var ( }) sceneFingerprintTable = newTableJoin(sceneTable, "scene_fingerprints", sceneJoinKey, func() interface{} { - return &models.SceneFingerprint{} + return &models.DBSceneFingerprint{} }) sceneURLTable = newTableJoin(sceneTable, "scene_urls", sceneJoinKey, func() interface{} { @@ -77,23 +79,43 @@ func (qb *sceneQueryBuilder) UpdateURLs(scene uuid.UUID, updatedJoins models.Sce return qb.dbi.ReplaceJoins(sceneURLTable, scene, &updatedJoins) } -func (qb *sceneQueryBuilder) CreateFingerprints(newJoins models.SceneFingerprints) error { - conflictHandling := ` - ON CONFLICT ON CONSTRAINT scene_hash_unique - DO NOTHING - ` +func (qb *sceneQueryBuilder) CreateFingerprints(sceneFingerprints models.SceneFingerprints) error { + conflictHandling := `ON CONFLICT DO NOTHING` + + var fingerprints models.DBSceneFingerprints + for _, fp := range sceneFingerprints { + id, err := qb.getOrCreateFingerprintID(fp.Hash, fp.Algorithm) + if err != nil { + return err + } - return qb.dbi.InsertJoinsWithConflictHandling(sceneFingerprintTable, &newJoins, conflictHandling) + fingerprints = append(fingerprints, &models.DBSceneFingerprint{ + FingerprintID: id, + SceneID: fp.SceneID, + UserID: fp.UserID, + Duration: fp.Duration, + }) + } + + return qb.dbi.InsertJoinsWithConflictHandling(sceneFingerprintTable, &fingerprints, conflictHandling) } func (qb *sceneQueryBuilder) UpdateFingerprints(sceneID uuid.UUID, updatedJoins models.SceneFingerprints) error { - return qb.dbi.ReplaceJoins(sceneFingerprintTable, sceneID, &updatedJoins) + err := qb.DestroyFingerprints(sceneID, updatedJoins) + if err != nil { + return err + } + + return qb.CreateFingerprints(updatedJoins) } func (qb *sceneQueryBuilder) DestroyFingerprints(sceneID uuid.UUID, toDestroy models.SceneFingerprints) error { for _, fp := range toDestroy { - query := qb.dbi.db().Rebind(`DELETE FROM ` + sceneFingerprintTable.name + ` WHERE algorithm = ? AND HASH = ? AND user_id = ? AND scene_id = ?`) - res, err := qb.dbi.db().Exec(query, fp.Algorithm, fp.Hash, fp.UserID, fp.SceneID) + res, err := qb.dbi.db().Exec(` + DELETE FROM `+sceneFingerprintTable.name+` + USING fingerprints FP + WHERE FP.hash = $1 AND FP.algorithm = $2 AND FP.id = fingerprint_id AND user_id = $3 AND scene_id = $4 + `, fp.Hash, fp.Algorithm, fp.UserID, fp.SceneID) if err != nil { return err } @@ -113,8 +135,9 @@ func (qb *sceneQueryBuilder) Find(id uuid.UUID) (*models.Scene, error) { func (qb *sceneQueryBuilder) FindByFingerprint(algorithm models.FingerprintAlgorithm, hash string) ([]*models.Scene, error) { query := ` SELECT scenes.* FROM scenes - LEFT JOIN scene_fingerprints as scenes_join on scenes_join.scene_id = scenes.id - WHERE scenes_join.algorithm = ? AND scenes_join.hash = ?` + JOIN scene_fingerprints as SFP on SFP.scene_id = scenes.id + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id + WHERE FP.algorithm = ? AND FP.hash = ?` var args []interface{} args = append(args, algorithm.String()) args = append(args, hash) @@ -125,8 +148,10 @@ func (qb *sceneQueryBuilder) FindByFingerprints(fingerprints []string) ([]*model query := ` SELECT scenes.* FROM scenes WHERE id IN ( - SELECT scene_id id FROM scene_fingerprints - WHERE hash IN (?) + SELECT scene_id AS id + FROM scene_fingerprints SFP + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id + WHERE FP.hash IN (?) GROUP BY id )` query, args, err := sqlx.In(query, fingerprints) @@ -138,15 +163,18 @@ func (qb *sceneQueryBuilder) FindByFingerprints(fingerprints []string) ([]*model func (qb *sceneQueryBuilder) FindByFullFingerprints(fingerprints []*models.FingerprintQueryInput) ([]*models.Scene, error) { hashClause := ` - SELECT scene_id id FROM scene_fingerprints - WHERE hash IN (:hashes) + SELECT SFP.scene_id AS id + FROM scene_fingerprints SFP + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id + WHERE FP.hash IN (:hashes) GROUP BY id ` phashClause := ` - SELECT scene_id as id + SELECT SFP.scene_id AS id FROM UNNEST(ARRAY[:phashes]) phash - JOIN scene_fingerprints ON ('x' || hash)::::bit(64)::::bigint <@ (phash::::BIGINT, :distance) + JOIN fingerprints FP ON ('x' || hash)::::bit(64)::::bigint <@ (phash::::BIGINT, :distance) AND algorithm = 'PHASH' + JOIN scene_fingerprints SFP ON SFP.fingerprint_id = FP.id ` var phashes []int64 @@ -221,7 +249,8 @@ func (qb *sceneQueryBuilder) FindByIds(ids []uuid.UUID) ([]*models.Scene, error) func (qb *sceneQueryBuilder) FindIdsBySceneFingerprints(fingerprints []*models.FingerprintQueryInput) (map[string][]uuid.UUID, error) { hashClause := ` SELECT scene_id, hash - FROM scene_fingerprints + FROM fingerprints FP + JOIN scene_fingerprints SFP ON FP.id = SFP.fingerprint_id JOIN scenes ON scene_id = scenes.id WHERE hash IN (:hashes) AND deleted = FALSE GROUP BY scene_id, hash @@ -229,8 +258,9 @@ func (qb *sceneQueryBuilder) FindIdsBySceneFingerprints(fingerprints []*models.F phashClause := ` SELECT scene_id, to_hex(phash::::bigint) as hash FROM UNNEST(ARRAY[:phashes]) phash - JOIN scene_fingerprints ON ('x' || hash)::::bit(64)::::bigint <@ (phash::::BIGINT, :distance) + JOIN fingerprints FP ON ('x' || hash)::::bit(64)::::bigint <@ (phash::::BIGINT, :distance) AND algorithm = 'PHASH' + JOIN scene_fingerprints SFP ON FP.id = SFP.fingerprint_id JOIN scenes ON scene_id = scenes.id WHERE deleted = FALSE GROUP BY scene_id, phash @@ -278,11 +308,16 @@ func (qb *sceneQueryBuilder) FindIdsBySceneFingerprints(fingerprints []*models.F return nil, err } + query = qb.dbi.db().Rebind(query) + fmt.Println(args) + output := models.SceneFingerprints{} - if err := qb.dbi.RawQuery(sceneFingerprintTable.table, query, args, &output); err != nil { + if err := qb.dbi.db().Select(&output, query, args...); err != nil { return nil, err } + fmt.Println(1) + res := make(map[string][]uuid.UUID) output.Each(func(row interface{}) { fp := row.(models.SceneFingerprint) @@ -368,8 +403,19 @@ func (qb *sceneQueryBuilder) buildQuery(filter models.SceneQueryInput, userID uu } if q := filter.Fingerprints; q != nil && len(q.Value) > 0 { - if err := setMultiCriterionClause(query, sceneFingerprintTable, "hash", q, true); err != nil { - return nil, err + inClause := getInBinding(len(q.Value)) + query.Body += ` + JOIN ( + SELECT scene_id + FROM scene_fingerprints SFP + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id + WHERE FP.hash IN ` + inClause + ` + GROUP BY scene_id + ) T ON scenes.id = T.scene_id + ` + + for _, hash := range q.Value { + query.AddArg(hash) } } @@ -569,33 +615,41 @@ func fingerprintGroupToFingerprint(fpg sceneFingerprintGroup) *models.Fingerprin func (qb *sceneQueryBuilder) GetFingerprints(id uuid.UUID) (models.SceneFingerprints, error) { joins := models.SceneFingerprints{} - err := qb.dbi.FindJoins(sceneFingerprintTable, id, &joins) + err := qb.dbi.db().Select(joins, ` + SELECT SFP.*, FP.hash, FP.algorithm + FROM scene_fingerprints SFP + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id + WHERE SFP.scene_id = $1 + `, id) return joins, err } func (qb *sceneQueryBuilder) GetAllFingerprints(currentUserID uuid.UUID, ids []uuid.UUID, onlySubmitted bool) ([][]*models.Fingerprint, []error) { query := ` SELECT - f.scene_id, - f.hash, - f.algorithm, - mode() WITHIN GROUP (ORDER BY f.duration) as duration, - COUNT(f.hash) as submissions, + SFP.scene_id, + FP.hash, + FP.algorithm, + mode() WITHIN GROUP (ORDER BY SFP.duration) as duration, + COUNT(SFP.fingerprint_id) as submissions, MIN(created_at) as created_at, MAX(created_at) as updated_at, - bool_or(f.user_id = :userid) as user_submitted - FROM scene_fingerprints f - WHERE f.scene_id IN (:sceneids) + bool_or(SFP.user_id = :userid) as user_submitted + FROM scene_fingerprints SFP + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id + WHERE SFP.scene_id IN (:sceneids) ` if onlySubmitted { - query += "AND f.user_id = :userid" + query += "AND SFP.user_id = :userid" } query += ` - GROUP BY f.scene_id, f.algorithm, f.hash + GROUP BY SFP.scene_id, FP.algorithm, FP.hash ORDER BY submissions DESC` + fmt.Println(query) + arg := map[string]interface{}{ "userid": currentUserID, "sceneids": ids, @@ -968,17 +1022,40 @@ func (qb *sceneQueryBuilder) addFingerprintsFromEdit(scene *models.Scene, data * for _, fingerprint := range data.New.AddedFingerprints { if fingerprint.Duration > 0 { newFingerprints = append(newFingerprints, &models.SceneFingerprint{ - SceneID: scene.ID, - UserID: userID, Hash: fingerprint.Hash, Algorithm: fingerprint.Algorithm.String(), + SceneID: scene.ID, + UserID: userID, Duration: fingerprint.Duration, CreatedAt: time.Now(), }) } } - return qb.UpdateFingerprints(scene.ID, newFingerprints) + return qb.CreateFingerprints(newFingerprints) +} + +func (qb *sceneQueryBuilder) getOrCreateFingerprintID(hash string, algorithm string) (int, error) { + id, err := qb.getFingerprintID(hash, algorithm) + if errors.Is(err, sql.ErrNoRows) { + id, err = qb.createFingerprint(hash, algorithm) + } + + return id, err +} + +func (qb *sceneQueryBuilder) getFingerprintID(hash string, algorithm string) (int, error) { + var id int + err := qb.dbi.db().Get(&id, "SELECT id FROM fingerprints WHERE hash = $1 AND algorithm = $2", hash, algorithm) + + return id, err +} + +func (qb *sceneQueryBuilder) createFingerprint(hash string, algorithm string) (int, error) { + var id int + err := qb.dbi.db().Get(&id, "INSERT INTO fingerprints (hash, algorithm) VALUES ($1, $2) RETURNING id", hash, algorithm) + + return id, err } func (qb *sceneQueryBuilder) MergeInto(source *models.Scene, target *models.Scene) error { @@ -1025,7 +1102,8 @@ func (qb *sceneQueryBuilder) FindExistingScenes(input models.QueryExistingSceneI clauses = append(clauses, ` id IN ( SELECT scene_id - FROM scene_fingerprints + FROM scene_fingerprints SFP + JOIN fingerprints FP ON SFP.fingerprint_id = FP.id WHERE hash IN (:hashes) GROUP BY scene_id ) From da16ee5c5464f2bbdff3935ccb8ff257c1b49a95 Mon Sep 17 00:00:00 2001 From: InfiniteStash <117855276+InfiniteStash@users.noreply.github.com> Date: Thu, 15 Feb 2024 18:41:29 +0000 Subject: [PATCH 2/4] Fix tests --- pkg/database/database.go | 2 +- pkg/sqlx/querybuilder_scene.go | 29 ++++++++++++++--------------- 2 files changed, 15 insertions(+), 16 deletions(-) diff --git a/pkg/database/database.go b/pkg/database/database.go index 52f6a8d72..edb8c99ec 100644 --- a/pkg/database/database.go +++ b/pkg/database/database.go @@ -4,7 +4,7 @@ import ( "github.com/jmoiron/sqlx" ) -var appSchemaVersion uint = 30 +var appSchemaVersion uint = 31 var databaseProviders map[string]databaseProvider diff --git a/pkg/sqlx/querybuilder_scene.go b/pkg/sqlx/querybuilder_scene.go index 8248320a6..78effcbac 100644 --- a/pkg/sqlx/querybuilder_scene.go +++ b/pkg/sqlx/querybuilder_scene.go @@ -101,8 +101,7 @@ func (qb *sceneQueryBuilder) CreateFingerprints(sceneFingerprints models.SceneFi } func (qb *sceneQueryBuilder) UpdateFingerprints(sceneID uuid.UUID, updatedJoins models.SceneFingerprints) error { - err := qb.DestroyFingerprints(sceneID, updatedJoins) - if err != nil { + if err := qb.dbi.DeleteJoins(sceneFingerprintTable, sceneID); err != nil { return err } @@ -111,10 +110,15 @@ func (qb *sceneQueryBuilder) UpdateFingerprints(sceneID uuid.UUID, updatedJoins func (qb *sceneQueryBuilder) DestroyFingerprints(sceneID uuid.UUID, toDestroy models.SceneFingerprints) error { for _, fp := range toDestroy { + fmt.Println(fp) res, err := qb.dbi.db().Exec(` - DELETE FROM `+sceneFingerprintTable.name+` + DELETE FROM scene_fingerprints SFP USING fingerprints FP - WHERE FP.hash = $1 AND FP.algorithm = $2 AND FP.id = fingerprint_id AND user_id = $3 AND scene_id = $4 + WHERE SFP.fingerprint_id = FP.id + AND FP.hash = $1 + AND FP.algorithm = $2 + AND user_id = $3 + AND scene_id = $4 `, fp.Hash, fp.Algorithm, fp.UserID, fp.SceneID) if err != nil { return err @@ -152,7 +156,7 @@ func (qb *sceneQueryBuilder) FindByFingerprints(fingerprints []string) ([]*model FROM scene_fingerprints SFP JOIN fingerprints FP ON SFP.fingerprint_id = FP.id WHERE FP.hash IN (?) - GROUP BY id + GROUP BY scene_id )` query, args, err := sqlx.In(query, fingerprints) if err != nil { @@ -167,7 +171,7 @@ func (qb *sceneQueryBuilder) FindByFullFingerprints(fingerprints []*models.Finge FROM scene_fingerprints SFP JOIN fingerprints FP ON SFP.fingerprint_id = FP.id WHERE FP.hash IN (:hashes) - GROUP BY id + GROUP BY SFP.scene_id ` phashClause := ` SELECT SFP.scene_id AS id @@ -309,15 +313,12 @@ func (qb *sceneQueryBuilder) FindIdsBySceneFingerprints(fingerprints []*models.F } query = qb.dbi.db().Rebind(query) - fmt.Println(args) output := models.SceneFingerprints{} if err := qb.dbi.db().Select(&output, query, args...); err != nil { return nil, err } - fmt.Println(1) - res := make(map[string][]uuid.UUID) output.Each(func(row interface{}) { fp := row.(models.SceneFingerprint) @@ -614,14 +615,14 @@ func fingerprintGroupToFingerprint(fpg sceneFingerprintGroup) *models.Fingerprin } func (qb *sceneQueryBuilder) GetFingerprints(id uuid.UUID) (models.SceneFingerprints, error) { - joins := models.SceneFingerprints{} - err := qb.dbi.db().Select(joins, ` - SELECT SFP.*, FP.hash, FP.algorithm + fingerprints := models.SceneFingerprints{} + err := qb.dbi.db().Select(&fingerprints, ` + SELECT SFP.scene_id, SFP.user_id, SFP.duration, SFP.created_at, FP.hash, FP.algorithm FROM scene_fingerprints SFP JOIN fingerprints FP ON SFP.fingerprint_id = FP.id WHERE SFP.scene_id = $1 `, id) - return joins, err + return fingerprints, err } func (qb *sceneQueryBuilder) GetAllFingerprints(currentUserID uuid.UUID, ids []uuid.UUID, onlySubmitted bool) ([][]*models.Fingerprint, []error) { @@ -648,8 +649,6 @@ func (qb *sceneQueryBuilder) GetAllFingerprints(currentUserID uuid.UUID, ids []u GROUP BY SFP.scene_id, FP.algorithm, FP.hash ORDER BY submissions DESC` - fmt.Println(query) - arg := map[string]interface{}{ "userid": currentUserID, "sceneids": ids, From 225d08f939e7fd8a3ab91a8e3f88ee78751e15f8 Mon Sep 17 00:00:00 2001 From: InfiniteStash <117855276+InfiniteStash@users.noreply.github.com> Date: Fri, 16 Feb 2024 09:09:55 +0000 Subject: [PATCH 3/4] Update migration number --- pkg/database/database.go | 2 +- .../postgres/{31_fingerprints.up.sql => 32_fingerprints.up.sql} | 1 - 2 files changed, 1 insertion(+), 2 deletions(-) rename pkg/database/migrations/postgres/{31_fingerprints.up.sql => 32_fingerprints.up.sql} (96%) diff --git a/pkg/database/database.go b/pkg/database/database.go index edb8c99ec..eacf25a3d 100644 --- a/pkg/database/database.go +++ b/pkg/database/database.go @@ -4,7 +4,7 @@ import ( "github.com/jmoiron/sqlx" ) -var appSchemaVersion uint = 31 +var appSchemaVersion uint = 32 var databaseProviders map[string]databaseProvider diff --git a/pkg/database/migrations/postgres/31_fingerprints.up.sql b/pkg/database/migrations/postgres/32_fingerprints.up.sql similarity index 96% rename from pkg/database/migrations/postgres/31_fingerprints.up.sql rename to pkg/database/migrations/postgres/32_fingerprints.up.sql index 32d65f1ed..4512fe3b7 100644 --- a/pkg/database/migrations/postgres/31_fingerprints.up.sql +++ b/pkg/database/migrations/postgres/32_fingerprints.up.sql @@ -31,7 +31,6 @@ JOIN "fingerprints" F ON SF.hash = F.hash AND SF.algorithm = F.algorithm; DROP TABLE "_scene_fingerprints"; -CREATE INDEX "scenes_deleted_idx" ON "scenes" (id, deleted); CREATE INDEX "scene_fingerprints_fingerprint_idx" ON "scene_fingerprints" (fingerprint_id); CREATE INDEX "scene_fingerprints_user_idx" on "scene_fingerprints" (user_id); CREATE INDEX "scene_fingerprints_created_at" on "scene_fingerprints" (created_at); From f1383b439d72e01933ca75640cda63d89d507dd4 Mon Sep 17 00:00:00 2001 From: InfiniteStash <117855276+InfiniteStash@users.noreply.github.com> Date: Fri, 16 Feb 2024 12:33:30 +0000 Subject: [PATCH 4/4] Improve trending index --- pkg/database/migrations/postgres/32_fingerprints.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/pkg/database/migrations/postgres/32_fingerprints.up.sql b/pkg/database/migrations/postgres/32_fingerprints.up.sql index 4512fe3b7..059a35587 100644 --- a/pkg/database/migrations/postgres/32_fingerprints.up.sql +++ b/pkg/database/migrations/postgres/32_fingerprints.up.sql @@ -33,7 +33,7 @@ DROP TABLE "_scene_fingerprints"; CREATE INDEX "scene_fingerprints_fingerprint_idx" ON "scene_fingerprints" (fingerprint_id); CREATE INDEX "scene_fingerprints_user_idx" on "scene_fingerprints" (user_id); -CREATE INDEX "scene_fingerprints_created_at" on "scene_fingerprints" (created_at); +CREATE INDEX "scene_fingerprints_created_at" on "scene_fingerprints" (created_at, scene_id); -- Create phash index if bktree is available