feat: query for usertitles written

This commit is contained in:
Iron_Felix 2025-11-22 07:53:50 +03:00
parent ba68b5ee04
commit 32566fe7a2
8 changed files with 497 additions and 250 deletions

View file

@ -128,7 +128,7 @@ SELECT
si.image_path as studio_image_path
FROM titles as t
LEFT JOIN images as i ON (t.image_id = i.id)
LEFT JOIN images as i ON (t.poster_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)
@ -349,7 +349,7 @@ SELECT
si.image_path as studio_image_path
FROM titles as t
LEFT JOIN images as i ON (t.image_id = i.id)
LEFT JOIN images as i ON (t.poster_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)
@ -548,82 +548,195 @@ func (q *Queries) SearchTitles(ctx context.Context, arg SearchTitlesParams) ([]S
const searchUserTitles = `-- name: SearchUserTitles :many
SELECT
user_id, title_id, status, rate, review_id, ctime, id, title_names, studio_id, poster_id, title_status, rating, rating_count, release_year, release_season, season, episodes_aired, episodes_all, episodes_len
FROM usertitles as u
JOIN titles as t ON (u.title_id = t.id)
WHERE
CASE
WHEN $1::text IS NOT NULL THEN
(
SELECT bool_and(
EXISTS (
SELECT 1
FROM jsonb_each_text(t.title_names) AS t(key, val)
WHERE val ILIKE pattern
)
)
FROM unnest(
ARRAY(
SELECT '%' || trim(w) || '%'
FROM unnest(string_to_array($1::text, ' ')) AS w
WHERE trim(w) <> ''
)
) AS pattern
)
ELSE true
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,
u.user_id as user_id,
u.status as usertitle_status,
u.rate as user_rate,
u.review_id as review_id,
u.ctime as user_ctime,
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 usertitles as u
LEFT JOIN titles as t ON (u.title_id = t.id)
LEFT JOIN images as i ON (t.poster_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 $1::boolean THEN
-- forward: greater than cursor (next page)
CASE $2::text
WHEN 'year' THEN
($3::int IS NULL) OR
(t.release_year > $3::int) OR
(t.release_year = $3::int AND t.id > $4::bigint)
WHEN 'rating' THEN
($5::float IS NULL) OR
(t.rating > $5::float) OR
(t.rating = $5::float AND t.id > $4::bigint)
WHEN 'id' THEN
($4::bigint IS NULL) OR
(t.id > $4::bigint)
ELSE true -- fallback
END
ELSE
-- backward: less than cursor (prev page)
CASE $2::text
WHEN 'year' THEN
($3::int IS NULL) OR
(t.release_year < $3::int) OR
(t.release_year = $3::int AND t.id < $4::bigint)
WHEN 'rating' THEN
($5::float IS NULL) OR
(t.rating < $5::float) OR
(t.rating = $5::float AND t.id < $4::bigint)
WHEN 'id' THEN
($4::bigint IS NULL) OR
(t.id < $4::bigint)
ELSE true
END
END
AND ($2::title_status_t IS NULL OR t.title_status = $2::title_status_t)
AND ($3::float IS NULL OR t.rating >= $3::float)
AND ($4::int IS NULL OR t.release_year = $4::int)
AND ($5::release_season_t IS NULL OR t.release_season = $5::release_season_t)
AND ($6::usertitle_status_t IS NULL OR u.usertitle_status = $6::usertitle_status_t)
AND (
CASE
WHEN $6::text IS NOT NULL THEN
(
SELECT bool_and(
EXISTS (
SELECT 1
FROM jsonb_each_text(t.title_names) AS t(key, val)
WHERE val ILIKE pattern
)
)
FROM unnest(
ARRAY(
SELECT '%' || trim(w) || '%'
FROM unnest(string_to_array($6::text, ' ')) AS w
WHERE trim(w) <> ''
)
) AS pattern
)
ELSE true
END
)
LIMIT COALESCE($7::int, 100)
AND (u.status::text IN ($7::text, $8::text, $9::text, $10::text))
AND (t.title_status::text IN ($7::text, $11::text, $8::text))
AND ($12::int IS NULL OR u.rate >= $12::int)
AND ($13::float IS NULL OR t.rating >= $13::float)
AND ($14::int IS NULL OR t.release_year = $14::int)
AND ($15::release_season_t IS NULL OR t.release_season = $15::release_season_t)
GROUP BY
t.id, i.id, s.id, si.id
ORDER BY
CASE WHEN $1::boolean THEN
CASE
WHEN $2::text = 'id' THEN t.id
WHEN $2::text = 'year' THEN t.release_year
WHEN $2::text = 'rating' THEN t.rating
WHEN $2::text = 'rate' THEN u.rate
END
END ASC,
CASE WHEN NOT $1::boolean THEN
CASE
WHEN $2::text = 'id' THEN t.id
WHEN $2::text = 'year' THEN t.release_year
WHEN $2::text = 'rating' THEN t.rating
WHEN $2::text = 'rate' THEN u.rate
END
END DESC,
CASE WHEN $2::text <> 'id' THEN t.id END ASC
LIMIT COALESCE($16::int, 100)
`
type SearchUserTitlesParams struct {
Word *string `json:"word"`
Status *TitleStatusT `json:"status"`
Rating *float64 `json:"rating"`
ReleaseYear *int32 `json:"release_year"`
ReleaseSeason *ReleaseSeasonT `json:"release_season"`
UsertitleStatus NullUsertitleStatusT `json:"usertitle_status"`
Limit *int32 `json:"limit"`
Forward bool `json:"forward"`
SortBy string `json:"sort_by"`
CursorYear *int32 `json:"cursor_year"`
CursorID *int64 `json:"cursor_id"`
CursorRating *float64 `json:"cursor_rating"`
Word *string `json:"word"`
Ongoing string `json:"ongoing"`
Planned string `json:"planned"`
Dropped string `json:"dropped"`
InProgress string `json:"in-progress"`
Finished string `json:"finished"`
Rate *int32 `json:"rate"`
Rating *float64 `json:"rating"`
ReleaseYear *int32 `json:"release_year"`
ReleaseSeason *ReleaseSeasonT `json:"release_season"`
Limit *int32 `json:"limit"`
}
type SearchUserTitlesRow struct {
UserID int64 `json:"user_id"`
TitleID int64 `json:"title_id"`
Status UsertitleStatusT `json:"status"`
Rate *int32 `json:"rate"`
ReviewID *int64 `json:"review_id"`
Ctime pgtype.Timestamptz `json:"ctime"`
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"`
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"`
UserID int64 `json:"user_id"`
UsertitleStatus UsertitleStatusT `json:"usertitle_status"`
UserRate *int32 `json:"user_rate"`
ReviewID *int64 `json:"review_id"`
UserCtime pgtype.Timestamptz `json:"user_ctime"`
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"`
}
// 100 is default limit
func (q *Queries) SearchUserTitles(ctx context.Context, arg SearchUserTitlesParams) ([]SearchUserTitlesRow, error) {
rows, err := q.db.Query(ctx, searchUserTitles,
arg.Forward,
arg.SortBy,
arg.CursorYear,
arg.CursorID,
arg.CursorRating,
arg.Word,
arg.Status,
arg.Ongoing,
arg.Planned,
arg.Dropped,
arg.InProgress,
arg.Finished,
arg.Rate,
arg.Rating,
arg.ReleaseYear,
arg.ReleaseSeason,
arg.UsertitleStatus,
arg.Limit,
)
if err != nil {
@ -634,12 +747,6 @@ func (q *Queries) SearchUserTitles(ctx context.Context, arg SearchUserTitlesPara
for rows.Next() {
var i SearchUserTitlesRow
if err := rows.Scan(
&i.UserID,
&i.TitleID,
&i.Status,
&i.Rate,
&i.ReviewID,
&i.Ctime,
&i.ID,
&i.TitleNames,
&i.StudioID,
@ -653,6 +760,19 @@ func (q *Queries) SearchUserTitles(ctx context.Context, arg SearchUserTitlesPara
&i.EpisodesAired,
&i.EpisodesAll,
&i.EpisodesLen,
&i.UserID,
&i.UsertitleStatus,
&i.UserRate,
&i.ReviewID,
&i.UserCtime,
&i.TitleStorageType,
&i.TitleImagePath,
&i.TagNames,
&i.StudioName,
&i.StudioIllustID,
&i.StudioDesc,
&i.StudioStorageType,
&i.StudioImagePath,
); err != nil {
return nil, err
}