Files
asset_assistant/backend/sql/06_currency.sql
2025-11-18 11:53:08 +08:00

103 lines
3.4 KiB
SQL

-- 切换到目标数据库
\c postgres;
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'currency') THEN
CREATE TABLE currency (
id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER update_currency_updated_at
BEFORE UPDATE ON "currency"
FOR EACH ROW
EXECUTE FUNCTION update_data_modified_column();
RAISE NOTICE 'created currency table and trigger';
ELSE
RAISE NOTICE 'currency table already exists';
END IF;
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'currency_name') THEN
CREATE TABLE currency_name (
id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL,
currency_id UUID NOT NULL,
name VARCHAR NOT NULL,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER update_name_updated_at
BEFORE UPDATE ON "currency_name"
FOR EACH ROW
EXECUTE FUNCTION update_data_modified_column();
RAISE NOTICE 'created currency_name table and trigger';
ELSE
RAISE NOTICE 'currency_name table already exists';
END IF;
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'currency_code') THEN
CREATE TABLE currency_code (
id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL,
currency_id UUID NOT NULL,
code VARCHAR NOT NULL,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER update_code_updated_at
BEFORE UPDATE ON "currency_code"
FOR EACH ROW
EXECUTE FUNCTION update_data_modified_column();
RAISE NOTICE 'created currency_code table and trigger';
ELSE
RAISE NOTICE 'currency_code table already exists';
END IF;
END $$;
DO $$
DECLARE
view_exists BOOLEAN;
BEGIN
-- 检查视图是否已存在
SELECT EXISTS (
SELECT 1 FROM information_schema.views
WHERE table_name = 'currency_info_view'
) INTO view_exists;
-- 若视图存在,先删除(避免字段名冲突)
IF view_exists THEN
DROP VIEW currency_info_view;
RAISE NOTICE '已删除旧视图 currency_info_view';
END IF;
-- 创建或更新视图
CREATE OR REPLACE VIEW currency_info_view AS
SELECT
u.id AS currency_id,
n.name AS name,
c.code AS code,
u.deleted AS deleted
FROM
currency u
JOIN
currency_name n ON u.id = n.currency_id
JOIN
currency_code c ON u.id = c.currency_id
WHERE
u.deleted = FALSE;
-- 根据视图是否已存在输出不同提示
IF view_exists THEN
RAISE NOTICE '视图 currency_info_view 已更新(删除旧视图后重建)';
ELSE
RAISE NOTICE '视图 currency_info_view 已创建';
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE NOTICE '处理视图时发生错误: %', SQLERRM;
END $$;