From 8ba76783b0bb95d2df83571de9d68fb5c7cda781 Mon Sep 17 00:00:00 2001 From: InfiniteTF Date: Mon, 11 May 2020 07:19:11 +0200 Subject: [PATCH] Query optimizations (#478) * Remove slow and largely pointless groupbys * Change scene.query to use querybuilder --- pkg/models/querybuilder_gallery.go | 2 +- pkg/models/querybuilder_movies.go | 3 +- pkg/models/querybuilder_performer.go | 8 +- pkg/models/querybuilder_performer_test.go | 25 ++++- pkg/models/querybuilder_scene.go | 128 ++++++++++----------- pkg/models/querybuilder_scene_marker.go | 3 +- pkg/models/querybuilder_scene_test.go | 129 +++++++++++++++++++++- pkg/models/querybuilder_sql.go | 12 +- pkg/models/querybuilder_tag.go | 3 +- 9 files changed, 228 insertions(+), 85 deletions(-) diff --git a/pkg/models/querybuilder_gallery.go b/pkg/models/querybuilder_gallery.go index b27af9b54..0f2b06e06 100644 --- a/pkg/models/querybuilder_gallery.go +++ b/pkg/models/querybuilder_gallery.go @@ -93,7 +93,7 @@ func (qb *GalleryQueryBuilder) FindByPath(path string) (*Gallery, error) { } func (qb *GalleryQueryBuilder) FindBySceneID(sceneID int, tx *sqlx.Tx) (*Gallery, error) { - query := "SELECT galleries.* FROM galleries JOIN scenes ON scenes.id = galleries.scene_id WHERE scenes.id = ? LIMIT 1" + query := "SELECT galleries.* FROM galleries WHERE galleries.scene_id = ? LIMIT 1" args := []interface{}{sceneID} return qb.queryGallery(query, args, tx) } diff --git a/pkg/models/querybuilder_movies.go b/pkg/models/querybuilder_movies.go index 125d75874..9c35017a1 100644 --- a/pkg/models/querybuilder_movies.go +++ b/pkg/models/querybuilder_movies.go @@ -76,8 +76,7 @@ func (qb *MovieQueryBuilder) FindBySceneID(sceneID int, tx *sqlx.Tx) ([]*Movie, query := ` SELECT movies.* FROM movies LEFT JOIN movies_scenes as scenes_join on scenes_join.movie_id = movies.id - LEFT JOIN scenes on scenes_join.scene_id = scenes.id - WHERE scenes.id = ? + WHERE scenes_join.scene_id = ? GROUP BY movies.id ` args := []interface{}{sceneID} diff --git a/pkg/models/querybuilder_performer.go b/pkg/models/querybuilder_performer.go index eea13a3d4..ffe3e5d3a 100644 --- a/pkg/models/querybuilder_performer.go +++ b/pkg/models/querybuilder_performer.go @@ -77,12 +77,9 @@ func (qb *PerformerQueryBuilder) Find(id int) (*Performer, error) { } func (qb *PerformerQueryBuilder) FindBySceneID(sceneID int, tx *sqlx.Tx) ([]*Performer, error) { - query := ` - SELECT performers.* FROM performers + query := selectAll("performers") + ` LEFT JOIN performers_scenes as scenes_join on scenes_join.performer_id = performers.id - LEFT JOIN scenes on scenes_join.scene_id = scenes.id - WHERE scenes.id = ? - GROUP BY performers.id + WHERE scenes_join.scene_id = ? ` args := []interface{}{sceneID} return qb.queryPerformers(query, args, tx) @@ -93,7 +90,6 @@ func (qb *PerformerQueryBuilder) FindNameBySceneID(sceneID int, tx *sqlx.Tx) ([] SELECT performers.name FROM performers LEFT JOIN performers_scenes as scenes_join on scenes_join.performer_id = performers.id WHERE scenes_join.scene_id = ? - GROUP BY performers.name ` args := []interface{}{sceneID} return qb.queryPerformers(query, args, tx) diff --git a/pkg/models/querybuilder_performer_test.go b/pkg/models/querybuilder_performer_test.go index 32f6111a7..a371e3c57 100644 --- a/pkg/models/querybuilder_performer_test.go +++ b/pkg/models/querybuilder_performer_test.go @@ -34,10 +34,33 @@ func TestPerformerFindBySceneID(t *testing.T) { assert.Equal(t, 0, len(performers)) } +func TestPerformerFindNameBySceneID(t *testing.T) { + pqb := models.NewPerformerQueryBuilder() + sceneID := sceneIDs[sceneIdxWithPerformer] + + performers, err := pqb.FindNameBySceneID(sceneID, nil) + + if err != nil { + t.Fatalf("Error finding performer: %s", err.Error()) + } + + assert.Equal(t, 1, len(performers)) + performer := performers[0] + + assert.Equal(t, getPerformerStringValue(performerIdxWithScene, "Name"), performer.Name.String) + + performers, err = pqb.FindBySceneID(0, nil) + + if err != nil { + t.Fatalf("Error finding performer: %s", err.Error()) + } + + assert.Equal(t, 0, len(performers)) +} + // TODO Update // TODO Destroy // TODO Find -// TODO FindNameBySceneID // TODO FindByNames // TODO Count // TODO All diff --git a/pkg/models/querybuilder_scene.go b/pkg/models/querybuilder_scene.go index c96fbdec4..2c2aa8a39 100644 --- a/pkg/models/querybuilder_scene.go +++ b/pkg/models/querybuilder_scene.go @@ -10,33 +10,34 @@ import ( "github.com/stashapp/stash/pkg/database" ) -const scenesForPerformerQuery = ` -SELECT scenes.* FROM scenes +const sceneTable = "scenes" + +var scenesForPerformerQuery = selectAll(sceneTable) + ` LEFT JOIN performers_scenes as performers_join on performers_join.scene_id = scenes.id -LEFT JOIN performers on performers_join.performer_id = performers.id -WHERE performers.id = ? +WHERE performers_join.performer_id = ? GROUP BY scenes.id ` -const scenesForStudioQuery = ` -SELECT scenes.* FROM scenes +var countScenesForPerformerQuery = ` +SELECT performer_id FROM performers_scenes as performers_join +WHERE performer_id = ? +GROUP BY scene_id +` + +var scenesForStudioQuery = selectAll(sceneTable) + ` JOIN studios ON studios.id = scenes.studio_id WHERE studios.id = ? GROUP BY scenes.id ` -const scenesForMovieQuery = ` -SELECT scenes.* FROM scenes +var scenesForMovieQuery = selectAll(sceneTable) + ` LEFT JOIN movies_scenes as movies_join on movies_join.scene_id = scenes.id -LEFT JOIN movies on movies_join.movie_id = movies.id -WHERE movies.id = ? +WHERE movies_join.movie_id = ? GROUP BY scenes.id ` -const scenesForTagQuery = ` -SELECT scenes.* FROM scenes +var scenesForTagQuery = selectAll(sceneTable) + ` LEFT JOIN scenes_tags as tags_join on tags_join.scene_id = scenes.id -LEFT JOIN tags on tags_join.tag_id = tags.id -WHERE tags.id = ? +WHERE tags_join.tag_id = ? GROUP BY scenes.id ` @@ -150,7 +151,7 @@ func (qb *SceneQueryBuilder) Find(id int) (*Scene, error) { } func (qb *SceneQueryBuilder) find(id int, tx *sqlx.Tx) (*Scene, error) { - query := "SELECT * FROM scenes WHERE id = ? LIMIT 1" + query := selectAll(sceneTable) + "WHERE id = ? LIMIT 1" args := []interface{}{id} return qb.queryScene(query, args, tx) } @@ -162,7 +163,7 @@ func (qb *SceneQueryBuilder) FindByChecksum(checksum string) (*Scene, error) { } func (qb *SceneQueryBuilder) FindByPath(path string) (*Scene, error) { - query := "SELECT * FROM scenes WHERE path = ? LIMIT 1" + query := selectAll(sceneTable) + "WHERE path = ? LIMIT 1" args := []interface{}{path} return qb.queryScene(query, args, nil) } @@ -174,7 +175,7 @@ func (qb *SceneQueryBuilder) FindByPerformerID(performerID int) ([]*Scene, error func (qb *SceneQueryBuilder) CountByPerformerID(performerID int) (int, error) { args := []interface{}{performerID} - return runCountQuery(buildCountQuery(scenesForPerformerQuery), args) + return runCountQuery(buildCountQuery(countScenesForPerformerQuery), args) } func (qb *SceneQueryBuilder) FindByStudioID(studioID int) ([]*Scene, error) { @@ -219,12 +220,12 @@ func (qb *SceneQueryBuilder) Wall(q *string) ([]*Scene, error) { if q != nil { s = *q } - query := "SELECT scenes.* FROM scenes WHERE scenes.details LIKE '%" + s + "%' ORDER BY RANDOM() LIMIT 80" + query := selectAll(sceneTable) + "WHERE scenes.details LIKE '%" + s + "%' ORDER BY RANDOM() LIMIT 80" return qb.queryScenes(query, nil, nil) } func (qb *SceneQueryBuilder) All() ([]*Scene, error) { - return qb.queryScenes(selectAll("scenes")+qb.getSceneSort(nil), nil, nil) + return qb.queryScenes(selectAll(sceneTable)+qb.getSceneSort(nil), nil, nil) } func (qb *SceneQueryBuilder) Query(sceneFilter *SceneFilterType, findFilter *FindFilterType) ([]*Scene, int) { @@ -235,137 +236,138 @@ func (qb *SceneQueryBuilder) Query(sceneFilter *SceneFilterType, findFilter *Fin findFilter = &FindFilterType{} } - var whereClauses []string - var havingClauses []string - var args []interface{} - body := selectDistinctIDs("scenes") - body = body + ` + query := queryBuilder{ + tableName: sceneTable, + } + + query.body = selectDistinctIDs(sceneTable) + query.body += ` left join scene_markers on scene_markers.scene_id = scenes.id left join performers_scenes as performers_join on performers_join.scene_id = scenes.id left join movies_scenes as movies_join on movies_join.scene_id = scenes.id - left join performers on performers_join.performer_id = performers.id - left join movies on movies_join.movie_id = movies.id left join studios as studio on studio.id = scenes.studio_id left join galleries as gallery on gallery.scene_id = scenes.id left join scenes_tags as tags_join on tags_join.scene_id = scenes.id - left join tags on tags_join.tag_id = tags.id ` if q := findFilter.Q; q != nil && *q != "" { searchColumns := []string{"scenes.title", "scenes.details", "scenes.path", "scenes.checksum", "scene_markers.title"} clause, thisArgs := getSearchBinding(searchColumns, *q, false) - whereClauses = append(whereClauses, clause) - args = append(args, thisArgs...) + query.addWhere(clause) + query.addArg(thisArgs...) } if rating := sceneFilter.Rating; rating != nil { clause, count := getIntCriterionWhereClause("scenes.rating", *sceneFilter.Rating) - whereClauses = append(whereClauses, clause) + query.addWhere(clause) if count == 1 { - args = append(args, sceneFilter.Rating.Value) + query.addArg(sceneFilter.Rating.Value) } } if oCounter := sceneFilter.OCounter; oCounter != nil { clause, count := getIntCriterionWhereClause("scenes.o_counter", *sceneFilter.OCounter) - whereClauses = append(whereClauses, clause) + query.addWhere(clause) if count == 1 { - args = append(args, sceneFilter.OCounter.Value) + query.addArg(sceneFilter.OCounter.Value) } } if durationFilter := sceneFilter.Duration; durationFilter != nil { clause, thisArgs := getDurationWhereClause(*durationFilter) - whereClauses = append(whereClauses, clause) - args = append(args, thisArgs...) + query.addWhere(clause) + query.addArg(thisArgs...) } if resolutionFilter := sceneFilter.Resolution; resolutionFilter != nil { if resolution := resolutionFilter.String(); resolutionFilter.IsValid() { switch resolution { case "LOW": - whereClauses = append(whereClauses, "scenes.height < 480") + query.addWhere("scenes.height < 480") case "STANDARD": - whereClauses = append(whereClauses, "(scenes.height >= 480 AND scenes.height < 720)") + query.addWhere("(scenes.height >= 480 AND scenes.height < 720)") case "STANDARD_HD": - whereClauses = append(whereClauses, "(scenes.height >= 720 AND scenes.height < 1080)") + query.addWhere("(scenes.height >= 720 AND scenes.height < 1080)") case "FULL_HD": - whereClauses = append(whereClauses, "(scenes.height >= 1080 AND scenes.height < 2160)") + query.addWhere("(scenes.height >= 1080 AND scenes.height < 2160)") case "FOUR_K": - whereClauses = append(whereClauses, "scenes.height >= 2160") + query.addWhere("scenes.height >= 2160") } } } if hasMarkersFilter := sceneFilter.HasMarkers; hasMarkersFilter != nil { if strings.Compare(*hasMarkersFilter, "true") == 0 { - havingClauses = append(havingClauses, "count(scene_markers.scene_id) > 0") + query.addHaving("count(scene_markers.scene_id) > 0") } else { - whereClauses = append(whereClauses, "scene_markers.id IS NULL") + query.addWhere("scene_markers.id IS NULL") } } if isMissingFilter := sceneFilter.IsMissing; isMissingFilter != nil && *isMissingFilter != "" { switch *isMissingFilter { case "gallery": - whereClauses = append(whereClauses, "gallery.scene_id IS NULL") + query.addWhere("gallery.scene_id IS NULL") case "studio": - whereClauses = append(whereClauses, "scenes.studio_id IS NULL") + query.addWhere("scenes.studio_id IS NULL") case "movie": - whereClauses = append(whereClauses, "movies_join.scene_id IS NULL") + query.addWhere("movies_join.scene_id IS NULL") case "performers": - whereClauses = append(whereClauses, "performers_join.scene_id IS NULL") + query.addWhere("performers_join.scene_id IS NULL") case "date": - whereClauses = append(whereClauses, "scenes.date IS \"\" OR scenes.date IS \"0001-01-01\"") + query.addWhere("scenes.date IS \"\" OR scenes.date IS \"0001-01-01\"") case "tags": - whereClauses = append(whereClauses, "tags_join.scene_id IS NULL") + query.addWhere("tags_join.scene_id IS NULL") default: - whereClauses = append(whereClauses, "scenes."+*isMissingFilter+" IS NULL") + query.addWhere("scenes." + *isMissingFilter + " IS NULL") } } if tagsFilter := sceneFilter.Tags; tagsFilter != nil && len(tagsFilter.Value) > 0 { for _, tagID := range tagsFilter.Value { - args = append(args, tagID) + query.addArg(tagID) } + query.body += " LEFT JOIN tags on tags_join.tag_id = tags.id" whereClause, havingClause := getMultiCriterionClause("tags", "scenes_tags", "tag_id", tagsFilter) - whereClauses = appendClause(whereClauses, whereClause) - havingClauses = appendClause(havingClauses, havingClause) + query.addWhere(whereClause) + query.addHaving(havingClause) } if performersFilter := sceneFilter.Performers; performersFilter != nil && len(performersFilter.Value) > 0 { for _, performerID := range performersFilter.Value { - args = append(args, performerID) + query.addArg(performerID) } + query.body += " LEFT JOIN performers ON performers_join.performer_id = performers.id" whereClause, havingClause := getMultiCriterionClause("performers", "performers_scenes", "performer_id", performersFilter) - whereClauses = appendClause(whereClauses, whereClause) - havingClauses = appendClause(havingClauses, havingClause) + query.addWhere(whereClause) + query.addHaving(havingClause) } if studiosFilter := sceneFilter.Studios; studiosFilter != nil && len(studiosFilter.Value) > 0 { for _, studioID := range studiosFilter.Value { - args = append(args, studioID) + query.addArg(studioID) } whereClause, havingClause := getMultiCriterionClause("studio", "", "studio_id", studiosFilter) - whereClauses = appendClause(whereClauses, whereClause) - havingClauses = appendClause(havingClauses, havingClause) + query.addWhere(whereClause) + query.addHaving(havingClause) } if moviesFilter := sceneFilter.Movies; moviesFilter != nil && len(moviesFilter.Value) > 0 { for _, movieID := range moviesFilter.Value { - args = append(args, movieID) + query.addArg(movieID) } + query.body += " LEFT JOIN movies ON movies_join.movie_id = movies.id" whereClause, havingClause := getMultiCriterionClause("movies", "movies_scenes", "movie_id", moviesFilter) - whereClauses = appendClause(whereClauses, whereClause) - havingClauses = appendClause(havingClauses, havingClause) + query.addWhere(whereClause) + query.addHaving(havingClause) } - sortAndPagination := qb.getSceneSort(findFilter) + getPagination(findFilter) - idsResult, countResult := executeFindQuery("scenes", body, args, sortAndPagination, whereClauses, havingClauses) + query.sortAndPagination = qb.getSceneSort(findFilter) + getPagination(findFilter) + idsResult, countResult := query.executeFind() var scenes []*Scene for _, id := range idsResult { diff --git a/pkg/models/querybuilder_scene_marker.go b/pkg/models/querybuilder_scene_marker.go index b1c8790a5..07c28d10e 100644 --- a/pkg/models/querybuilder_scene_marker.go +++ b/pkg/models/querybuilder_scene_marker.go @@ -77,8 +77,7 @@ func (qb *SceneMarkerQueryBuilder) Find(id int) (*SceneMarker, error) { func (qb *SceneMarkerQueryBuilder) FindBySceneID(sceneID int, tx *sqlx.Tx) ([]*SceneMarker, error) { query := ` SELECT scene_markers.* FROM scene_markers - JOIN scenes ON scenes.id = scene_markers.scene_id - WHERE scenes.id = ? + WHERE scene_markers.scene_id = ? GROUP BY scene_markers.id ORDER BY scene_markers.seconds ASC ` diff --git a/pkg/models/querybuilder_scene_test.go b/pkg/models/querybuilder_scene_test.go index 06a03a26f..df6b0e817 100644 --- a/pkg/models/querybuilder_scene_test.go +++ b/pkg/models/querybuilder_scene_test.go @@ -735,18 +735,135 @@ func TestSceneQueryPagination(t *testing.T) { assert.Equal(t, secondID, scenes[1].ID) } +func TestSceneCountByTagID(t *testing.T) { + sqb := models.NewSceneQueryBuilder() + + sceneCount, err := sqb.CountByTagID(tagIDs[tagIdxWithScene]) + + if err != nil { + t.Fatalf("error calling CountByTagID: %s", err.Error()) + } + + assert.Equal(t, 1, sceneCount) + + sceneCount, err = sqb.CountByTagID(0) + + if err != nil { + t.Fatalf("error calling CountByTagID: %s", err.Error()) + } + + assert.Equal(t, 0, sceneCount) +} + +func TestSceneCountByMovieID(t *testing.T) { + sqb := models.NewSceneQueryBuilder() + + sceneCount, err := sqb.CountByMovieID(movieIDs[movieIdxWithScene]) + + if err != nil { + t.Fatalf("error calling CountByMovieID: %s", err.Error()) + } + + assert.Equal(t, 1, sceneCount) + + sceneCount, err = sqb.CountByMovieID(0) + + if err != nil { + t.Fatalf("error calling CountByMovieID: %s", err.Error()) + } + + assert.Equal(t, 0, sceneCount) +} + +func TestSceneCountByStudioID(t *testing.T) { + sqb := models.NewSceneQueryBuilder() + + sceneCount, err := sqb.CountByStudioID(studioIDs[studioIdxWithScene]) + + if err != nil { + t.Fatalf("error calling CountByStudioID: %s", err.Error()) + } + + assert.Equal(t, 1, sceneCount) + + sceneCount, err = sqb.CountByStudioID(0) + + if err != nil { + t.Fatalf("error calling CountByStudioID: %s", err.Error()) + } + + assert.Equal(t, 0, sceneCount) +} + +func TestFindByMovieID(t *testing.T) { + sqb := models.NewSceneQueryBuilder() + + scenes, err := sqb.FindByMovieID(movieIDs[movieIdxWithScene]) + + if err != nil { + t.Fatalf("error calling FindByMovieID: %s", err.Error()) + } + + assert.Len(t, scenes, 1) + assert.Equal(t, sceneIDs[sceneIdxWithMovie], scenes[0].ID) + + scenes, err = sqb.FindByMovieID(0) + + if err != nil { + t.Fatalf("error calling FindByMovieID: %s", err.Error()) + } + + assert.Len(t, scenes, 0) +} + +func TestFindByPerformerID(t *testing.T) { + sqb := models.NewSceneQueryBuilder() + + scenes, err := sqb.FindByPerformerID(performerIDs[performerIdxWithScene]) + + if err != nil { + t.Fatalf("error calling FindByPerformerID: %s", err.Error()) + } + + assert.Len(t, scenes, 1) + assert.Equal(t, sceneIDs[sceneIdxWithPerformer], scenes[0].ID) + + scenes, err = sqb.FindByPerformerID(0) + + if err != nil { + t.Fatalf("error calling FindByPerformerID: %s", err.Error()) + } + + assert.Len(t, scenes, 0) +} + +func TestFindByStudioID(t *testing.T) { + sqb := models.NewSceneQueryBuilder() + + scenes, err := sqb.FindByStudioID(performerIDs[studioIdxWithScene]) + + if err != nil { + t.Fatalf("error calling FindByStudioID: %s", err.Error()) + } + + assert.Len(t, scenes, 1) + assert.Equal(t, sceneIDs[sceneIdxWithStudio], scenes[0].ID) + + scenes, err = sqb.FindByStudioID(0) + + if err != nil { + t.Fatalf("error calling FindByStudioID: %s", err.Error()) + } + + assert.Len(t, scenes, 0) +} + // TODO Update // TODO IncrementOCounter // TODO DecrementOCounter // TODO ResetOCounter // TODO Destroy // TODO FindByChecksum -// TODO FindByPerformerID -// TODO FindByStudioID -// TODO FindByMovieID -// TODO CountByMovieID // TODO Count // TODO SizeCount -// TODO CountByStudioID -// TODO CountByTagID // TODO All diff --git a/pkg/models/querybuilder_sql.go b/pkg/models/querybuilder_sql.go index 3acbd7d44..2944462c2 100644 --- a/pkg/models/querybuilder_sql.go +++ b/pkg/models/querybuilder_sql.go @@ -29,11 +29,19 @@ func (qb queryBuilder) executeFind() ([]int, int) { } func (qb *queryBuilder) addWhere(clauses ...string) { - qb.whereClauses = append(qb.whereClauses, clauses...) + for _, clause := range clauses { + if len(clause) > 0 { + qb.whereClauses = append(qb.whereClauses, clauses...) + } + } } func (qb *queryBuilder) addHaving(clauses ...string) { - qb.havingClauses = append(qb.havingClauses, clauses...) + for _, clause := range clauses { + if len(clause) > 0 { + qb.havingClauses = append(qb.havingClauses, clause) + } + } } func (qb *queryBuilder) addArg(args ...interface{}) { diff --git a/pkg/models/querybuilder_tag.go b/pkg/models/querybuilder_tag.go index 6f7f0e180..94cac05cd 100644 --- a/pkg/models/querybuilder_tag.go +++ b/pkg/models/querybuilder_tag.go @@ -103,8 +103,7 @@ func (qb *TagQueryBuilder) FindBySceneMarkerID(sceneMarkerID int, tx *sqlx.Tx) ( query := ` SELECT tags.* FROM tags LEFT JOIN scene_markers_tags as scene_markers_join on scene_markers_join.tag_id = tags.id - LEFT JOIN scene_markers on scene_markers_join.scene_marker_id = scene_markers.id - WHERE scene_markers.id = ? + WHERE scene_markers_join.scene_marker_id = ? GROUP BY tags.id ` query += qb.getTagSort(nil)