73 lines
2.6 KiB
PL/PgSQL
73 lines
2.6 KiB
PL/PgSQL
-- +migrate Up
|
|
|
|
CREATE TABLE albums (
|
|
id SERIAL PRIMARY KEY,
|
|
title VARCHAR(200) NOT NULL,
|
|
description TEXT,
|
|
slug VARCHAR(255) UNIQUE,
|
|
cover_photo_id INTEGER REFERENCES photos(id) ON DELETE SET NULL,
|
|
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
category_id INTEGER REFERENCES categories(id) ON DELETE SET NULL,
|
|
is_public BOOLEAN DEFAULT true,
|
|
is_featured BOOLEAN DEFAULT false,
|
|
password VARCHAR(255),
|
|
view_count INTEGER DEFAULT 0,
|
|
like_count INTEGER DEFAULT 0,
|
|
photo_count INTEGER DEFAULT 0,
|
|
sort_order INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
deleted_at TIMESTAMP
|
|
);
|
|
|
|
-- 创建索引
|
|
CREATE INDEX idx_albums_user_id ON albums(user_id);
|
|
CREATE INDEX idx_albums_category_id ON albums(category_id);
|
|
CREATE INDEX idx_albums_cover_photo_id ON albums(cover_photo_id);
|
|
CREATE INDEX idx_albums_slug ON albums(slug);
|
|
CREATE INDEX idx_albums_is_public ON albums(is_public);
|
|
CREATE INDEX idx_albums_is_featured ON albums(is_featured);
|
|
CREATE INDEX idx_albums_created_at ON albums(created_at);
|
|
CREATE INDEX idx_albums_view_count ON albums(view_count);
|
|
CREATE INDEX idx_albums_like_count ON albums(like_count);
|
|
CREATE INDEX idx_albums_photo_count ON albums(photo_count);
|
|
CREATE INDEX idx_albums_sort_order ON albums(sort_order);
|
|
CREATE INDEX idx_albums_deleted_at ON albums(deleted_at) WHERE deleted_at IS NOT NULL;
|
|
|
|
-- 添加更新时间触发器
|
|
CREATE TRIGGER update_albums_updated_at BEFORE UPDATE ON albums
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- 添加 slug 自动生成触发器
|
|
CREATE OR REPLACE FUNCTION generate_album_slug()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF NEW.slug IS NULL OR NEW.slug = '' THEN
|
|
NEW.slug = lower(regexp_replace(NEW.title, '[^a-zA-Z0-9]+', '-', 'g'));
|
|
NEW.slug = trim(both '-' from NEW.slug);
|
|
|
|
-- 确保 slug 唯一
|
|
DECLARE
|
|
counter INTEGER := 0;
|
|
base_slug VARCHAR(255);
|
|
BEGIN
|
|
base_slug := NEW.slug;
|
|
WHILE EXISTS (SELECT 1 FROM albums WHERE slug = NEW.slug AND id != COALESCE(NEW.id, 0)) LOOP
|
|
counter := counter + 1;
|
|
NEW.slug := base_slug || '-' || counter;
|
|
END LOOP;
|
|
END;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER generate_albums_slug BEFORE INSERT OR UPDATE ON albums
|
|
FOR EACH ROW EXECUTE FUNCTION generate_album_slug();
|
|
|
|
-- +migrate Down
|
|
|
|
DROP TRIGGER IF EXISTS generate_albums_slug ON albums;
|
|
DROP FUNCTION IF EXISTS generate_album_slug();
|
|
DROP TRIGGER IF EXISTS update_albums_updated_at ON albums;
|
|
DROP TABLE IF EXISTS albums; |