111 lines
4.0 KiB
PL/PgSQL
111 lines
4.0 KiB
PL/PgSQL
-- +migrate Up
|
|
|
|
-- 添加照片表的外键约束
|
|
ALTER TABLE photos
|
|
ADD CONSTRAINT fk_photos_album_id
|
|
FOREIGN KEY (album_id) REFERENCES albums(id) ON DELETE SET NULL;
|
|
|
|
ALTER TABLE photos
|
|
ADD CONSTRAINT fk_photos_category_id
|
|
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE SET NULL;
|
|
|
|
-- 添加相册表的外键约束(如果还没有的话)
|
|
-- 这些约束在创建相册表时可能已经存在,这里做一个保险
|
|
|
|
-- 添加一些有用的触发器和函数
|
|
|
|
-- 创建照片计数更新触发器(用于相册和分类)
|
|
CREATE OR REPLACE FUNCTION update_photo_counts()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'INSERT' THEN
|
|
-- 更新相册照片数量
|
|
IF NEW.album_id IS NOT NULL THEN
|
|
UPDATE albums SET photo_count = photo_count + 1 WHERE id = NEW.album_id;
|
|
END IF;
|
|
-- 更新分类照片数量
|
|
IF NEW.category_id IS NOT NULL THEN
|
|
UPDATE categories SET photo_count = photo_count + 1 WHERE id = NEW.category_id;
|
|
END IF;
|
|
RETURN NEW;
|
|
ELSIF TG_OP = 'DELETE' THEN
|
|
-- 更新相册照片数量
|
|
IF OLD.album_id IS NOT NULL THEN
|
|
UPDATE albums SET photo_count = photo_count - 1 WHERE id = OLD.album_id;
|
|
END IF;
|
|
-- 更新分类照片数量
|
|
IF OLD.category_id IS NOT NULL THEN
|
|
UPDATE categories SET photo_count = photo_count - 1 WHERE id = OLD.category_id;
|
|
END IF;
|
|
RETURN OLD;
|
|
ELSIF TG_OP = 'UPDATE' THEN
|
|
-- 处理相册变更
|
|
IF OLD.album_id IS DISTINCT FROM NEW.album_id THEN
|
|
IF OLD.album_id IS NOT NULL THEN
|
|
UPDATE albums SET photo_count = photo_count - 1 WHERE id = OLD.album_id;
|
|
END IF;
|
|
IF NEW.album_id IS NOT NULL THEN
|
|
UPDATE albums SET photo_count = photo_count + 1 WHERE id = NEW.album_id;
|
|
END IF;
|
|
END IF;
|
|
-- 处理分类变更
|
|
IF OLD.category_id IS DISTINCT FROM NEW.category_id THEN
|
|
IF OLD.category_id IS NOT NULL THEN
|
|
UPDATE categories SET photo_count = photo_count - 1 WHERE id = OLD.category_id;
|
|
END IF;
|
|
IF NEW.category_id IS NOT NULL THEN
|
|
UPDATE categories SET photo_count = photo_count + 1 WHERE id = NEW.category_id;
|
|
END IF;
|
|
END IF;
|
|
RETURN NEW;
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
-- 创建触发器
|
|
CREATE TRIGGER trigger_update_photo_counts
|
|
AFTER INSERT OR UPDATE OR DELETE ON photos
|
|
FOR EACH ROW EXECUTE FUNCTION update_photo_counts();
|
|
|
|
-- 创建相册计数更新触发器(用于分类)
|
|
CREATE OR REPLACE FUNCTION update_album_counts()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'INSERT' THEN
|
|
IF NEW.category_id IS NOT NULL THEN
|
|
UPDATE categories SET album_count = album_count + 1 WHERE id = NEW.category_id;
|
|
END IF;
|
|
RETURN NEW;
|
|
ELSIF TG_OP = 'DELETE' THEN
|
|
IF OLD.category_id IS NOT NULL THEN
|
|
UPDATE categories SET album_count = album_count - 1 WHERE id = OLD.category_id;
|
|
END IF;
|
|
RETURN OLD;
|
|
ELSIF TG_OP = 'UPDATE' THEN
|
|
IF OLD.category_id IS DISTINCT FROM NEW.category_id THEN
|
|
IF OLD.category_id IS NOT NULL THEN
|
|
UPDATE categories SET album_count = album_count - 1 WHERE id = OLD.category_id;
|
|
END IF;
|
|
IF NEW.category_id IS NOT NULL THEN
|
|
UPDATE categories SET album_count = album_count + 1 WHERE id = NEW.category_id;
|
|
END IF;
|
|
END IF;
|
|
RETURN NEW;
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER trigger_update_album_counts
|
|
AFTER INSERT OR UPDATE OR DELETE ON albums
|
|
FOR EACH ROW EXECUTE FUNCTION update_album_counts();
|
|
|
|
-- +migrate Down
|
|
|
|
DROP TRIGGER IF EXISTS trigger_update_album_counts ON albums;
|
|
DROP FUNCTION IF EXISTS update_album_counts();
|
|
DROP TRIGGER IF EXISTS trigger_update_photo_counts ON photos;
|
|
DROP FUNCTION IF EXISTS update_photo_counts();
|
|
ALTER TABLE photos DROP CONSTRAINT IF EXISTS fk_photos_category_id;
|
|
ALTER TABLE photos DROP CONSTRAINT IF EXISTS fk_photos_album_id; |