refact: optimizied queries
This commit is contained in:
parent
870bbe2395
commit
89a05492c3
6 changed files with 294 additions and 143 deletions
|
|
@ -116,11 +116,53 @@ const getTitleByID = `-- name: GetTitleByID :one
|
|||
|
||||
|
||||
|
||||
SELECT id, title_names, studio_id, poster_id, title_status, rating, rating_count, release_year, release_season, season, episodes_aired, episodes_all, episodes_len
|
||||
FROM titles
|
||||
SELECT
|
||||
t.id, t.title_names, t.studio_id, t.poster_id, t.title_status, t.rating, t.rating_count, t.release_year, t.release_season, t.season, t.episodes_aired, t.episodes_all, t.episodes_len,
|
||||
i.storage_type::text as title_storage_type,
|
||||
i.image_path as title_image_path,
|
||||
jsonb_agg_strict(g.tag_name)'[]'::jsonb as tag_names,
|
||||
s.studio_name as studio_name,
|
||||
s.illust_id as studio_illust_id,
|
||||
s.studio_desc as studio_desc,
|
||||
si.storage_type::text as studio_storage_type,
|
||||
si.image_path as studio_image_path
|
||||
|
||||
FROM titles as t
|
||||
LEFT JOIN images as i ON (t.image_id = i.id)
|
||||
LEFT JOIN title_tags as tt ON (t.id = tt.title_id)
|
||||
LEFT JOIN tags as g ON (tt.tag_id = g.id)
|
||||
LEFT JOIN studios as s ON (t.studio_id = s.id)
|
||||
LEFT JOIN images as si ON (s.illust_id = si.id)
|
||||
|
||||
WHERE id = $1::bigint
|
||||
GROUP BY
|
||||
t.id, i.id, s.id, si.id
|
||||
`
|
||||
|
||||
type GetTitleByIDRow struct {
|
||||
ID int64 `json:"id"`
|
||||
TitleNames []byte `json:"title_names"`
|
||||
StudioID int64 `json:"studio_id"`
|
||||
PosterID *int64 `json:"poster_id"`
|
||||
TitleStatus TitleStatusT `json:"title_status"`
|
||||
Rating *float64 `json:"rating"`
|
||||
RatingCount *int32 `json:"rating_count"`
|
||||
ReleaseYear *int32 `json:"release_year"`
|
||||
ReleaseSeason *ReleaseSeasonT `json:"release_season"`
|
||||
Season *int32 `json:"season"`
|
||||
EpisodesAired *int32 `json:"episodes_aired"`
|
||||
EpisodesAll *int32 `json:"episodes_all"`
|
||||
EpisodesLen []byte `json:"episodes_len"`
|
||||
TitleStorageType string `json:"title_storage_type"`
|
||||
TitleImagePath *string `json:"title_image_path"`
|
||||
TagNames []byte `json:"tag_names"`
|
||||
StudioName *string `json:"studio_name"`
|
||||
StudioIllustID *int64 `json:"studio_illust_id"`
|
||||
StudioDesc *string `json:"studio_desc"`
|
||||
StudioStorageType string `json:"studio_storage_type"`
|
||||
StudioImagePath *string `json:"studio_image_path"`
|
||||
}
|
||||
|
||||
// -- name: ListUsers :many
|
||||
// SELECT user_id, avatar_id, passhash, mail, nickname, disp_name, user_desc, creation_date
|
||||
// FROM users
|
||||
|
|
@ -144,9 +186,10 @@ WHERE id = $1::bigint
|
|||
// -- name: DeleteUser :exec
|
||||
// DELETE FROM users
|
||||
// WHERE user_id = $1;
|
||||
func (q *Queries) GetTitleByID(ctx context.Context, titleID int64) (Title, error) {
|
||||
// sqlc.struct: TitlesFull
|
||||
func (q *Queries) GetTitleByID(ctx context.Context, titleID int64) (GetTitleByIDRow, error) {
|
||||
row := q.db.QueryRow(ctx, getTitleByID, titleID)
|
||||
var i Title
|
||||
var i GetTitleByIDRow
|
||||
err := row.Scan(
|
||||
&i.ID,
|
||||
&i.TitleNames,
|
||||
|
|
@ -161,6 +204,14 @@ func (q *Queries) GetTitleByID(ctx context.Context, titleID int64) (Title, error
|
|||
&i.EpisodesAired,
|
||||
&i.EpisodesAll,
|
||||
&i.EpisodesLen,
|
||||
&i.TitleStorageType,
|
||||
&i.TitleImagePath,
|
||||
&i.TagNames,
|
||||
&i.StudioName,
|
||||
&i.StudioIllustID,
|
||||
&i.StudioDesc,
|
||||
&i.StudioStorageType,
|
||||
&i.StudioImagePath,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
|
@ -288,15 +339,15 @@ func (q *Queries) InsertTitleTags(ctx context.Context, arg InsertTitleTagsParams
|
|||
const searchTitles = `-- name: SearchTitles :many
|
||||
SELECT
|
||||
t.id, t.title_names, t.studio_id, t.poster_id, t.title_status, t.rating, t.rating_count, t.release_year, t.release_season, t.season, t.episodes_aired, t.episodes_all, t.episodes_len,
|
||||
i.storage_type as title_storage_type,
|
||||
i.image_path as title_image_path,
|
||||
g.tag_names as tag_names,
|
||||
s.studio_name as studio_name,
|
||||
s.illust_id as studio_illust_id,
|
||||
s.studio_desc as studio_desc,
|
||||
si.storage_type as studio_storage_type,
|
||||
si.image_path as studio_image_path
|
||||
|
||||
i.storage_type::text as title_storage_type,
|
||||
i.image_path as title_image_path,
|
||||
jsonb_agg_strict(g.tag_name)'[]'::jsonb as tag_names,
|
||||
s.studio_name as studio_name,
|
||||
s.illust_id as studio_illust_id,
|
||||
s.studio_desc as studio_desc,
|
||||
si.storage_type::text as studio_storage_type,
|
||||
si.image_path as studio_image_path
|
||||
|
||||
FROM titles as t
|
||||
LEFT JOIN images as i ON (t.image_id = i.id)
|
||||
LEFT JOIN title_tags as tt ON (t.id = tt.title_id)
|
||||
|
|
@ -370,10 +421,13 @@ WHERE
|
|||
END
|
||||
)
|
||||
|
||||
AND ($7::title_status_t IS NULL OR t.title_status = $7::title_status_t)
|
||||
AND ($8::float IS NULL OR t.rating >= $8::float)
|
||||
AND ($9::int IS NULL OR t.release_year = $9::int)
|
||||
AND ($10::release_season_t IS NULL OR t.release_season = $10::release_season_t)
|
||||
AND (t.title_status::text IN ($7::text, $8::text, $9::text))
|
||||
AND ($10::float IS NULL OR t.rating >= $10::float)
|
||||
AND ($11::int IS NULL OR t.release_year = $11::int)
|
||||
AND ($12::release_season_t IS NULL OR t.release_season = $12::release_season_t)
|
||||
|
||||
GROUP BY
|
||||
t.id, i.id, s.id, si.id
|
||||
|
||||
ORDER BY
|
||||
CASE WHEN $1::boolean THEN
|
||||
|
|
@ -393,7 +447,7 @@ ORDER BY
|
|||
|
||||
CASE WHEN $2::text <> 'id' THEN t.id END ASC
|
||||
|
||||
LIMIT COALESCE($11::int, 100)
|
||||
LIMIT COALESCE($13::int, 100)
|
||||
`
|
||||
|
||||
type SearchTitlesParams struct {
|
||||
|
|
@ -403,7 +457,9 @@ type SearchTitlesParams struct {
|
|||
CursorID *int64 `json:"cursor_id"`
|
||||
CursorRating *float64 `json:"cursor_rating"`
|
||||
Word *string `json:"word"`
|
||||
Status *TitleStatusT `json:"status"`
|
||||
Ongoing string `json:"ongoing"`
|
||||
Finished string `json:"finished"`
|
||||
Planned string `json:"planned"`
|
||||
Rating *float64 `json:"rating"`
|
||||
ReleaseYear *int32 `json:"release_year"`
|
||||
ReleaseSeason *ReleaseSeasonT `json:"release_season"`
|
||||
|
|
@ -411,27 +467,27 @@ type SearchTitlesParams struct {
|
|||
}
|
||||
|
||||
type SearchTitlesRow struct {
|
||||
ID int64 `json:"id"`
|
||||
TitleNames []byte `json:"title_names"`
|
||||
StudioID int64 `json:"studio_id"`
|
||||
PosterID *int64 `json:"poster_id"`
|
||||
TitleStatus TitleStatusT `json:"title_status"`
|
||||
Rating *float64 `json:"rating"`
|
||||
RatingCount *int32 `json:"rating_count"`
|
||||
ReleaseYear *int32 `json:"release_year"`
|
||||
ReleaseSeason *ReleaseSeasonT `json:"release_season"`
|
||||
Season *int32 `json:"season"`
|
||||
EpisodesAired *int32 `json:"episodes_aired"`
|
||||
EpisodesAll *int32 `json:"episodes_all"`
|
||||
EpisodesLen []byte `json:"episodes_len"`
|
||||
TitleStorageType NullStorageTypeT `json:"title_storage_type"`
|
||||
TitleImagePath *string `json:"title_image_path"`
|
||||
TagNames []byte `json:"tag_names"`
|
||||
StudioName *string `json:"studio_name"`
|
||||
StudioIllustID *int64 `json:"studio_illust_id"`
|
||||
StudioDesc *string `json:"studio_desc"`
|
||||
StudioStorageType NullStorageTypeT `json:"studio_storage_type"`
|
||||
StudioImagePath *string `json:"studio_image_path"`
|
||||
ID int64 `json:"id"`
|
||||
TitleNames []byte `json:"title_names"`
|
||||
StudioID int64 `json:"studio_id"`
|
||||
PosterID *int64 `json:"poster_id"`
|
||||
TitleStatus TitleStatusT `json:"title_status"`
|
||||
Rating *float64 `json:"rating"`
|
||||
RatingCount *int32 `json:"rating_count"`
|
||||
ReleaseYear *int32 `json:"release_year"`
|
||||
ReleaseSeason *ReleaseSeasonT `json:"release_season"`
|
||||
Season *int32 `json:"season"`
|
||||
EpisodesAired *int32 `json:"episodes_aired"`
|
||||
EpisodesAll *int32 `json:"episodes_all"`
|
||||
EpisodesLen []byte `json:"episodes_len"`
|
||||
TitleStorageType string `json:"title_storage_type"`
|
||||
TitleImagePath *string `json:"title_image_path"`
|
||||
TagNames []byte `json:"tag_names"`
|
||||
StudioName *string `json:"studio_name"`
|
||||
StudioIllustID *int64 `json:"studio_illust_id"`
|
||||
StudioDesc *string `json:"studio_desc"`
|
||||
StudioStorageType string `json:"studio_storage_type"`
|
||||
StudioImagePath *string `json:"studio_image_path"`
|
||||
}
|
||||
|
||||
func (q *Queries) SearchTitles(ctx context.Context, arg SearchTitlesParams) ([]SearchTitlesRow, error) {
|
||||
|
|
@ -442,7 +498,9 @@ func (q *Queries) SearchTitles(ctx context.Context, arg SearchTitlesParams) ([]S
|
|||
arg.CursorID,
|
||||
arg.CursorRating,
|
||||
arg.Word,
|
||||
arg.Status,
|
||||
arg.Ongoing,
|
||||
arg.Finished,
|
||||
arg.Planned,
|
||||
arg.Rating,
|
||||
arg.ReleaseYear,
|
||||
arg.ReleaseSeason,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue