refact: optimizied queries

This commit is contained in:
Iron_Felix 2025-11-22 06:34:07 +03:00
parent 870bbe2395
commit 89a05492c3
6 changed files with 294 additions and 143 deletions

View file

@ -73,14 +73,48 @@ RETURNING id, tag_names;
-- WHERE user_id = $1;
-- name: GetTitleByID :one
SELECT *
FROM titles
WHERE id = sqlc.arg('title_id')::bigint;
-- sqlc.struct: TitlesFull
SELECT
t.*,
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 = sqlc.arg('title_id')::bigint
GROUP BY
t.id, i.id, s.id, si.id;
-- name: SearchTitles :many
SELECT
*
FROM titles
t.*,
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
CASE
WHEN sqlc.arg('forward')::boolean THEN
@ -88,17 +122,17 @@ WHERE
CASE sqlc.arg('sort_by')::text
WHEN 'year' THEN
(sqlc.narg('cursor_year')::int IS NULL) OR
(release_year > sqlc.narg('cursor_year')::int) OR
(release_year = sqlc.narg('cursor_year')::int AND id > sqlc.narg('cursor_id')::bigint)
(t.release_year > sqlc.narg('cursor_year')::int) OR
(t.release_year = sqlc.narg('cursor_year')::int AND t.id > sqlc.narg('cursor_id')::bigint)
WHEN 'rating' THEN
(sqlc.narg('cursor_rating')::float IS NULL) OR
(rating > sqlc.narg('cursor_rating')::float) OR
(rating = sqlc.narg('cursor_rating')::float AND id > sqlc.narg('cursor_id')::bigint)
(t.rating > sqlc.narg('cursor_rating')::float) OR
(t.rating = sqlc.narg('cursor_rating')::float AND t.id > sqlc.narg('cursor_id')::bigint)
WHEN 'id' THEN
(sqlc.narg('cursor_id')::bigint IS NULL) OR
(id > sqlc.narg('cursor_id')::bigint)
(t.id > sqlc.narg('cursor_id')::bigint)
ELSE true -- fallback
END
@ -108,17 +142,17 @@ WHERE
CASE sqlc.arg('sort_by')::text
WHEN 'year' THEN
(sqlc.narg('cursor_year')::int IS NULL) OR
(release_year < sqlc.narg('cursor_year')::int) OR
(release_year = sqlc.narg('cursor_year')::int AND id < sqlc.narg('cursor_id')::bigint)
(t.release_year < sqlc.narg('cursor_year')::int) OR
(t.release_year = sqlc.narg('cursor_year')::int AND t.id < sqlc.narg('cursor_id')::bigint)
WHEN 'rating' THEN
(sqlc.narg('cursor_rating')::float IS NULL) OR
(rating < sqlc.narg('cursor_rating')::float) OR
(rating = sqlc.narg('cursor_rating')::float AND id < sqlc.narg('cursor_id')::bigint)
(t.rating < sqlc.narg('cursor_rating')::float) OR
(t.rating = sqlc.narg('cursor_rating')::float AND t.id < sqlc.narg('cursor_id')::bigint)
WHEN 'id' THEN
(sqlc.narg('cursor_id')::bigint IS NULL) OR
(id < sqlc.narg('cursor_id')::bigint)
(t.id < sqlc.narg('cursor_id')::bigint)
ELSE true
END
@ -131,7 +165,7 @@ WHERE
SELECT bool_and(
EXISTS (
SELECT 1
FROM jsonb_each_text(title_names) AS t(key, val)
FROM jsonb_each_text(t.title_names) AS t(key, val)
WHERE val ILIKE pattern
)
)
@ -147,28 +181,31 @@ WHERE
END
)
AND (sqlc.narg('status')::title_status_t IS NULL OR title_status = sqlc.narg('status')::title_status_t)
AND (sqlc.narg('rating')::float IS NULL OR rating >= sqlc.narg('rating')::float)
AND (sqlc.narg('release_year')::int IS NULL OR release_year = sqlc.narg('release_year')::int)
AND (sqlc.narg('release_season')::release_season_t IS NULL OR release_season = sqlc.narg('release_season')::release_season_t)
AND (t.title_status::text IN (sqlc.arg('ongoing')::text, sqlc.arg('finished')::text, sqlc.arg('planned')::text))
AND (sqlc.narg('rating')::float IS NULL OR t.rating >= sqlc.narg('rating')::float)
AND (sqlc.narg('release_year')::int IS NULL OR t.release_year = sqlc.narg('release_year')::int)
AND (sqlc.narg('release_season')::release_season_t IS NULL OR t.release_season = sqlc.narg('release_season')::release_season_t)
GROUP BY
t.id, i.id, s.id, si.id
ORDER BY
CASE WHEN sqlc.arg('forward')::boolean THEN
CASE
WHEN sqlc.arg('sort_by')::text = 'id' THEN id
WHEN sqlc.arg('sort_by')::text = 'year' THEN release_year
WHEN sqlc.arg('sort_by')::text = 'rating' THEN rating
WHEN sqlc.arg('sort_by')::text = 'id' THEN t.id
WHEN sqlc.arg('sort_by')::text = 'year' THEN t.release_year
WHEN sqlc.arg('sort_by')::text = 'rating' THEN t.rating
END
END ASC,
CASE WHEN NOT sqlc.arg('forward')::boolean THEN
CASE
WHEN sqlc.arg('sort_by')::text = 'id' THEN id
WHEN sqlc.arg('sort_by')::text = 'year' THEN release_year
WHEN sqlc.arg('sort_by')::text = 'rating' THEN rating
WHEN sqlc.arg('sort_by')::text = 'id' THEN t.id
WHEN sqlc.arg('sort_by')::text = 'year' THEN t.release_year
WHEN sqlc.arg('sort_by')::text = 'rating' THEN t.rating
END
END DESC,
CASE WHEN sqlc.arg('sort_by')::text <> 'id' THEN id END ASC
CASE WHEN sqlc.arg('sort_by')::text <> 'id' THEN t.id END ASC
LIMIT COALESCE(sqlc.narg('limit')::int, 100); -- 100 is default limit