# 开发中使用的存储过程 ## 统计一下,数据库中哪些表中有site_id字段或者store_id字段,而且表中是有数据的 ```sql -- 检查符合条件的表 DELIMITER $$ CREATE PROCEDURE CheckTablesWithHasData() BEGIN DECLARE done INT DEFAULT FALSE; DECLARE tbl_name VARCHAR(255); DECLARE cur CURSOR FOR SELECT DISTINCT TABLE_NAME FROM information_schema.COLUMNS WHERE COLUMN_NAME IN ('site_id', 'store_id') AND TABLE_SCHEMA = DATABASE(); -- 使用当前数据库 DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; CREATE TEMPORARY TABLE tmp_results (table_name VARCHAR(255)); OPEN cur; read_loop: LOOP FETCH cur INTO tbl_name; IF done THEN LEAVE read_loop; END IF; SET @sql = CONCAT('INSERT INTO tmp_results SELECT ''', tbl_name, ''' FROM ', tbl_name, ' HAVING COUNT(*) > 0'); PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; END LOOP; CLOSE cur; SELECT table_name FROM tmp_results; DROP TEMPORARY TABLE tmp_results; END$$ DELIMITER ; -- 执行 CALL CheckTablesWithHasData(); --- 结果 +-----------------+ | table_name | +-----------------+ | t_order_info | | t_order_item | | t_order_payment | | t_order_refund | +-----------------+ ``` ## 统计一下,数据库中哪些表中是有数据的 ```sql -- 检查符合条件的表 DELIMITER $$ CREATE PROCEDURE CheckTablesIsNotEmpty() BEGIN DECLARE done INT DEFAULT FALSE; DECLARE tbl_name VARCHAR(255); DECLARE cur CURSOR FOR SELECT DISTINCT TABLE_NAME FROM information_schema.COLUMNS WHERE TABLE_SCHEMA = DATABASE(); -- 使用当前数据库 DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; CREATE TEMPORARY TABLE tmp_results (table_name VARCHAR(255)); OPEN cur; read_loop: LOOP FETCH cur INTO tbl_name; IF done THEN LEAVE read_loop; END IF; SET @sql = CONCAT('INSERT INTO tmp_results SELECT ''', tbl_name, ''' FROM ', tbl_name, ' HAVING COUNT(*) > 0'); PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; END LOOP; CLOSE cur; SELECT table_name FROM tmp_results; DROP TEMPORARY TABLE tmp_results; END$$ DELIMITER ; -- 执行 CALL CheckTablesIsNotEmpty(); ``` ## 对于空表或者无数据表,重置 AUTO_INCREMENT ```sql -- 定义存储过程 DELIMITER $$ CREATE PROCEDURE ResetAutoIncrementForEmptyTables() BEGIN DECLARE done INT DEFAULT FALSE; DECLARE tbl_name VARCHAR(255); DECLARE cnt BIGINT; -- 声明游标:获取所有表名 DECLARE cur CURSOR FOR SELECT DISTINCT c.TABLE_NAME FROM information_schema.COLUMNS c INNER JOIN information_schema.TABLES t ON c.TABLE_SCHEMA = t.TABLE_SCHEMA AND c.TABLE_NAME = t.TABLE_NAME WHERE c.TABLE_SCHEMA = DATABASE() AND t.TABLE_TYPE = 'BASE TABLE'; -- 排除视图 DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; OPEN cur; read_loop: LOOP FETCH cur INTO tbl_name; IF done THEN LEAVE read_loop; END IF; -- 动态获取行数 SET @sql = CONCAT('SELECT COUNT(*) INTO @cnt FROM `', tbl_name, '`'); PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- 如果为空,重置 AUTO_INCREMENT IF @cnt = 0 THEN SET @reset_sql = CONCAT('ALTER TABLE `', tbl_name, '` AUTO_INCREMENT = 1'); PREPARE reset_stmt FROM @reset_sql; EXECUTE reset_stmt; DEALLOCATE PREPARE reset_stmt; SELECT CONCAT('Reset AUTO_INCREMENT for table: ', tbl_name) AS message; END IF; END LOOP; CLOSE cur; END$$ DELIMITER ; -- 执行 CALL ResetAutoIncrementForEmptyTables(); ``` ## 数据重置到初始化状态 ### 1. 删除数据,保留表结构,当表中有site_id字段时,只删除site_id不为0的数据 ```sql -- 定义存储过程 -- 增强版数据库重置脚本 -- 支持 MySQL/PostgreSQL/SQL Server DELIMITER $$ DROP PROCEDURE IF EXISTS reset_tables_has_site_id_where; CREATE PROCEDURE reset_tables_has_site_id_where( IN p_preserve_site_zero BOOLEAN, -- 是否保留 site_id = 0 的数据 IN p_dry_run BOOLEAN, -- 是否试运行(不实际执行) IN p_exclude_tables TEXT -- 排除的表列表,逗号分隔 ) BEGIN DECLARE v_done INT DEFAULT FALSE; DECLARE v_table_name VARCHAR(255); DECLARE v_has_site_id INT DEFAULT 0; DECLARE v_table_count INT DEFAULT 0; DECLARE v_processed_count INT DEFAULT 0; DECLARE v_skipped_count INT DEFAULT 0; DECLARE v_error_count INT DEFAULT 0; DECLARE v_no_site_id_tables TEXT DEFAULT ''; DECLARE v_excluded_tables TEXT DEFAULT ''; -- 游标声明 DECLARE table_cursor CURSOR FOR SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = DATABASE() AND TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME NOT IN ( 'sys_operation_log', 'sys_login_log', 'system_parameters' -- 系统表默认排除 ) ORDER BY TABLE_NAME; DECLARE CONTINUE HANDLER FOR NOT FOUND SET v_done = TRUE; -- 创建详细的日志表 DROP TEMPORARY TABLE IF EXISTS reset_operation_log; CREATE TEMPORARY TABLE reset_operation_log ( id INT AUTO_INCREMENT PRIMARY KEY, log_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP, table_name VARCHAR(255) NOT NULL, action_type ENUM('CLEARED', 'SKIPPED', 'ERROR', 'EXCLUDED') NOT NULL, records_affected INT DEFAULT 0, sql_statement TEXT, error_message TEXT, execution_time_ms INT DEFAULT 0 ); -- 开始事务(确保原子性) START TRANSACTION; OPEN table_cursor; process_tables: LOOP FETCH table_cursor INTO v_table_name; IF v_done THEN LEAVE process_tables; END IF; SET v_table_count = v_table_count + 1; -- 检查是否在排除列表中 IF FIND_IN_SET(v_table_name, p_exclude_tables) > 0 OR FIND_IN_SET(v_table_name, v_excluded_tables) > 0 THEN INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement) VALUES (v_table_name, 'EXCLUDED', 0, '表在排除列表中,跳过处理'); SET v_skipped_count = v_skipped_count + 1; ITERATE process_tables; END IF; -- 检查表是否有 site_id 字段 SELECT COUNT(*) INTO v_has_site_id FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = v_table_name AND COLUMN_NAME = 'site_id'; SET @start_time = UNIX_TIMESTAMP(NOW(3)) * 1000; IF v_has_site_id > 0 THEN -- 构建动态SQL IF p_preserve_site_zero THEN SET @sql = CONCAT('DELETE FROM `', v_table_name, '` WHERE site_id != 0'); ELSE SET @sql = CONCAT('TRUNCATE TABLE `', v_table_name, '`'); END IF; BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN GET DIAGNOSTICS CONDITION 1 @sqlstate = RETURNED_SQLSTATE, @errmsg = MESSAGE_TEXT; INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement, error_message) VALUES (v_table_name, 'ERROR', 0, @sql, CONCAT(@sqlstate, ' - ', @errmsg)); SET v_error_count = v_error_count + 1; END; IF p_dry_run THEN -- 试运行模式,只记录不执行 INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement) VALUES (v_table_name, 'SKIPPED', 0, CONCAT('试运行: ', @sql)); SET v_skipped_count = v_skipped_count + 1; ELSE -- 实际执行 PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; SET @row_count = ROW_COUNT(); SET @end_time = UNIX_TIMESTAMP(NOW(3)) * 1000; INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement, execution_time_ms) VALUES (v_table_name, 'CLEARED', @row_count, @sql, (@end_time - @start_time)); SET v_processed_count = v_processed_count + 1; END IF; END; ELSE -- 表没有 site_id 字段 SET v_no_site_id_tables = CONCAT_WS(', ', v_no_site_id_tables, v_table_name); INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement) VALUES (v_table_name, 'SKIPPED', 0, '表没有 site_id 字段,跳过处理'); SET v_skipped_count = v_skipped_count + 1; END IF; SET v_has_site_id = 0; END LOOP; CLOSE table_cursor; IF p_dry_run THEN ROLLBACK; -- 试运行模式回滚 SELECT '=== 试运行模式 - 未实际执行任何操作 ===' as notice; ELSE COMMIT; -- 提交事务 SELECT '=== 数据库重置完成 ===' as summary; END IF; -- 生成总结报告 SELECT CONCAT('数据库: ', DATABASE()) as database_info, CONCAT('开始时间: ', DATE_FORMAT(MIN(log_time), '%Y-%m-%d %H:%i:%s')) as start_time, CONCAT('结束时间: ', DATE_FORMAT(MAX(log_time), '%Y-%m-%d %H:%i:%s')) as end_time, CONCAT('总表数: ', v_table_count) as total_tables, CONCAT('已处理表: ', v_processed_count) as processed_tables, CONCAT('跳过表: ', v_skipped_count) as skipped_tables, CONCAT('错误数: ', v_error_count) as error_count, CONCAT('总耗时: ', SUM(execution_time_ms), 'ms') as total_duration FROM reset_operation_log; -- 显示没有 site_id 字段的表 IF v_no_site_id_tables != '' THEN SELECT '以下表没有 site_id 字段,已被跳过:' as warning_title, v_no_site_id_tables as skipped_tables; END IF; -- 显示错误详情 IF v_error_count > 0 THEN SELECT '=== 错误详情 ===' as error_title; SELECT table_name, error_message, sql_statement FROM reset_operation_log WHERE action_type = 'ERROR' ORDER BY log_time; END IF; -- 显示处理详情 SELECT '=== 处理详情 ===' as details_title; SELECT table_name as '表名', CASE action_type WHEN 'CLEARED' THEN '已清空' WHEN 'SKIPPED' THEN '已跳过' WHEN 'ERROR' THEN '错误' WHEN 'EXCLUDED' THEN '已排除' END as '操作状态', records_affected as '影响行数', execution_time_ms as '耗时(ms)', CASE WHEN error_message IS NOT NULL THEN error_message ELSE LEFT(sql_statement, 100) END as '详情' FROM reset_operation_log ORDER BY action_type, table_name; -- 性能统计 SELECT '=== 性能统计 ===' as performance_title; SELECT action_type as '操作类型', COUNT(*) as '表数量', SUM(records_affected) as '总影响行数', AVG(execution_time_ms) as '平均耗时(ms)', SUM(execution_time_ms) as '总耗时(ms)' FROM reset_operation_log GROUP BY action_type; -- 清理 DROP TEMPORARY TABLE IF EXISTS reset_operation_log; END $$ DELIMITER ; -- 使用示例 -- 试运行(不实际执行) CALL reset_tables_has_site_id_where(TRUE, TRUE, 'user,config'); -- 实际执行(保留site_id=0的数据,排除user和config表) CALL reset_tables_has_site_id_where(TRUE, FALSE, ''); -- 完全清空所有表(不保留任何数据) CALL reset_tables_has_site_id_where(FALSE, FALSE, ''); ``` ## 删除数据,保留表结构,当表中有store_id字段时,只删除store_id不为0的数据 ```sql DELIMITER $$ DROP PROCEDURE IF EXISTS reset_tables_has_store_id_where; CREATE PROCEDURE reset_tables_has_store_id_where( IN p_preserve_site_zero BOOLEAN, -- 是否保留 store_id = 0 的数据 IN p_dry_run BOOLEAN, -- 是否试运行(不实际执行) IN p_exclude_tables TEXT -- 排除的表列表,逗号分隔 ) BEGIN DECLARE v_done INT DEFAULT FALSE; DECLARE v_table_name VARCHAR(255); DECLARE v_has_store_id INT DEFAULT 0; DECLARE v_table_count INT DEFAULT 0; DECLARE v_processed_count INT DEFAULT 0; DECLARE v_skipped_count INT DEFAULT 0; DECLARE v_error_count INT DEFAULT 0; DECLARE v_no_store_id_tables TEXT DEFAULT ''; DECLARE v_excluded_tables TEXT DEFAULT ''; -- 游标声明 DECLARE table_cursor CURSOR FOR SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = DATABASE() AND TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME NOT IN ( 'sys_operation_log', 'sys_login_log', 'system_parameters' -- 系统表默认排除 ) ORDER BY TABLE_NAME; DECLARE CONTINUE HANDLER FOR NOT FOUND SET v_done = TRUE; -- 创建详细的日志表 DROP TEMPORARY TABLE IF EXISTS reset_operation_log; CREATE TEMPORARY TABLE reset_operation_log ( id INT AUTO_INCREMENT PRIMARY KEY, log_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP, table_name VARCHAR(255) NOT NULL, action_type ENUM('CLEARED', 'SKIPPED', 'ERROR', 'EXCLUDED') NOT NULL, records_affected INT DEFAULT 0, sql_statement TEXT, error_message TEXT, execution_time_ms INT DEFAULT 0 ); -- 开始事务(确保原子性) START TRANSACTION; OPEN table_cursor; process_tables: LOOP FETCH table_cursor INTO v_table_name; IF v_done THEN LEAVE process_tables; END IF; SET v_table_count = v_table_count + 1; -- 检查是否在排除列表中 IF FIND_IN_SET(v_table_name, p_exclude_tables) > 0 OR FIND_IN_SET(v_table_name, v_excluded_tables) > 0 THEN INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement) VALUES (v_table_name, 'EXCLUDED', 0, '表在排除列表中,跳过处理'); SET v_skipped_count = v_skipped_count + 1; ITERATE process_tables; END IF; -- 检查表是否有 store_id 字段 SELECT COUNT(*) INTO v_has_store_id FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = v_table_name AND COLUMN_NAME = 'store_id'; SET @start_time = UNIX_TIMESTAMP(NOW(3)) * 1000; IF v_has_store_id > 0 THEN -- 构建动态SQL IF p_preserve_site_zero THEN SET @sql = CONCAT('DELETE FROM `', v_table_name, '` WHERE store_id != 0'); ELSE SET @sql = CONCAT('TRUNCATE TABLE `', v_table_name, '`'); END IF; BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN GET DIAGNOSTICS CONDITION 1 @sqlstate = RETURNED_SQLSTATE, @errmsg = MESSAGE_TEXT; INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement, error_message) VALUES (v_table_name, 'ERROR', 0, @sql, CONCAT(@sqlstate, ' - ', @errmsg)); SET v_error_count = v_error_count + 1; END; IF p_dry_run THEN -- 试运行模式,只记录不执行 INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement) VALUES (v_table_name, 'SKIPPED', 0, CONCAT('试运行: ', @sql)); SET v_skipped_count = v_skipped_count + 1; ELSE -- 实际执行 PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; SET @row_count = ROW_COUNT(); SET @end_time = UNIX_TIMESTAMP(NOW(3)) * 1000; INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement, execution_time_ms) VALUES (v_table_name, 'CLEARED', @row_count, @sql, (@end_time - @start_time)); SET v_processed_count = v_processed_count + 1; END IF; END; ELSE -- 表没有 store_id 字段 SET v_no_store_id_tables = CONCAT_WS(', ', v_no_store_id_tables, v_table_name); INSERT INTO reset_operation_log (table_name, action_type, records_affected, sql_statement) VALUES (v_table_name, 'SKIPPED', 0, '表没有 store_id 字段,跳过处理'); SET v_skipped_count = v_skipped_count + 1; END IF; SET v_has_store_id = 0; END LOOP; CLOSE table_cursor; IF p_dry_run THEN ROLLBACK; -- 试运行模式回滚 SELECT '=== 试运行模式 - 未实际执行任何操作 ===' as notice; ELSE COMMIT; -- 提交事务 SELECT '=== 数据库重置完成 ===' as summary; END IF; -- 生成总结报告 SELECT CONCAT('数据库: ', DATABASE()) as database_info, CONCAT('开始时间: ', DATE_FORMAT(MIN(log_time), '%Y-%m-%d %H:%i:%s')) as start_time, CONCAT('结束时间: ', DATE_FORMAT(MAX(log_time), '%Y-%m-%d %H:%i:%s')) as end_time, CONCAT('总表数: ', v_table_count) as total_tables, CONCAT('已处理表: ', v_processed_count) as processed_tables, CONCAT('跳过表: ', v_skipped_count) as skipped_tables, CONCAT('错误数: ', v_error_count) as error_count, CONCAT('总耗时: ', SUM(execution_time_ms), 'ms') as total_duration FROM reset_operation_log; -- 显示没有 store_id 字段的表 IF v_no_store_id_tables != '' THEN SELECT '以下表没有 store_id 字段,已被跳过:' as warning_title, v_no_store_id_tables as skipped_tables; END IF; -- 显示错误详情 IF v_error_count > 0 THEN SELECT '=== 错误详情 ===' as error_title; SELECT table_name, error_message, sql_statement FROM reset_operation_log WHERE action_type = 'ERROR' ORDER BY log_time; END IF; -- 显示处理详情 SELECT '=== 处理详情 ===' as details_title; SELECT table_name as '表名', CASE action_type WHEN 'CLEARED' THEN '已清空' WHEN 'SKIPPED' THEN '已跳过' WHEN 'ERROR' THEN '错误' WHEN 'EXCLUDED' THEN '已排除' END as '操作状态', records_affected as '影响行数', execution_time_ms as '耗时(ms)', CASE WHEN error_message IS NOT NULL THEN error_message ELSE LEFT(sql_statement, 100) END as '详情' FROM reset_operation_log ORDER BY action_type, table_name; -- 性能统计 SELECT '=== 性能统计 ===' as performance_title; SELECT action_type as '操作类型', COUNT(*) as '表数量', SUM(records_affected) as '总影响行数', AVG(execution_time_ms) as '平均耗时(ms)', SUM(execution_time_ms) as '总耗时(ms)' FROM reset_operation_log GROUP BY action_type; -- 清理 DROP TEMPORARY TABLE IF EXISTS reset_operation_log; END $$ DELIMITER ; -- 实际执行(保留site_id=0的数据,排除user和config表) CALL reset_tables_has_store_id_where(TRUE, FALSE, ''); ```