feat: implement comprehensive recipe management schema
- Add full database schema with accounts, dishes, ingredients, categories, and pricing - Implement custom types for weight, currency, recipe difficulty, and color hex - Add soft delete pattern with deleted_at and active views for all tables - Include journaling triggers for created_at/updated_at automation feat: add SQLC configuration with proper type overrides - Configure SQLC to use UUID, decimal, and timestamptz types with proper Go mappings - Add github.com/shopspring/decimal dependency for precise decimal handling - Set up proper pointer handling for nullable fields in generated structs refactor: replace simple food_items with full dish management system - Remove old FoodItem model and replace with comprehensive Dish model - Implement dish creation and retrieval queries with full field support - Add ingredient management with weight/amount tracking chore: update infrastructure dependencies - Switch to custom PostgreSQL image with pg_idkit extension for UUIDv7 support - Add DATABASE_URI environment variable configuration - Update Docker Compose configuration for new database image chore: organize SQL with fold markers and section comments - Add vim fold markers for better code navigation - Structure schema into clear sections: extensions, types, tables, triggers - Separate query files with organized comment blocks
This commit is contained in:
@@ -28,6 +28,7 @@ require (
|
||||
github.com/pelletier/go-toml/v2 v2.2.4 // indirect
|
||||
github.com/quic-go/qpack v0.5.1 // indirect
|
||||
github.com/quic-go/quic-go v0.54.0 // indirect
|
||||
github.com/shopspring/decimal v1.4.0 // indirect
|
||||
github.com/twitchyliquid64/golang-asm v0.15.1 // indirect
|
||||
github.com/ugorji/go/codec v1.3.0 // indirect
|
||||
go.uber.org/dig v1.19.0 // indirect
|
||||
|
||||
@@ -52,6 +52,8 @@ github.com/quic-go/qpack v0.5.1 h1:giqksBPnT/HDtZ6VhtFKgoLOWmlyo9Ei6u9PqzIMbhI=
|
||||
github.com/quic-go/qpack v0.5.1/go.mod h1:+PC4XFrEskIVkcLzpEkbLqq1uCoxPhQuvK5rH1ZgaEg=
|
||||
github.com/quic-go/quic-go v0.54.0 h1:6s1YB9QotYI6Ospeiguknbp2Znb/jZYjZLRXn9kMQBg=
|
||||
github.com/quic-go/quic-go v0.54.0/go.mod h1:e68ZEaCdyviluZmy44P6Iey98v/Wfz6HCjQEm+l8zTY=
|
||||
github.com/shopspring/decimal v1.4.0 h1:bxl37RwXBklmTi0C79JfXCEBD1cqqHt0bbgBAGFp81k=
|
||||
github.com/shopspring/decimal v1.4.0/go.mod h1:gawqmDU56v4yIKSwfBSFip1HdCCXN8/+DMd9qYNcwME=
|
||||
github.com/stretchr/objx v0.1.0/go.mod h1:HFkY916IF+rwdDfMAkV7OtwuqBVzrE8GR6GFx+wExME=
|
||||
github.com/stretchr/objx v0.4.0/go.mod h1:YvHI0jy2hoMjB+UWwv71VJQ9isScKT/TqJzVSSt89Yw=
|
||||
github.com/stretchr/objx v0.5.0/go.mod h1:Yh+to48EsGEfYuaHDzXPcE3xhTkx73EhmCGUpEOglKo=
|
||||
|
||||
@@ -5,11 +5,399 @@
|
||||
package db
|
||||
|
||||
import (
|
||||
"github.com/jackc/pgx/v5/pgtype"
|
||||
"database/sql/driver"
|
||||
"fmt"
|
||||
"time"
|
||||
|
||||
"github.com/google/uuid"
|
||||
"github.com/shopspring/decimal"
|
||||
)
|
||||
|
||||
type FoodItem struct {
|
||||
Guid pgtype.UUID
|
||||
Title string
|
||||
Description string
|
||||
type Currency string
|
||||
|
||||
const (
|
||||
CurrencyRUB Currency = "RUB"
|
||||
CurrencyEUR Currency = "EUR"
|
||||
CurrencyUSD Currency = "USD"
|
||||
)
|
||||
|
||||
func (e *Currency) Scan(src interface{}) error {
|
||||
switch s := src.(type) {
|
||||
case []byte:
|
||||
*e = Currency(s)
|
||||
case string:
|
||||
*e = Currency(s)
|
||||
default:
|
||||
return fmt.Errorf("unsupported scan type for Currency: %T", src)
|
||||
}
|
||||
return nil
|
||||
}
|
||||
|
||||
type NullCurrency struct {
|
||||
Currency Currency
|
||||
Valid bool // Valid is true if Currency is not NULL
|
||||
}
|
||||
|
||||
// Scan implements the Scanner interface.
|
||||
func (ns *NullCurrency) Scan(value interface{}) error {
|
||||
if value == nil {
|
||||
ns.Currency, ns.Valid = "", false
|
||||
return nil
|
||||
}
|
||||
ns.Valid = true
|
||||
return ns.Currency.Scan(value)
|
||||
}
|
||||
|
||||
// Value implements the driver Valuer interface.
|
||||
func (ns NullCurrency) Value() (driver.Value, error) {
|
||||
if !ns.Valid {
|
||||
return nil, nil
|
||||
}
|
||||
return string(ns.Currency), nil
|
||||
}
|
||||
|
||||
type RecipeDifficulty string
|
||||
|
||||
const (
|
||||
RecipeDifficultyBeginner RecipeDifficulty = "beginner"
|
||||
RecipeDifficultyEasy RecipeDifficulty = "easy"
|
||||
RecipeDifficultyMedium RecipeDifficulty = "medium"
|
||||
RecipeDifficultyHard RecipeDifficulty = "hard"
|
||||
RecipeDifficultyExpert RecipeDifficulty = "expert"
|
||||
)
|
||||
|
||||
func (e *RecipeDifficulty) Scan(src interface{}) error {
|
||||
switch s := src.(type) {
|
||||
case []byte:
|
||||
*e = RecipeDifficulty(s)
|
||||
case string:
|
||||
*e = RecipeDifficulty(s)
|
||||
default:
|
||||
return fmt.Errorf("unsupported scan type for RecipeDifficulty: %T", src)
|
||||
}
|
||||
return nil
|
||||
}
|
||||
|
||||
type NullRecipeDifficulty struct {
|
||||
RecipeDifficulty RecipeDifficulty
|
||||
Valid bool // Valid is true if RecipeDifficulty is not NULL
|
||||
}
|
||||
|
||||
// Scan implements the Scanner interface.
|
||||
func (ns *NullRecipeDifficulty) Scan(value interface{}) error {
|
||||
if value == nil {
|
||||
ns.RecipeDifficulty, ns.Valid = "", false
|
||||
return nil
|
||||
}
|
||||
ns.Valid = true
|
||||
return ns.RecipeDifficulty.Scan(value)
|
||||
}
|
||||
|
||||
// Value implements the driver Valuer interface.
|
||||
func (ns NullRecipeDifficulty) Value() (driver.Value, error) {
|
||||
if !ns.Valid {
|
||||
return nil, nil
|
||||
}
|
||||
return string(ns.RecipeDifficulty), nil
|
||||
}
|
||||
|
||||
type Weight string
|
||||
|
||||
const (
|
||||
WeightMg Weight = "mg"
|
||||
WeightG Weight = "g"
|
||||
WeightKg Weight = "kg"
|
||||
WeightLb Weight = "lb"
|
||||
WeightOz Weight = "oz"
|
||||
)
|
||||
|
||||
func (e *Weight) Scan(src interface{}) error {
|
||||
switch s := src.(type) {
|
||||
case []byte:
|
||||
*e = Weight(s)
|
||||
case string:
|
||||
*e = Weight(s)
|
||||
default:
|
||||
return fmt.Errorf("unsupported scan type for Weight: %T", src)
|
||||
}
|
||||
return nil
|
||||
}
|
||||
|
||||
type NullWeight struct {
|
||||
Weight Weight
|
||||
Valid bool // Valid is true if Weight is not NULL
|
||||
}
|
||||
|
||||
// Scan implements the Scanner interface.
|
||||
func (ns *NullWeight) Scan(value interface{}) error {
|
||||
if value == nil {
|
||||
ns.Weight, ns.Valid = "", false
|
||||
return nil
|
||||
}
|
||||
ns.Valid = true
|
||||
return ns.Weight.Scan(value)
|
||||
}
|
||||
|
||||
// Value implements the driver Valuer interface.
|
||||
func (ns NullWeight) Value() (driver.Value, error) {
|
||||
if !ns.Valid {
|
||||
return nil, nil
|
||||
}
|
||||
return string(ns.Weight), nil
|
||||
}
|
||||
|
||||
type Account struct {
|
||||
Guid uuid.UUID
|
||||
Username string
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveAccount struct {
|
||||
Guid uuid.UUID
|
||||
Username string
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveDish struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
Instructions *string
|
||||
PreparationTimeMinutes *int16
|
||||
CookingTimeMinutes *int16
|
||||
Difficulty RecipeDifficulty
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
MadePublicAt *time.Time
|
||||
Tags []string
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveDishCategory struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
Color *string
|
||||
SortOrder *int16
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveDishCategoryDish struct {
|
||||
Guid uuid.UUID
|
||||
DishCategoryGuid uuid.UUID
|
||||
DishGuid uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveDishIngredient struct {
|
||||
Guid uuid.UUID
|
||||
DishGuid uuid.UUID
|
||||
IngredientGuid uuid.UUID
|
||||
Amount *decimal.Decimal
|
||||
Weight *decimal.Decimal
|
||||
WeightUnit Weight
|
||||
Notes *string
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveIngredient struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
MadePublicAt *time.Time
|
||||
Tags []string
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveIngredientPrice struct {
|
||||
Guid uuid.UUID
|
||||
IngredientGuid uuid.UUID
|
||||
Price decimal.Decimal
|
||||
PriceCurrency Currency
|
||||
Weight decimal.Decimal
|
||||
WeightUnit Weight
|
||||
StoreGuid uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveLoginInfo struct {
|
||||
Guid uuid.UUID
|
||||
AccountGuid uuid.UUID
|
||||
Email *string
|
||||
PasswordHash string
|
||||
SuspendedAt *time.Time
|
||||
SuspendedReason *string
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveProfile struct {
|
||||
Guid uuid.UUID
|
||||
AccountGuid uuid.UUID
|
||||
Name string
|
||||
Surname *string
|
||||
Patronymic *string
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ActiveStore struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type Dish struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
Instructions *string
|
||||
PreparationTimeMinutes *int16
|
||||
CookingTimeMinutes *int16
|
||||
Difficulty RecipeDifficulty
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
MadePublicAt *time.Time
|
||||
Tags []string
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type DishCategoriesDish struct {
|
||||
Guid uuid.UUID
|
||||
DishCategoryGuid uuid.UUID
|
||||
DishGuid uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type DishCategory struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
Color *string
|
||||
SortOrder *int16
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type DishIngredient struct {
|
||||
Guid uuid.UUID
|
||||
DishGuid uuid.UUID
|
||||
IngredientGuid uuid.UUID
|
||||
Amount *decimal.Decimal
|
||||
Weight *decimal.Decimal
|
||||
WeightUnit Weight
|
||||
Notes *string
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type Ingredient struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
MadePublicAt *time.Time
|
||||
Tags []string
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type IngredientPrice struct {
|
||||
Guid uuid.UUID
|
||||
IngredientGuid uuid.UUID
|
||||
Price decimal.Decimal
|
||||
PriceCurrency Currency
|
||||
Weight decimal.Decimal
|
||||
WeightUnit Weight
|
||||
StoreGuid uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type LoginInfo struct {
|
||||
Guid uuid.UUID
|
||||
AccountGuid uuid.UUID
|
||||
Email *string
|
||||
PasswordHash string
|
||||
SuspendedAt *time.Time
|
||||
SuspendedReason *string
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type Profile struct {
|
||||
Guid uuid.UUID
|
||||
AccountGuid uuid.UUID
|
||||
Name string
|
||||
Surname *string
|
||||
Patronymic *string
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type Store struct {
|
||||
Guid uuid.UUID
|
||||
Title string
|
||||
Description *string
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
Author *uuid.UUID
|
||||
CreatedAt time.Time
|
||||
UpdatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
type ViewAccountProfile struct {
|
||||
Guid uuid.UUID
|
||||
Username string
|
||||
Name string
|
||||
Surname *string
|
||||
Patronymic *string
|
||||
CreatedAt time.Time
|
||||
DeletedAt *time.Time
|
||||
}
|
||||
|
||||
@@ -7,22 +7,74 @@ package db
|
||||
|
||||
import (
|
||||
"context"
|
||||
|
||||
"github.com/google/uuid"
|
||||
)
|
||||
|
||||
const createFoodItem = `-- name: CreateFoodItem :one
|
||||
INSERT INTO food_items(title, description)
|
||||
VALUES ($1, $2)
|
||||
RETURNING guid, title, description
|
||||
const createDish = `-- name: CreateDish :one
|
||||
INSERT INTO dishes(title, description, difficulty, thumbnail_s3_key)
|
||||
VALUES($1, $2, $3, $4)
|
||||
RETURNING guid, title, description, instructions, preparation_time_minutes, cooking_time_minutes, difficulty, thumbnail_s3_key, made_public_at, tags, author, created_at, updated_at, deleted_at
|
||||
`
|
||||
|
||||
type CreateFoodItemParams struct {
|
||||
type CreateDishParams struct {
|
||||
Title string
|
||||
Description string
|
||||
Description *string
|
||||
Difficulty RecipeDifficulty
|
||||
ThumbnailS3Key *uuid.UUID
|
||||
}
|
||||
|
||||
func (q *Queries) CreateFoodItem(ctx context.Context, arg CreateFoodItemParams) (FoodItem, error) {
|
||||
row := q.db.QueryRow(ctx, createFoodItem, arg.Title, arg.Description)
|
||||
var i FoodItem
|
||||
err := row.Scan(&i.Guid, &i.Title, &i.Description)
|
||||
func (q *Queries) CreateDish(ctx context.Context, arg CreateDishParams) (Dish, error) {
|
||||
row := q.db.QueryRow(ctx, createDish,
|
||||
arg.Title,
|
||||
arg.Description,
|
||||
arg.Difficulty,
|
||||
arg.ThumbnailS3Key,
|
||||
)
|
||||
var i Dish
|
||||
err := row.Scan(
|
||||
&i.Guid,
|
||||
&i.Title,
|
||||
&i.Description,
|
||||
&i.Instructions,
|
||||
&i.PreparationTimeMinutes,
|
||||
&i.CookingTimeMinutes,
|
||||
&i.Difficulty,
|
||||
&i.ThumbnailS3Key,
|
||||
&i.MadePublicAt,
|
||||
&i.Tags,
|
||||
&i.Author,
|
||||
&i.CreatedAt,
|
||||
&i.UpdatedAt,
|
||||
&i.DeletedAt,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
||||
const getDish = `-- name: GetDish :one
|
||||
SELECT guid, title, description, instructions, preparation_time_minutes, cooking_time_minutes, difficulty, thumbnail_s3_key, made_public_at, tags, author, created_at, updated_at, deleted_at FROM active_dishes
|
||||
WHERE guid = $1
|
||||
LIMIT 1
|
||||
`
|
||||
|
||||
func (q *Queries) GetDish(ctx context.Context, guid uuid.UUID) (ActiveDish, error) {
|
||||
row := q.db.QueryRow(ctx, getDish, guid)
|
||||
var i ActiveDish
|
||||
err := row.Scan(
|
||||
&i.Guid,
|
||||
&i.Title,
|
||||
&i.Description,
|
||||
&i.Instructions,
|
||||
&i.PreparationTimeMinutes,
|
||||
&i.CookingTimeMinutes,
|
||||
&i.Difficulty,
|
||||
&i.ThumbnailS3Key,
|
||||
&i.MadePublicAt,
|
||||
&i.Tags,
|
||||
&i.Author,
|
||||
&i.CreatedAt,
|
||||
&i.UpdatedAt,
|
||||
&i.DeletedAt,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
||||
@@ -16,7 +16,7 @@ services:
|
||||
- app-network
|
||||
|
||||
postgres:
|
||||
image: postgres:latest
|
||||
image: ghcr.io/vadosware/pg_idkit:0.4.0-pg18.0-alpine3.22.2-amd64
|
||||
healthcheck:
|
||||
test: [ "CMD", "pg_isready", "-q", "-d", "${POSTGRES_DB}", "-U", "${POSTGRES_USER}" ]
|
||||
interval: 5s
|
||||
|
||||
@@ -1,3 +1,4 @@
|
||||
POSTGRES_USER="postgres"
|
||||
POSTGRES_PASSWORD="postgres"
|
||||
POSTGRES_DB="postgres"
|
||||
DATABASE_URI="postgresql://postgres:postgres@localhost:5432/postgres?sslmode=disable"
|
||||
|
||||
@@ -1,4 +1,15 @@
|
||||
-- name: CreateFoodItem :one
|
||||
INSERT INTO food_items(title, description)
|
||||
VALUES ($1, $2)
|
||||
-- vim:fileencoding=utf-8:foldmethod=marker
|
||||
|
||||
--: Dish Object {{{
|
||||
|
||||
;-- name: CreateDish :one
|
||||
INSERT INTO dishes(title, description, difficulty, thumbnail_s3_key)
|
||||
VALUES($1, $2, $3, $4)
|
||||
RETURNING *;
|
||||
|
||||
;-- name: GetDish :one
|
||||
SELECT * FROM active_dishes
|
||||
WHERE guid = $1
|
||||
LIMIT 1;
|
||||
|
||||
--: }}}
|
||||
|
||||
300
sqlc/schema.sql
300
sqlc/schema.sql
@@ -1,7 +1,297 @@
|
||||
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
|
||||
-- vim:fileencoding=utf-8:foldmethod=marker
|
||||
|
||||
CREATE TABLE IF NOT EXISTS food_items (
|
||||
guid UUID PRIMARY KEY,
|
||||
title VARCHAR(50) UNIQUE NOT NULL,
|
||||
description VARCHAR(500) NOT NULL
|
||||
-- Extensions {{{
|
||||
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
|
||||
CREATE EXTENSION IF NOT EXISTS "pg_idkit";
|
||||
-- }}}
|
||||
|
||||
-- Types {{{
|
||||
CREATE TYPE weight AS ENUM ('mg', 'g', 'kg', 'lb', 'oz');
|
||||
CREATE TYPE currency AS ENUM ('RUB', 'EUR', 'USD');
|
||||
CREATE TYPE recipe_difficulty AS ENUM ('beginner', 'easy', 'medium', 'hard', 'expert');
|
||||
CREATE DOMAIN color_hex AS VARCHAR(9)
|
||||
CHECK (VALUE ~ '^#([0-9a-fA-F]{6}|[0-9a-fA-F]{3})$');
|
||||
-- }}}
|
||||
|
||||
-- Tables {{{
|
||||
|
||||
-- accounts {{{
|
||||
CREATE TABLE IF NOT EXISTS accounts (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
username VARCHAR(18) UNIQUE NOT NULL CHECK (LENGTH(username) BETWEEN 3 AND 18),
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_accounts AS SELECT * FROM accounts WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_accounts_username ON accounts(username);
|
||||
-- }}}
|
||||
|
||||
-- login_info {{{
|
||||
CREATE TABLE IF NOT EXISTS login_info (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
account_guid UUID UNIQUE NOT NULL REFERENCES accounts(guid),
|
||||
|
||||
-- Email not necessary
|
||||
email VARCHAR(255) UNIQUE CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'),
|
||||
password_hash VARCHAR(60) NOT NULL,
|
||||
suspended_at TIMESTAMPTZ,
|
||||
suspended_reason VARCHAR(500),
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_login_info AS SELECT * FROM login_info WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_login_info_account ON login_info(account_guid);
|
||||
-- }}}
|
||||
|
||||
-- profiles {{{
|
||||
CREATE TABLE IF NOT EXISTS profiles (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
account_guid UUID UNIQUE NOT NULL REFERENCES accounts(guid),
|
||||
|
||||
name VARCHAR(100) NOT NULL,
|
||||
surname VARCHAR(100),
|
||||
patronymic VARCHAR(100),
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_profiles AS SELECT * FROM profiles WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_profiles_account ON profiles(account_guid);
|
||||
|
||||
CREATE OR REPLACE VIEW view_account_profile AS
|
||||
SELECT
|
||||
a.guid,
|
||||
a.username,
|
||||
p.name,
|
||||
p.surname,
|
||||
p.patronymic,
|
||||
a.created_at,
|
||||
a.deleted_at
|
||||
FROM accounts a
|
||||
JOIN profiles p ON a.guid = p.account_guid
|
||||
WHERE a.deleted_at IS NULL;
|
||||
-- }}}
|
||||
|
||||
-- dish_categories {{{
|
||||
CREATE TABLE IF NOT EXISTS dish_categories (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
title VARCHAR(30) UNIQUE NOT NULL,
|
||||
description VARCHAR(100),
|
||||
color color_hex,
|
||||
sort_order SMALLINT DEFAULT 0,
|
||||
thumbnail_s3_key UUID,
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_dish_categories AS SELECT * FROM dish_categories WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_dish_categories_title ON dish_categories(title);
|
||||
-- }}}
|
||||
|
||||
-- dishes {{{
|
||||
CREATE TABLE IF NOT EXISTS dishes (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
title VARCHAR(50) UNIQUE NOT NULL,
|
||||
description VARCHAR(500),
|
||||
instructions TEXT,
|
||||
preparation_time_minutes SMALLINT CHECK (preparation_time_minutes > 0),
|
||||
cooking_time_minutes SMALLINT CHECK (cooking_time_minutes >= 0),
|
||||
difficulty RECIPE_DIFFICULTY NOT NULL DEFAULT 'medium',
|
||||
thumbnail_s3_key UUID,
|
||||
|
||||
made_public_at TIMESTAMPTZ,
|
||||
tags VARCHAR(20)[],
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_dishes AS SELECT * FROM dishes WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_dishes_title ON dishes(title);
|
||||
CREATE INDEX idx_dishes_title_description_fts ON dishes
|
||||
USING gin(to_tsvector('english', title || ' ' || description));
|
||||
CREATE INDEX idx_dishes_tags ON dishes USING gin(tags);
|
||||
-- }}}
|
||||
|
||||
-- ingredients {{{
|
||||
CREATE TABLE IF NOT EXISTS ingredients (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
title VARCHAR(50) UNIQUE NOT NULL,
|
||||
description VARCHAR(500),
|
||||
thumbnail_s3_key UUID,
|
||||
|
||||
made_public_at TIMESTAMPTZ,
|
||||
tags VARCHAR(20)[],
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_ingredients AS SELECT * FROM ingredients WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_ingredients_title ON ingredients(title);
|
||||
CREATE INDEX idx_ingredients_title_description_fts ON dishes
|
||||
USING gin(to_tsvector('english', title || ' ' || description));
|
||||
CREATE INDEX idx_ingredients_tags ON ingredients USING gin(tags);
|
||||
-- }}}
|
||||
|
||||
-- stores {{{
|
||||
CREATE TABLE IF NOT EXISTS stores (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
title VARCHAR(50) UNIQUE NOT NULL,
|
||||
description VARCHAR(500),
|
||||
thumbnail_s3_key UUID,
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_stores AS SELECT * FROM stores WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_stores_title ON stores(title);
|
||||
-- }}}
|
||||
|
||||
-- ingredient_prices {{{
|
||||
CREATE TABLE IF NOT EXISTS ingredient_prices (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
ingredient_guid UUID NOT NULL REFERENCES ingredients(guid) ON DELETE CASCADE,
|
||||
price DECIMAL(10,2) NOT NULL CHECK (price > 0),
|
||||
price_currency CURRENCY NOT NULL DEFAULT 'USD',
|
||||
weight DECIMAL(8,3) NOT NULL CHECK (weight > 0),
|
||||
weight_unit WEIGHT NOT NULL DEFAULT 'g',
|
||||
store_guid UUID NOT NULL REFERENCES stores(guid) ON DELETE CASCADE,
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_ingredient_prices AS SELECT * FROM ingredient_prices WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_ingredient_prices_ingredient_store ON ingredient_prices(ingredient_guid, store_guid);
|
||||
-- }}}
|
||||
|
||||
-- dish_categories_dishes {{{
|
||||
CREATE TABLE IF NOT EXISTS dish_categories_dishes (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
dish_category_guid UUID NOT NULL REFERENCES dish_categories(guid) ON DELETE CASCADE,
|
||||
dish_guid UUID NOT NULL REFERENCES dishes(guid) ON DELETE CASCADE,
|
||||
UNIQUE(dish_category_guid, dish_guid),
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_dish_category_dishes AS SELECT * FROM dish_categories_dishes WHERE deleted_at IS NULL;
|
||||
--}}}
|
||||
|
||||
-- dish_ingredients {{{
|
||||
CREATE TABLE IF NOT EXISTS dish_ingredients (
|
||||
guid UUID PRIMARY KEY DEFAULT idkit_uuidv7_generate_uuid(),
|
||||
|
||||
dish_guid UUID NOT NULL REFERENCES dishes(guid) ON DELETE CASCADE,
|
||||
ingredient_guid UUID NOT NULL REFERENCES ingredients(guid) ON DELETE CASCADE,
|
||||
UNIQUE(dish_guid, ingredient_guid),
|
||||
|
||||
amount DECIMAL(4,1) DEFAULT 1,
|
||||
weight DECIMAL(8,3),
|
||||
weight_unit WEIGHT NOT NULL DEFAULT 'g',
|
||||
CHECK (amount > 0 OR weight > 0),
|
||||
notes VARCHAR(200),
|
||||
|
||||
author UUID REFERENCES accounts(guid) ON DELETE SET NULL,
|
||||
|
||||
created_at TIMESTAMPTZ NOT NULL,
|
||||
updated_at TIMESTAMPTZ NOT NULL,
|
||||
deleted_at TIMESTAMPTZ
|
||||
);
|
||||
CREATE OR REPLACE VIEW active_dish_ingredients AS SELECT * FROM dish_ingredients WHERE deleted_at IS NULL;
|
||||
CREATE INDEX idx_dish_ingredients_dish_ingredient ON dish_ingredients(dish_guid, ingredient_guid);
|
||||
-- }}}
|
||||
-- }}}
|
||||
|
||||
-- Triggers {{{
|
||||
|
||||
CREATE OR REPLACE FUNCTION handle_journal_insert()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.created_at = now();
|
||||
NEW.updated_at = now();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION handle_journal_update()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.created_at = OLD.created_at;
|
||||
NEW.updated_at = now();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DO $$
|
||||
DECLARE
|
||||
tbl TEXT;
|
||||
BEGIN
|
||||
FOREACH tbl IN ARRAY ARRAY[
|
||||
-- All tables must be listed here
|
||||
'accounts',
|
||||
'login_info',
|
||||
'profiles',
|
||||
'dishes',
|
||||
'dish_categories',
|
||||
'ingredients',
|
||||
'stores',
|
||||
'ingredient_prices',
|
||||
'dish_ingredients',
|
||||
'dish_categories_dishes'
|
||||
]
|
||||
LOOP
|
||||
-- This creates views for all tables, which was supposed to be a relief.
|
||||
-- Unfortunately, SQLC does not see what we doo here; and while queries still work, structs
|
||||
-- are not created in Go code. Moreover, stars cannot be expanded. For this reason we manually
|
||||
-- declare boilerpla.. I mean views under each table. Otherwise this loop would be sufficient.
|
||||
-- Anyways, it does not hurt to have this
|
||||
-- EXECUTE format('
|
||||
-- CREATE OR REPLACE VIEW active_%s AS SELECT * FROM %s WHERE deleted_at IS NULL;
|
||||
-- ', tbl, tbl);
|
||||
|
||||
-- Triggers for journal management
|
||||
EXECUTE format('
|
||||
CREATE OR REPLACE TRIGGER journal_insert_%s
|
||||
BEFORE INSERT ON %s
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION handle_journal_insert();
|
||||
', tbl, tbl);
|
||||
EXECUTE format('
|
||||
CREATE OR REPLACE TRIGGER journal_update_%s
|
||||
BEFORE UPDATE ON %s
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION handle_journal_update();
|
||||
', tbl, tbl);
|
||||
END LOOP;
|
||||
END $$;
|
||||
|
||||
-- }}}
|
||||
|
||||
@@ -1,4 +1,7 @@
|
||||
version: "2"
|
||||
servers:
|
||||
- engine: postgresql
|
||||
uri: "postgresql://postgres:postgres@localhost:5432/postgres?sslmode=disable"
|
||||
sql:
|
||||
- schema: "schema.sql"
|
||||
queries: "query.sql"
|
||||
@@ -9,9 +12,53 @@ sql:
|
||||
sql_package: "pgx/v5"
|
||||
emit_prepared_queries: true
|
||||
emit_pointers_for_null_types: true
|
||||
overrides:
|
||||
- db_type: "color_hex"
|
||||
nullable: false
|
||||
go_type:
|
||||
type: string
|
||||
- db_type: "color_hex"
|
||||
nullable: true
|
||||
go_type:
|
||||
type: "string"
|
||||
pointer: true
|
||||
- db_type: "pg_catalog.numeric"
|
||||
nullable: false
|
||||
go_type:
|
||||
import: "github.com/shopspring/decimal"
|
||||
type: "Decimal"
|
||||
pointer: false
|
||||
- db_type: "pg_catalog.numeric"
|
||||
nullable: true
|
||||
go_type:
|
||||
import: "github.com/shopspring/decimal"
|
||||
type: "Decimal"
|
||||
pointer: true
|
||||
- db_type: "uuid"
|
||||
nullable: true
|
||||
go_type:
|
||||
import: "github.com/google/uuid"
|
||||
type: "UUID"
|
||||
pointer: true
|
||||
- db_type: "uuid"
|
||||
nullable: false
|
||||
go_type:
|
||||
import: "github.com/google/uuid"
|
||||
type: "UUID"
|
||||
pointer: false
|
||||
- db_type: "timestamptz"
|
||||
nullable: true
|
||||
go_type:
|
||||
type: "time.Time"
|
||||
pointer: true
|
||||
- db_type: "timestamptz"
|
||||
nullable: false
|
||||
go_type:
|
||||
type: "time.Time"
|
||||
pointer: false
|
||||
database:
|
||||
# managed: true
|
||||
uri: "postgresql://postgres:postgres@localhost:5432/postgres?sslmode=disable"
|
||||
managed: true
|
||||
# uri: "postgresql://postgres:postgres@localhost:5432/postgres?sslmode=disable"
|
||||
rules:
|
||||
- sqlc/db-prepare
|
||||
|
||||
|
||||
Reference in New Issue
Block a user