mmap/migrations/007_create_page_blocks.sql
tsuki d29679c6f8
Some checks are pending
Docker Build and Push / build (push) Waiting to run
add casbin
2025-08-11 21:26:29 +08:00

158 lines
6.1 KiB
PL/PgSQL

-- 创建页面表
CREATE TABLE IF NOT EXISTS pages (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
title VARCHAR(255) NOT NULL,
slug VARCHAR(255) NOT NULL UNIQUE,
description TEXT,
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
created_by UUID REFERENCES users(id),
updated_by UUID REFERENCES users(id)
);
-- 创建文本块表
CREATE TABLE IF NOT EXISTS text_blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
page_id UUID NOT NULL REFERENCES pages(id) ON DELETE CASCADE,
block_order INTEGER NOT NULL,
title VARCHAR(255),
markdown TEXT NOT NULL,
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
UNIQUE(page_id, block_order)
);
-- 创建图表块表
CREATE TABLE IF NOT EXISTS chart_blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
page_id UUID NOT NULL REFERENCES pages(id) ON DELETE CASCADE,
block_order INTEGER NOT NULL,
title VARCHAR(255) NOT NULL,
chart_type VARCHAR(50) NOT NULL,
config JSONB,
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
UNIQUE(page_id, block_order)
);
-- 创建数据点表
CREATE TABLE IF NOT EXISTS data_points (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
chart_block_id UUID NOT NULL REFERENCES chart_blocks(id) ON DELETE CASCADE,
x DOUBLE PRECISION NOT NULL,
y DOUBLE PRECISION NOT NULL,
label VARCHAR(255),
color VARCHAR(50),
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-- 创建设置块表
CREATE TABLE IF NOT EXISTS settings_blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
page_id UUID NOT NULL REFERENCES pages(id) ON DELETE CASCADE,
block_order INTEGER NOT NULL,
title VARCHAR(255),
category VARCHAR(100) NOT NULL,
editable BOOLEAN NOT NULL DEFAULT true,
display_mode VARCHAR(50) NOT NULL DEFAULT 'form',
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
UNIQUE(page_id, block_order)
);
-- 创建表格块表
CREATE TABLE IF NOT EXISTS table_blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
page_id UUID NOT NULL REFERENCES pages(id) ON DELETE CASCADE,
block_order INTEGER NOT NULL,
title VARCHAR(255),
data_source VARCHAR(100) NOT NULL,
data_config JSONB,
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
UNIQUE(page_id, block_order)
);
-- 创建表格列定义表
CREATE TABLE IF NOT EXISTS table_columns (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
table_block_id UUID NOT NULL REFERENCES table_blocks(id) ON DELETE CASCADE,
name VARCHAR(100) NOT NULL,
label VARCHAR(255) NOT NULL,
data_type VARCHAR(50) NOT NULL,
is_sortable BOOLEAN NOT NULL DEFAULT false,
is_filterable BOOLEAN NOT NULL DEFAULT false,
width INTEGER,
"order" INTEGER NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
UNIQUE(table_block_id, "order")
);
-- 创建英雄块表
CREATE TABLE IF NOT EXISTS hero_blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
page_id UUID NOT NULL REFERENCES pages(id) ON DELETE CASCADE,
block_order INTEGER NOT NULL,
title VARCHAR(255) NOT NULL,
subtitle TEXT,
background_image VARCHAR(500),
background_color VARCHAR(50),
text_color VARCHAR(50),
cta_text VARCHAR(100),
cta_link VARCHAR(500),
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
UNIQUE(page_id, block_order)
);
-- 创建索引
CREATE INDEX IF NOT EXISTS idx_pages_slug ON pages(slug);
CREATE INDEX IF NOT EXISTS idx_pages_is_active ON pages(is_active);
CREATE INDEX IF NOT EXISTS idx_text_blocks_page_id ON text_blocks(page_id);
CREATE INDEX IF NOT EXISTS idx_chart_blocks_page_id ON chart_blocks(page_id);
CREATE INDEX IF NOT EXISTS idx_settings_blocks_page_id ON settings_blocks(page_id);
CREATE INDEX IF NOT EXISTS idx_table_blocks_page_id ON table_blocks(page_id);
CREATE INDEX IF NOT EXISTS idx_hero_blocks_page_id ON hero_blocks(page_id);
CREATE INDEX IF NOT EXISTS idx_data_points_chart_block_id ON data_points(chart_block_id);
CREATE INDEX IF NOT EXISTS idx_table_columns_table_block_id ON table_columns(table_block_id);
-- 创建更新时间触发器函数
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ language 'plpgsql';
-- 为所有表添加更新时间触发器
CREATE TRIGGER update_pages_updated_at BEFORE UPDATE ON pages
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_text_blocks_updated_at BEFORE UPDATE ON text_blocks
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_chart_blocks_updated_at BEFORE UPDATE ON chart_blocks
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_settings_blocks_updated_at BEFORE UPDATE ON settings_blocks
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_table_blocks_updated_at BEFORE UPDATE ON table_blocks
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_hero_blocks_updated_at BEFORE UPDATE ON hero_blocks
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- 插入一些示例数据
INSERT INTO pages (id, title, slug, description, is_active) VALUES
(gen_random_uuid(), '系统设置', 'system-settings', '系统配置管理页面', true),
(gen_random_uuid(), '数据概览', 'data-overview', '数据统计和图表展示', true),
(gen_random_uuid(), '用户管理', 'user-management', '用户信息管理页面', true)
ON CONFLICT (slug) DO NOTHING;