From 5cc67579000c0f3369de0ce83aa1faeb8900f5b6 Mon Sep 17 00:00:00 2001 From: Iron_Felix Date: Sat, 15 Nov 2025 02:51:52 +0300 Subject: [PATCH] feat: minor changes to db and new query --- sql/migrations/000001_init.up.sql | 4 +- sql/models.go | 37 ++++++---- sql/queries.sql.go | 114 ++++++++++++++++++++++++++++++ sql/sqlc.yaml | 12 +++- 4 files changed, 152 insertions(+), 15 deletions(-) diff --git a/sql/migrations/000001_init.up.sql b/sql/migrations/000001_init.up.sql index a5e89b8..c325dc8 100644 --- a/sql/migrations/000001_init.up.sql +++ b/sql/migrations/000001_init.up.sql @@ -44,6 +44,7 @@ CREATE TABLE studios ( CREATE TABLE titles ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, + -- example {"ru": ["Атака титанов", "Атака Титанов"],"en": ["Attack on Titan", "AoT"],"ja": ["進撃の巨人", "しんげきのきょじん"]} title_names jsonb NOT NULL, studio_id bigint NOT NULL REFERENCES studios (id), poster_id bigint REFERENCES images (id), @@ -55,6 +56,7 @@ CREATE TABLE titles ( season int CHECK (season >= 0), episodes_aired int CHECK (episodes_aired >= 0), episodes_all int CHECK (episodes_all >= 0), + -- example { "1": "50.50", "2": "23.23"} episodes_len jsonb, CHECK ((episodes_aired IS NULL AND episodes_all IS NULL) OR (episodes_aired IS NOT NULL AND episodes_all IS NOT NULL @@ -86,7 +88,7 @@ CREATE TABLE signals ( ); CREATE TABLE external_ids ( - user_id NOT NULL REFERENCES users (id), + user_id bigint NOT NULL REFERENCES users (id), service_id bigint REFERENCES external_services (id), external_id text NOT NULL ); diff --git a/sql/models.go b/sql/models.go index 928d5ac..6583b71 100644 --- a/sql/models.go +++ b/sql/models.go @@ -185,6 +185,17 @@ func (ns NullUsertitleStatusT) Value() (driver.Value, error) { return string(ns.UsertitleStatusT), nil } +type ExternalID struct { + UserID int64 `json:"user_id"` + ServiceID *int64 `json:"service_id"` + ExternalID string `json:"external_id"` +} + +type ExternalService struct { + ID int64 `json:"id"` + Name string `json:"name"` +} + type Image struct { ID int64 `json:"id"` StorageType StorageTypeT `json:"storage_type"` @@ -218,19 +229,19 @@ type Tag struct { } type Title 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 NullReleaseSeasonT `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"` } type TitleTag struct { diff --git a/sql/queries.sql.go b/sql/queries.sql.go index 8f92c2a..2ef4178 100644 --- a/sql/queries.sql.go +++ b/sql/queries.sql.go @@ -71,3 +71,117 @@ func (q *Queries) GetUserByID(ctx context.Context, id int64) (GetUserByIDRow, er ) return i, err } + +const searchTitles = `-- name: SearchTitles :many + + + + +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 +WHERE + CASE + WHEN $1::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($1::text, ' ')) AS w + WHERE trim(w) <> '' + ) + ) AS pattern + ) + ELSE true + END + + AND ($2::title_status_t IS NULL OR title_status = $2::title_status_t) + AND ($3::float IS NULL OR rating >= $3::float) + AND ($4::int IS NULL OR release_year = $4::int) + AND ($5::release_season_t IS NULL OR release_season = $5::release_season_t) + +LIMIT COALESCE($7::int, 100) -- 100 is default limit +OFFSET $6::int +` + +type SearchTitlesParams struct { + Word *string `json:"word"` + Status *TitleStatusT `json:"status"` + Rating *float64 `json:"rating"` + ReleaseYear *int32 `json:"release_year"` + ReleaseSeason *ReleaseSeasonT `json:"release_season"` + Offset *int32 `json:"offset"` + Limit *int32 `json:"limit"` +} + +// -- 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; +func (q *Queries) SearchTitles(ctx context.Context, arg SearchTitlesParams) ([]Title, error) { + rows, err := q.db.Query(ctx, searchTitles, + arg.Word, + arg.Status, + arg.Rating, + arg.ReleaseYear, + arg.ReleaseSeason, + arg.Offset, + arg.Limit, + ) + if err != nil { + return nil, err + } + defer rows.Close() + var items []Title + for rows.Next() { + var i Title + if err := rows.Scan( + &i.ID, + &i.TitleNames, + &i.StudioID, + &i.PosterID, + &i.TitleStatus, + &i.Rating, + &i.RatingCount, + &i.ReleaseYear, + &i.ReleaseSeason, + &i.Season, + &i.EpisodesAired, + &i.EpisodesAll, + &i.EpisodesLen, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} diff --git a/sql/sqlc.yaml b/sql/sqlc.yaml index f44761e..f74d2ad 100644 --- a/sql/sqlc.yaml +++ b/sql/sqlc.yaml @@ -24,4 +24,14 @@ sql: nullable: false go_type: import: "time" - type: "Time" \ No newline at end of file + type: "Time" + - db_type: "title_status_t" + nullable: true + go_type: + pointer: true + type: "TitleStatusT" + - db_type: "release_season_t" + nullable: true + go_type: + pointer: true + type: "ReleaseSeasonT" \ No newline at end of file