Files
his/sql/fix_audit_fields.sql

85 lines
3.4 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- 数据库审计字段修复脚本
-- 用于确保所有表都能正确处理 create_by 和 create_time 字段
-- 步骤 1: 检查哪些表有审计字段但没有正确设置
-- 查询所有包含审计字段的表及其约束状态
SELECT
table_name,
column_name,
is_nullable,
column_default
FROM
information_schema.columns
WHERE
table_schema = 'public'
AND column_name IN ('create_by', 'create_time', 'update_by', 'update_time')
AND is_nullable = 'NO' -- 表示有NOT NULL约束
ORDER BY
table_name, column_name;
-- 步骤 2: 为所有审计字段设置合理的默认值(可选)
-- 这样即使自动填充失败,也不会违反约束
ALTER TABLE "public"."adm_practitioner" ALTER COLUMN "create_by" SET DEFAULT 'system';
ALTER TABLE "public"."adm_practitioner" ALTER COLUMN "update_by" SET DEFAULT 'system';
-- 步骤 3: 检查并更新现有数据确保没有NULL值
-- 对于create_by字段
UPDATE "public"."adm_practitioner"
SET "create_by" = 'system'
WHERE "create_by" IS NULL OR "create_by" = '';
-- 对于update_by字段
UPDATE "public"."adm_practitioner"
SET "update_by" = 'system'
WHERE "update_by" IS NULL;
-- 步骤 4: 为其他可能存在相同问题的表执行类似操作
-- 以下是根据数据库结构推测的一些表名,您可能需要根据实际情况调整
DO $$
DECLARE
table_name text;
tables_with_audit_fields CURSOR FOR
SELECT DISTINCT t.table_name
FROM information_schema.tables t
JOIN information_schema.columns c ON t.table_name = c.table_name
WHERE t.table_schema = 'public'
AND c.column_name IN ('create_by', 'create_time', 'update_by', 'update_time')
AND c.is_nullable = 'NO';
BEGIN
FOR rec IN tables_with_audit_fields LOOP
BEGIN
-- 为每个表设置审计字段的默认值
EXECUTE format('ALTER TABLE "public"."%I" ALTER COLUMN "create_by" SET DEFAULT ''system''', rec.table_name);
EXECUTE format('ALTER TABLE "public"."%I" ALTER COLUMN "update_by" SET DEFAULT ''system''', rec.table_name);
-- 更新现有的NULL值
EXECUTE format('UPDATE "public"."%I" SET "create_by" = ''system'' WHERE "create_by" IS NULL OR "create_by" = ''''', rec.table_name);
EXECUTE format('UPDATE "public"."%I" SET "update_by" = ''system'' WHERE "update_by" IS NULL', rec.table_name);
RAISE NOTICE 'Processed table: %', rec.table_name;
EXCEPTION
WHEN OTHERS THEN
RAISE NOTICE 'Could not process table: %, Error: %', rec.table_name, SQLERRM;
END;
END LOOP;
END $$;
-- 步骤 5: 验证修复结果
-- 检查是否还有表存在审计字段的NULL值
SELECT
table_name,
column_name,
COUNT(*) as null_count
FROM (
SELECT 'adm_practitioner' as table_name, 'create_by' as column_name, create_by FROM "public"."adm_practitioner" WHERE create_by IS NULL
UNION ALL
SELECT 'adm_practitioner' as table_name, 'update_by' as column_name, update_by FROM "public"."adm_practitioner" WHERE update_by IS NULL
-- 在这里添加其他表的检查
) t
GROUP BY table_name, column_name;
-- 注意事项:
-- 1. 在生产环境执行前务必备份数据库
-- 2. 根据实际业务需求调整默认值(例如使用实际的用户名而非'system'
-- 3. 确保应用程序层面的自动填充机制正常工作
-- 4. 考虑在应用程序启动时进行审计字段的完整性检查