temp
This commit is contained in:
549
urbanLifelineServ/.bin/database/postgres/sql/optimizations.sql
Normal file
549
urbanLifelineServ/.bin/database/postgres/sql/optimizations.sql
Normal file
@@ -0,0 +1,549 @@
|
||||
-- =============================
|
||||
-- 数据库优化补丁脚本
|
||||
-- 基于现有表结构的增强和修改
|
||||
-- =============================
|
||||
|
||||
-- =============================
|
||||
-- 1. 用户模块优化
|
||||
-- =============================
|
||||
|
||||
-- 1.1 移除登录日志表中的敏感密码字段
|
||||
DO $$
|
||||
BEGIN
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'sys'
|
||||
AND table_name = 'tb_sys_login_log'
|
||||
AND column_name = 'password'
|
||||
) THEN
|
||||
ALTER TABLE sys.tb_sys_login_log DROP COLUMN password;
|
||||
RAISE NOTICE '已移除登录日志表的密码字段';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- 1.2 创建用户部门关联表
|
||||
CREATE TABLE IF NOT EXISTS sys.tb_sys_user_dept (
|
||||
optsn VARCHAR(50) NOT NULL,
|
||||
user_id VARCHAR(50) NOT NULL,
|
||||
dept_id VARCHAR(50) NOT NULL,
|
||||
is_primary BOOLEAN DEFAULT false,
|
||||
position VARCHAR(100),
|
||||
creator VARCHAR(50) DEFAULT NULL,
|
||||
updater VARCHAR(50) DEFAULT NULL,
|
||||
create_time timestamptz NOT NULL DEFAULT now(),
|
||||
update_time timestamptz DEFAULT NULL,
|
||||
delete_time timestamptz DEFAULT NULL,
|
||||
deleted BOOLEAN NOT NULL DEFAULT false,
|
||||
PRIMARY KEY (user_id, dept_id),
|
||||
UNIQUE (optsn),
|
||||
FOREIGN KEY (user_id) REFERENCES sys.tb_sys_user(user_id),
|
||||
FOREIGN KEY (dept_id) REFERENCES sys.tb_sys_dept(dept_id)
|
||||
);
|
||||
|
||||
COMMENT ON TABLE sys.tb_sys_user_dept IS '用户部门关联表';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_dept.is_primary IS '是否主部门';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_dept.position IS '职位';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_user_dept_user ON sys.tb_sys_user_dept(user_id) WHERE deleted = false;
|
||||
CREATE INDEX IF NOT EXISTS idx_user_dept_dept ON sys.tb_sys_user_dept(dept_id) WHERE deleted = false;
|
||||
|
||||
-- 1.3 用户表添加主部门字段
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'sys'
|
||||
AND table_name = 'tb_sys_user'
|
||||
AND column_name = 'primary_dept_id'
|
||||
) THEN
|
||||
ALTER TABLE sys.tb_sys_user ADD COLUMN primary_dept_id VARCHAR(50);
|
||||
COMMENT ON COLUMN sys.tb_sys_user.primary_dept_id IS '主部门ID';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- =============================
|
||||
-- 2. 权限模块优化
|
||||
-- =============================
|
||||
|
||||
-- 2.1 角色表添加排序字段
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'sys'
|
||||
AND table_name = 'tb_sys_role'
|
||||
AND column_name = 'order_num'
|
||||
) THEN
|
||||
ALTER TABLE sys.tb_sys_role ADD COLUMN order_num INTEGER DEFAULT 0;
|
||||
COMMENT ON COLUMN sys.tb_sys_role.order_num IS '排序号';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- 2.2 权限表添加权限类型字段
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'sys'
|
||||
AND table_name = 'tb_sys_permission'
|
||||
AND column_name = 'permission_type'
|
||||
) THEN
|
||||
ALTER TABLE sys.tb_sys_permission ADD COLUMN permission_type VARCHAR(20) DEFAULT 'action';
|
||||
COMMENT ON COLUMN sys.tb_sys_permission.permission_type IS '权限类型:action-操作权限/data-数据权限/menu-菜单权限';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- =============================
|
||||
-- 3. 文件模块扩展
|
||||
-- =============================
|
||||
|
||||
-- 3.1 文件表添加版本管理字段
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'file'
|
||||
AND table_name = 'tb_sys_file'
|
||||
AND column_name = 'version'
|
||||
) THEN
|
||||
ALTER TABLE file.tb_sys_file
|
||||
ADD COLUMN version VARCHAR(20) DEFAULT '1.0',
|
||||
ADD COLUMN parent_file_id VARCHAR(50),
|
||||
ADD COLUMN is_latest BOOLEAN DEFAULT true;
|
||||
|
||||
COMMENT ON COLUMN file.tb_sys_file.version IS '文件版本号';
|
||||
COMMENT ON COLUMN file.tb_sys_file.parent_file_id IS '父文件ID(版本链)';
|
||||
COMMENT ON COLUMN file.tb_sys_file.is_latest IS '是否最新版本';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- 3.2 文件表添加分类和标签
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'file'
|
||||
AND table_name = 'tb_sys_file'
|
||||
AND column_name = 'category'
|
||||
) THEN
|
||||
ALTER TABLE file.tb_sys_file
|
||||
ADD COLUMN category VARCHAR(100),
|
||||
ADD COLUMN tags TEXT[],
|
||||
ADD COLUMN metadata JSONB;
|
||||
|
||||
COMMENT ON COLUMN file.tb_sys_file.category IS '文件分类';
|
||||
COMMENT ON COLUMN file.tb_sys_file.tags IS '文件标签数组';
|
||||
COMMENT ON COLUMN file.tb_sys_file.metadata IS '文件元数据';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- 3.3 创建文件关联表
|
||||
CREATE TABLE IF NOT EXISTS file.tb_file_relation (
|
||||
optsn VARCHAR(50) NOT NULL,
|
||||
relation_id VARCHAR(50) NOT NULL,
|
||||
file_id VARCHAR(50) NOT NULL,
|
||||
object_type VARCHAR(50) NOT NULL,
|
||||
object_id VARCHAR(50) NOT NULL,
|
||||
relation_type VARCHAR(30) DEFAULT 'attachment',
|
||||
order_num INTEGER DEFAULT 0,
|
||||
creator VARCHAR(50) DEFAULT NULL,
|
||||
updater VARCHAR(50) DEFAULT NULL,
|
||||
create_time timestamptz NOT NULL DEFAULT now(),
|
||||
update_time timestamptz DEFAULT NULL,
|
||||
delete_time timestamptz DEFAULT NULL,
|
||||
deleted BOOLEAN NOT NULL DEFAULT false,
|
||||
PRIMARY KEY (relation_id),
|
||||
UNIQUE (optsn),
|
||||
FOREIGN KEY (file_id) REFERENCES file.tb_sys_file(file_id)
|
||||
);
|
||||
|
||||
COMMENT ON TABLE file.tb_file_relation IS '文件关联表';
|
||||
COMMENT ON COLUMN file.tb_file_relation.object_type IS '对象类型:bidding_project/ticket/document等';
|
||||
COMMENT ON COLUMN file.tb_file_relation.object_id IS '对象ID';
|
||||
COMMENT ON COLUMN file.tb_file_relation.relation_type IS '关联类型:attachment-附件/avatar-头像/banner-横幅';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_file_relation_object
|
||||
ON file.tb_file_relation(object_type, object_id) WHERE deleted = false;
|
||||
CREATE INDEX IF NOT EXISTS idx_file_relation_file
|
||||
ON file.tb_file_relation(file_id) WHERE deleted = false;
|
||||
|
||||
-- =============================
|
||||
-- 4. 消息模块增强
|
||||
-- =============================
|
||||
|
||||
-- 4.1 创建消息模板表
|
||||
CREATE TABLE IF NOT EXISTS message.tb_message_template (
|
||||
optsn VARCHAR(50) NOT NULL,
|
||||
template_id VARCHAR(50) NOT NULL,
|
||||
template_code VARCHAR(100) NOT NULL,
|
||||
template_name VARCHAR(255) NOT NULL,
|
||||
template_type VARCHAR(30) NOT NULL,
|
||||
title_template TEXT,
|
||||
content_template TEXT NOT NULL,
|
||||
variables JSONB,
|
||||
dept_path VARCHAR(255) DEFAULT NULL,
|
||||
creator VARCHAR(50) DEFAULT NULL,
|
||||
updater VARCHAR(50) DEFAULT NULL,
|
||||
create_time timestamptz NOT NULL DEFAULT now(),
|
||||
update_time timestamptz DEFAULT NULL,
|
||||
delete_time timestamptz DEFAULT NULL,
|
||||
deleted BOOLEAN NOT NULL DEFAULT false,
|
||||
PRIMARY KEY (template_id),
|
||||
UNIQUE (optsn),
|
||||
UNIQUE (template_code)
|
||||
);
|
||||
|
||||
COMMENT ON TABLE message.tb_message_template IS '消息模板表';
|
||||
COMMENT ON COLUMN message.tb_message_template.template_type IS '模板类型:system-系统/business-业务';
|
||||
COMMENT ON COLUMN message.tb_message_template.variables IS '模板变量定义';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_template_type
|
||||
ON message.tb_message_template(template_type) WHERE deleted = false;
|
||||
|
||||
-- =============================
|
||||
-- 5. 日志模块优化
|
||||
-- =============================
|
||||
|
||||
-- 5.1 日志表添加trace_id用于链路追踪
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'log'
|
||||
AND table_name = 'tb_sys_log'
|
||||
AND column_name = 'trace_id'
|
||||
) THEN
|
||||
ALTER TABLE log.tb_sys_log
|
||||
ADD COLUMN trace_id VARCHAR(50),
|
||||
ADD COLUMN span_id VARCHAR(50),
|
||||
ADD COLUMN parent_span_id VARCHAR(50);
|
||||
|
||||
COMMENT ON COLUMN log.tb_sys_log.trace_id IS '追踪ID(用于分布式追踪)';
|
||||
COMMENT ON COLUMN log.tb_sys_log.span_id IS '跨度ID';
|
||||
COMMENT ON COLUMN log.tb_sys_log.parent_span_id IS '父跨度ID';
|
||||
|
||||
CREATE INDEX idx_log_trace ON log.tb_sys_log(trace_id) WHERE trace_id IS NOT NULL;
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- =============================
|
||||
-- 6. 全文搜索索引
|
||||
-- =============================
|
||||
|
||||
-- 6.1 为知识文档标题创建全文搜索索引
|
||||
CREATE INDEX IF NOT EXISTS idx_knowledge_doc_title_trgm
|
||||
ON knowledge.tb_knowledge_document USING gin(title gin_trgm_ops)
|
||||
WHERE deleted = false;
|
||||
|
||||
-- 6.2 为招标项目名称创建全文搜索索引
|
||||
CREATE INDEX IF NOT EXISTS idx_project_name_trgm
|
||||
ON bidding.tb_bidding_project USING gin(project_name gin_trgm_ops)
|
||||
WHERE deleted = false;
|
||||
|
||||
-- 6.3 为客户姓名创建全文搜索索引
|
||||
CREATE INDEX IF NOT EXISTS idx_customer_name_trgm
|
||||
ON customer_service.tb_customer USING gin(customer_name gin_trgm_ops)
|
||||
WHERE deleted = false;
|
||||
|
||||
-- =============================
|
||||
-- 7. JSONB字段优化索引
|
||||
-- =============================
|
||||
|
||||
-- 7.1 智能体配置JSONB索引
|
||||
CREATE INDEX IF NOT EXISTS idx_agent_model_config_gin
|
||||
ON agent.tb_agent USING gin(model_config)
|
||||
WHERE deleted = false;
|
||||
|
||||
-- 7.2 工单元数据JSONB索引
|
||||
CREATE INDEX IF NOT EXISTS idx_ticket_metadata_gin
|
||||
ON customer_service.tb_ticket USING gin(metadata)
|
||||
WHERE deleted = false;
|
||||
|
||||
-- =============================
|
||||
-- 8. 性能优化视图
|
||||
-- =============================
|
||||
|
||||
-- 8.1 用户完整权限视图(包含ACL)
|
||||
CREATE OR REPLACE VIEW sys.v_user_full_permissions AS
|
||||
WITH user_roles AS (
|
||||
-- 用户直接拥有的角色权限
|
||||
SELECT DISTINCT
|
||||
ur.user_id,
|
||||
p.permission_id,
|
||||
p.code AS permission_code,
|
||||
p.name AS permission_name,
|
||||
'role' AS source_type,
|
||||
r.role_id AS source_id
|
||||
FROM sys.tb_sys_user_role ur
|
||||
JOIN sys.tb_sys_role r ON ur.role_id = r.role_id
|
||||
JOIN sys.tb_sys_role_permission rp ON r.role_id = rp.role_id
|
||||
JOIN sys.tb_sys_permission p ON rp.permission_id = p.permission_id
|
||||
WHERE ur.deleted = false
|
||||
AND r.deleted = false
|
||||
AND rp.deleted = false
|
||||
AND p.deleted = false
|
||||
),
|
||||
user_acls AS (
|
||||
-- 用户的ACL权限
|
||||
SELECT DISTINCT
|
||||
principal_id AS user_id,
|
||||
object_type || ':' || object_id AS permission_id,
|
||||
object_type || '_' ||
|
||||
CASE
|
||||
WHEN (permission & 1) = 1 THEN 'read'
|
||||
WHEN (permission & 2) = 2 THEN 'write'
|
||||
WHEN (permission & 4) = 4 THEN 'exec'
|
||||
END AS permission_code,
|
||||
'ACL permission on ' || object_type AS permission_name,
|
||||
'acl' AS source_type,
|
||||
acl_id AS source_id
|
||||
FROM sys.tb_sys_acl
|
||||
WHERE principal_type = 'user'
|
||||
AND allow = true
|
||||
AND deleted = false
|
||||
)
|
||||
SELECT * FROM user_roles
|
||||
UNION ALL
|
||||
SELECT * FROM user_acls;
|
||||
|
||||
COMMENT ON VIEW sys.v_user_full_permissions IS '用户完整权限视图(包含角色权限和ACL权限)';
|
||||
|
||||
-- 8.2 智能体实时状态视图
|
||||
CREATE OR REPLACE VIEW agent.v_agent_realtime_status AS
|
||||
SELECT
|
||||
a.agent_id,
|
||||
a.agent_name,
|
||||
a.agent_type,
|
||||
a.status,
|
||||
COUNT(DISTINCT s.session_id) FILTER (WHERE s.session_status = 'active') AS active_sessions,
|
||||
COUNT(DISTINCT s.user_id) FILTER (WHERE s.start_time > now() - interval '24 hours') AS daily_users,
|
||||
COALESCE(SUM(s.message_count) FILTER (WHERE s.start_time > now() - interval '1 hour'), 0) AS hourly_messages,
|
||||
COALESCE(AVG(r.rating) FILTER (WHERE r.create_time > now() - interval '7 days'), 0) AS weekly_avg_rating
|
||||
FROM agent.tb_agent a
|
||||
LEFT JOIN agent.tb_agent_session s ON a.agent_id = s.agent_id AND s.deleted = false
|
||||
LEFT JOIN agent.tb_agent_rating r ON a.agent_id = r.agent_id AND r.deleted = false
|
||||
WHERE a.deleted = false
|
||||
GROUP BY a.agent_id, a.agent_name, a.agent_type, a.status;
|
||||
|
||||
COMMENT ON VIEW agent.v_agent_realtime_status IS '智能体实时状态视图';
|
||||
|
||||
-- 8.3 工单处理效率视图
|
||||
CREATE OR REPLACE VIEW customer_service.v_ticket_efficiency AS
|
||||
SELECT
|
||||
DATE(t.create_time) AS stat_date,
|
||||
t.ticket_type,
|
||||
t.priority,
|
||||
COUNT(*) AS total_tickets,
|
||||
COUNT(*) FILTER (WHERE t.ticket_status = 'resolved') AS resolved_tickets,
|
||||
COUNT(*) FILTER (WHERE t.is_overdue) AS overdue_tickets,
|
||||
AVG(EXTRACT(EPOCH FROM (t.response_time - t.create_time))/60) AS avg_response_minutes,
|
||||
AVG(EXTRACT(EPOCH FROM (t.resolution_time - t.create_time))/3600) FILTER (WHERE t.resolution_time IS NOT NULL) AS avg_resolution_hours,
|
||||
AVG(t.customer_rating) FILTER (WHERE t.customer_rating IS NOT NULL) AS avg_rating
|
||||
FROM customer_service.tb_ticket t
|
||||
WHERE t.deleted = false
|
||||
AND t.create_time > now() - interval '90 days'
|
||||
GROUP BY DATE(t.create_time), t.ticket_type, t.priority;
|
||||
|
||||
COMMENT ON VIEW customer_service.v_ticket_efficiency IS '工单处理效率统计视图';
|
||||
|
||||
-- =============================
|
||||
-- 9. 审计触发器增强
|
||||
-- =============================
|
||||
|
||||
-- 9.1 创建审计日志函数
|
||||
CREATE OR REPLACE FUNCTION public.audit_trigger_func()
|
||||
RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
audit_data JSONB;
|
||||
BEGIN
|
||||
IF (TG_OP = 'DELETE') THEN
|
||||
audit_data := jsonb_build_object(
|
||||
'operation', 'DELETE',
|
||||
'table', TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME,
|
||||
'old_data', row_to_json(OLD)
|
||||
);
|
||||
|
||||
INSERT INTO log.tb_sys_log (
|
||||
optsn, log_id, type, level, module, message, data, creator
|
||||
) VALUES (
|
||||
'AUDIT_' || gen_random_uuid()::text,
|
||||
gen_random_uuid()::text,
|
||||
'audit',
|
||||
'info',
|
||||
TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME,
|
||||
'Record deleted',
|
||||
audit_data,
|
||||
COALESCE(current_setting('app.current_user_id', true), 'system')
|
||||
);
|
||||
RETURN OLD;
|
||||
|
||||
ELSIF (TG_OP = 'UPDATE') THEN
|
||||
audit_data := jsonb_build_object(
|
||||
'operation', 'UPDATE',
|
||||
'table', TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME,
|
||||
'old_data', row_to_json(OLD),
|
||||
'new_data', row_to_json(NEW)
|
||||
);
|
||||
|
||||
INSERT INTO log.tb_sys_log (
|
||||
optsn, log_id, type, level, module, message, data, creator
|
||||
) VALUES (
|
||||
'AUDIT_' || gen_random_uuid()::text,
|
||||
gen_random_uuid()::text,
|
||||
'audit',
|
||||
'info',
|
||||
TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME,
|
||||
'Record updated',
|
||||
audit_data,
|
||||
COALESCE(current_setting('app.current_user_id', true), 'system')
|
||||
);
|
||||
RETURN NEW;
|
||||
|
||||
ELSIF (TG_OP = 'INSERT') THEN
|
||||
audit_data := jsonb_build_object(
|
||||
'operation', 'INSERT',
|
||||
'table', TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME,
|
||||
'new_data', row_to_json(NEW)
|
||||
);
|
||||
|
||||
INSERT INTO log.tb_sys_log (
|
||||
optsn, log_id, type, level, module, message, data, creator
|
||||
) VALUES (
|
||||
'AUDIT_' || gen_random_uuid()::text,
|
||||
gen_random_uuid()::text,
|
||||
'audit',
|
||||
'info',
|
||||
TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME,
|
||||
'Record created',
|
||||
audit_data,
|
||||
COALESCE(current_setting('app.current_user_id', true), 'system')
|
||||
);
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION public.audit_trigger_func() IS '审计日志触发器函数';
|
||||
|
||||
-- =============================
|
||||
-- 10. 数据归档函数
|
||||
-- =============================
|
||||
|
||||
-- 10.1 创建日志归档函数
|
||||
CREATE OR REPLACE FUNCTION public.archive_old_logs(
|
||||
p_months_to_keep INTEGER DEFAULT 6
|
||||
)
|
||||
RETURNS TABLE(
|
||||
archived_count INTEGER,
|
||||
deleted_count INTEGER
|
||||
) AS $$
|
||||
DECLARE
|
||||
v_cutoff_date TIMESTAMPTZ;
|
||||
v_archived INTEGER := 0;
|
||||
v_deleted INTEGER := 0;
|
||||
BEGIN
|
||||
v_cutoff_date := now() - (p_months_to_keep || ' months')::INTERVAL;
|
||||
|
||||
-- 归档系统日志
|
||||
CREATE TABLE IF NOT EXISTS log.tb_sys_log_archived (LIKE log.tb_sys_log INCLUDING ALL);
|
||||
|
||||
WITH moved_rows AS (
|
||||
INSERT INTO log.tb_sys_log_archived
|
||||
SELECT * FROM log.tb_sys_log
|
||||
WHERE create_time < v_cutoff_date
|
||||
RETURNING *
|
||||
)
|
||||
SELECT COUNT(*) INTO v_archived FROM moved_rows;
|
||||
|
||||
DELETE FROM log.tb_sys_log
|
||||
WHERE create_time < v_cutoff_date;
|
||||
|
||||
GET DIAGNOSTICS v_deleted = ROW_COUNT;
|
||||
|
||||
RETURN QUERY SELECT v_archived, v_deleted;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION public.archive_old_logs IS '归档旧日志数据';
|
||||
|
||||
-- 10.2 创建API调用日志归档函数
|
||||
CREATE OR REPLACE FUNCTION agent.archive_api_logs(
|
||||
p_months_to_keep INTEGER DEFAULT 3
|
||||
)
|
||||
RETURNS INTEGER AS $$
|
||||
DECLARE
|
||||
v_cutoff_date TIMESTAMPTZ;
|
||||
v_archived INTEGER;
|
||||
BEGIN
|
||||
v_cutoff_date := now() - (p_months_to_keep || ' months')::INTERVAL;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS agent.tb_api_call_log_archived (LIKE agent.tb_api_call_log INCLUDING ALL);
|
||||
|
||||
WITH moved_rows AS (
|
||||
INSERT INTO agent.tb_api_call_log_archived
|
||||
SELECT * FROM agent.tb_api_call_log
|
||||
WHERE create_time < v_cutoff_date
|
||||
RETURNING *
|
||||
)
|
||||
SELECT COUNT(*) INTO v_archived FROM moved_rows;
|
||||
|
||||
DELETE FROM agent.tb_api_call_log
|
||||
WHERE create_time < v_cutoff_date;
|
||||
|
||||
RETURN v_archived;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION agent.archive_api_logs IS '归档旧API调用日志';
|
||||
|
||||
-- =============================
|
||||
-- 11. 性能监控函数
|
||||
-- =============================
|
||||
|
||||
-- 11.1 表膨胀检查函数
|
||||
CREATE OR REPLACE FUNCTION public.check_table_bloat()
|
||||
RETURNS TABLE(
|
||||
schemaname TEXT,
|
||||
tablename TEXT,
|
||||
table_size_mb NUMERIC,
|
||||
bloat_size_mb NUMERIC,
|
||||
bloat_ratio NUMERIC
|
||||
) AS $$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
s.schemaname::TEXT,
|
||||
s.tablename::TEXT,
|
||||
ROUND(pg_total_relation_size(s.schemaname || '.' || s.tablename)::NUMERIC / 1024 / 1024, 2) AS table_size_mb,
|
||||
ROUND((pg_total_relation_size(s.schemaname || '.' || s.tablename) - pg_relation_size(s.schemaname || '.' || s.tablename))::NUMERIC / 1024 / 1024, 2) AS bloat_size_mb,
|
||||
ROUND(((pg_total_relation_size(s.schemaname || '.' || s.tablename) - pg_relation_size(s.schemaname || '.' || s.tablename))::NUMERIC / NULLIF(pg_total_relation_size(s.schemaname || '.' || s.tablename), 0) * 100), 2) AS bloat_ratio
|
||||
FROM pg_tables s
|
||||
WHERE s.schemaname IN ('sys', 'file', 'message', 'log', 'config', 'knowledge', 'bidding', 'customer_service', 'agent')
|
||||
ORDER BY pg_total_relation_size(s.schemaname || '.' || s.tablename) DESC;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION public.check_table_bloat IS '检查表膨胀情况';
|
||||
|
||||
-- =============================
|
||||
-- 执行完成提示
|
||||
-- =============================
|
||||
DO $$
|
||||
BEGIN
|
||||
RAISE NOTICE '==============================';
|
||||
RAISE NOTICE '数据库优化补丁执行完成!';
|
||||
RAISE NOTICE '==============================';
|
||||
RAISE NOTICE '已完成以下优化:';
|
||||
RAISE NOTICE '1. 用户模块:移除敏感字段、添加部门关联';
|
||||
RAISE NOTICE '2. 权限模块:添加排序和类型字段';
|
||||
RAISE NOTICE '3. 文件模块:版本管理、分类标签、关联表';
|
||||
RAISE NOTICE '4. 消息模块:消息模板表';
|
||||
RAISE NOTICE '5. 日志模块:链路追踪支持';
|
||||
RAISE NOTICE '6. 全文搜索:添加GIN索引';
|
||||
RAISE NOTICE '7. JSONB优化:添加GIN索引';
|
||||
RAISE NOTICE '8. 性能视图:用户权限、智能体状态、工单效率';
|
||||
RAISE NOTICE '9. 审计增强:完整审计触发器';
|
||||
RAISE NOTICE '10. 数据归档:日志和API调用归档函数';
|
||||
RAISE NOTICE '11. 监控工具:表膨胀检查函数';
|
||||
RAISE NOTICE '==============================';
|
||||
END $$;
|
||||
Reference in New Issue
Block a user