-- name: GetImageByID :one SELECT id, storage_type, image_path FROM images WHERE id = sqlc.arg('illust_id')::bigint; -- name: CreateImage :one INSERT INTO images (storage_type, image_path) VALUES ($1, $2) RETURNING id, storage_type, image_path; -- name: GetUserByID :one SELECT id, avatar_id, mail, nickname, disp_name, user_desc, creation_date FROM users WHERE id = $1; -- name: GetStudioByID :one SELECT * FROM studios WHERE id = sqlc.arg('studio_id')::bigint; -- name: InsertStudio :one INSERT INTO studios (studio_name, illust_id, studio_desc) VALUES ( sqlc.arg('studio_name')::text, sqlc.narg('illust_id')::bigint, sqlc.narg('studio_desc')::text) RETURNING id, studio_name, illust_id, studio_desc; -- name: GetTitleTags :many SELECT tag_names FROM tags as g JOIN title_tags as t ON(t.tag_id = g.id) WHERE t.title_id = sqlc.arg('title_id')::bigint; -- name: InsertTitleTags :one INSERT INTO title_tags (title_id, tag_id) VALUES ( sqlc.arg('title_id')::bigint, sqlc.arg('tag_id')::bigint) RETURNING title_id, tag_id; -- name: InsertTag :one INSERT INTO tags (tag_names) VALUES ( sqlc.arg('tag_names')::jsonb) RETURNING id, tag_names; -- -- name: ListUsers :many -- SELECT user_id, avatar_id, passhash, mail, nickname, disp_name, user_desc, creation_date -- FROM users -- ORDER BY user_id -- LIMIT $1 OFFSET $2; -- -- name: CreateUser :one -- INSERT INTO users (avatar_id, passhash, mail, nickname, disp_name, user_desc, creation_date) -- VALUES ($1, $2, $3, $4, $5, $6, $7) -- RETURNING user_id, avatar_id, nickname, disp_name, user_desc, creation_date; -- -- name: UpdateUser :one -- UPDATE users -- SET -- avatar_id = COALESCE(sqlc.narg('avatar_id'), avatar_id), -- disp_name = COALESCE(sqlc.narg('disp_name'), disp_name), -- user_desc = COALESCE(sqlc.narg('user_desc'), user_desc), -- passhash = COALESCE(sqlc.narg('passhash'), passhash) -- WHERE user_id = sqlc.arg('user_id') -- RETURNING user_id, avatar_id, nickname, disp_name, user_desc, creation_date; -- -- name: DeleteUser :exec -- DELETE FROM users -- WHERE user_id = $1; -- name: GetTitleByID :one -- sqlc.struct: TitlesFull SELECT t.*, i.storage_type::text as title_storage_type, i.image_path as title_image_path, COALESCE( jsonb_agg(g.tag_names) FILTER (WHERE g.tag_names IS NOT NULL), '[]'::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.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 id = sqlc.arg('title_id')::bigint GROUP BY t.id, i.id, s.id, si.id; -- name: SearchTitles :many SELECT t.*, i.storage_type::text as title_storage_type, i.image_path as title_image_path, COALESCE( jsonb_agg(g.tag_names) FILTER (WHERE g.tag_names IS NOT NULL), '[]'::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.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 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 (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 (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 (t.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 (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 (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 (t.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(t.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 (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 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 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 t.id END ASC LIMIT COALESCE(sqlc.narg('limit')::int, 100); -- 100 is default limit -- name: SearchUserTitles :many SELECT t.*, 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(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 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 (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 (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 (t.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 (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 (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 (t.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(t.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 (u.status::text IN (sqlc.arg('ongoing')::text, sqlc.arg('planned')::text, sqlc.arg('dropped')::text, sqlc.arg('in-progress')::text)) AND (t.title_status::text IN (sqlc.arg('ongoing')::text, sqlc.arg('finished')::text, sqlc.arg('planned')::text)) AND (sqlc.narg('rate')::int IS NULL OR u.rate >= sqlc.narg('rate')::int) 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 t.id WHEN sqlc.arg('sort_by')::text = 'year' THEN t.release_year WHEN sqlc.arg('sort_by')::text = 'rating' THEN t.rating WHEN sqlc.arg('sort_by')::text = 'rate' THEN u.rate END END ASC, CASE WHEN NOT sqlc.arg('forward')::boolean THEN CASE 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 WHEN sqlc.arg('sort_by')::text = 'rate' THEN u.rate END END DESC, CASE WHEN sqlc.arg('sort_by')::text <> 'id' THEN t.id END ASC LIMIT COALESCE(sqlc.narg('limit')::int, 100); -- 100 is default limit -- -- name: ListTitles :many -- SELECT title_id, title_names, studio_id, poster_id, signal_ids, -- title_status, rating, rating_count, release_year, release_season, -- season, episodes_aired, episodes_all, episodes_len -- FROM titles -- ORDER BY title_id -- LIMIT $1 OFFSET $2; -- -- name: UpdateTitle :one -- UPDATE titles -- SET -- title_names = COALESCE(sqlc.narg('title_names'), title_names), -- studio_id = COALESCE(sqlc.narg('studio_id'), studio_id), -- poster_id = COALESCE(sqlc.narg('poster_id'), poster_id), -- signal_ids = COALESCE(sqlc.narg('signal_ids'), signal_ids), -- title_status = COALESCE(sqlc.narg('title_status'), title_status), -- release_year = COALESCE(sqlc.narg('release_year'), release_year), -- release_season = COALESCE(sqlc.narg('release_season'), release_season), -- episodes_aired = COALESCE(sqlc.narg('episodes_aired'), episodes_aired), -- episodes_all = COALESCE(sqlc.narg('episodes_all'), episodes_all), -- episodes_len = COALESCE(sqlc.narg('episodes_len'), episodes_len) -- WHERE title_id = sqlc.arg('title_id') -- RETURNING *; -- name: GetReviewByID :one SELECT * FROM reviews WHERE review_id = sqlc.arg('review_id')::bigint; -- -- name: CreateReview :one -- INSERT INTO reviews (user_id, title_id, image_ids, review_text, creation_date) -- VALUES ($1, $2, $3, $4, $5) -- RETURNING review_id, user_id, title_id, image_ids, review_text, creation_date; -- -- name: UpdateReview :one -- UPDATE reviews -- SET -- image_ids = COALESCE(sqlc.narg('image_ids'), image_ids), -- review_text = COALESCE(sqlc.narg('review_text'), review_text) -- WHERE review_id = sqlc.arg('review_id') -- RETURNING *; -- -- name: DeleteReview :exec -- DELETE FROM reviews -- WHERE review_id = $1; -- name: ListReviewsByTitle :many -- SELECT review_id, user_id, title_id, image_ids, review_text, creation_date -- FROM reviews -- WHERE title_id = $1 -- ORDER BY creation_date DESC -- LIMIT $2 OFFSET $3; -- -- name: ListReviewsByUser :many -- SELECT review_id, user_id, title_id, image_ids, review_text, creation_date -- FROM reviews -- WHERE user_id = $1 -- ORDER BY creation_date DESC -- LIMIT $2 OFFSET $3; -- -- name: GetUserTitle :one -- SELECT usertitle_id, user_id, title_id, status, rate, review_id -- FROM usertitles -- WHERE user_id = $1 AND title_id = $2; -- -- name: ListUserTitles :many -- SELECT usertitle_id, user_id, title_id, status, rate, review_id -- FROM usertitles -- WHERE user_id = $1 -- ORDER BY usertitle_id -- LIMIT $2 OFFSET $3; -- -- name: CreateUserTitle :one -- INSERT INTO usertitles (user_id, title_id, status, rate, review_id) -- VALUES ($1, $2, $3, $4, $5) -- RETURNING usertitle_id, user_id, title_id, status, rate, review_id; -- -- name: UpdateUserTitle :one -- UPDATE usertitles -- SET -- status = COALESCE(sqlc.narg('status'), status), -- rate = COALESCE(sqlc.narg('rate'), rate), -- review_id = COALESCE(sqlc.narg('review_id'), review_id) -- WHERE user_id = $1 AND title_id = $2 -- RETURNING *; -- -- name: DeleteUserTitle :exec -- DELETE FROM usertitles -- WHERE user_id = $1 AND ($2::int IS NULL OR title_id = $2); -- -- name: ListTags :many -- SELECT tag_id, tag_names -- FROM tags -- ORDER BY tag_id -- LIMIT $1 OFFSET $2;