feat: cursor implemented

This commit is contained in:
Iron_Felix 2025-11-22 00:01:48 +03:00
parent 9c0fada00e
commit af0492cdf1
8 changed files with 435 additions and 106 deletions

View file

@ -81,56 +81,96 @@ WHERE id = sqlc.arg('title_id')::bigint;
SELECT
*
FROM titles
WHERE
CASE
WHEN sqlc.narg('word')::text IS NOT NULL THEN
(
SELECT bool_and(
EXISTS (
SELECT 1
FROM jsonb_each_text(title_names) AS t(key, val)
WHERE val ILIKE pattern
)
)
FROM unnest(
ARRAY(
SELECT '%' || trim(w) || '%'
FROM unnest(string_to_array(sqlc.narg('word')::text, ' ')) AS w
WHERE trim(w) <> ''
)
) AS pattern
)
ELSE true
WHERE
CASE
WHEN sqlc.arg('forward')::boolean THEN
-- forward: greater than cursor (next page)
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)
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)
WHEN 'id' THEN
(sqlc.narg('cursor_id')::bigint IS NULL) OR
(id > sqlc.narg('cursor_id')::bigint)
ELSE true -- fallback
END
ELSE
-- backward: less than cursor (prev page)
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)
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)
WHEN 'id' THEN
(sqlc.narg('cursor_id')::bigint IS NULL) OR
(id < sqlc.narg('cursor_id')::bigint)
ELSE true
END
END
AND (
CASE
WHEN sqlc.narg('word')::text IS NOT NULL THEN
(
SELECT bool_and(
EXISTS (
SELECT 1
FROM jsonb_each_text(title_names) AS t(key, val)
WHERE val ILIKE pattern
)
)
FROM unnest(
ARRAY(
SELECT '%' || trim(w) || '%'
FROM unnest(string_to_array(sqlc.narg('word')::text, ' ')) AS w
WHERE trim(w) <> ''
)
) AS pattern
)
ELSE true
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)
ORDER BY
-- Основной ключ: выбранное поле
CASE
WHEN sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'id' THEN id
WHEN sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'year' THEN release_year
WHEN sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'rating' THEN rating
-- WHEN sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'views' THEN views
END ASC,
CASE
WHEN NOT sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'id' THEN id
WHEN NOT sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'year' THEN release_year
WHEN NOT sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'rating' THEN rating
-- WHEN NOT sqlc.arg(forward)::boolean AND sqlc.arg(sort_by)::text = 'views' THEN views
END DESC,
-- Вторичный ключ: id — только если НЕ сортируем по id
CASE
WHEN sqlc.arg(sort_by)::text != 'id' AND sqlc.arg(forward)::boolean THEN id
END ASC,
CASE
WHEN sqlc.arg(sort_by)::text != 'id' AND NOT sqlc.arg(forward)::boolean THEN id
END DESC
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
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
END
END DESC,
CASE WHEN sqlc.arg('sort_by')::text <> 'id' THEN id END ASC
LIMIT COALESCE(sqlc.narg('limit')::int, 100); -- 100 is default limit
-- OFFSET sqlc.narg('offset')::int;
-- name: SearchUserTitles :many
SELECT