DROP all system tables
Posted: Fri Jan 15, 2021 7:46 am
Created a Wiki Article on the topic.
Multi table DROP based on pattern of table name is not available in MySQL. The workaround is:
On next login, nubuilder4.sql is used to populate it with the System Tables. Useful when you want all developmental work reset to new code from the repo whilst retaining the user tables and their data.
Multi table DROP based on pattern of table name is not available in MySQL. The workaround is:
Code: Select all
SET SESSION group_concat_max_len = 1000000;
SET @schema:='nubuilder4';
SET @string:='zzzzsys_%';
SELECT CONCAT ('DROP TABLE ',GROUP_CONCAT(DISTINCT CONCAT(@schema,'.',TABLE_NAME) SEPARATOR ", "),';')
INTO @droptool
FROM information_schema.TABLES
WHERE @schema = DATABASE() AND TABLE_TYPE="BASE TABLE"
AND TABLE_NAME LIKE @string;
SELECT @droptool;
PREPARE stmt FROM @droptool;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;