Skip to content

Commit 7390574

Browse files
committed
Delete empty tables from an given database.
1 parent 7a97314 commit 7390574

File tree

1 file changed

+45
-0
lines changed

1 file changed

+45
-0
lines changed
Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
-- https://stackoverflow.com/questions/190776/how-to-have-dynamic-sql-in-mysql-stored-procedure
2+
-- https://dba.stackexchange.com/questions/99298/how-do-i-perform-a-query-on-a-dynamic-list-of-tables
3+
-- https://stackoverflow.com/questions/8393550/mysql-drop-tables-with-wildcard-using-only-sql-statement
4+
-- https://www.w3schools.com/sql/func_mysql_replace.asp
5+
-- https://stackoverflow.com/questions/1524858/create-table-variable-in-mysql
6+
7+
DROP PROCEDURE IF EXISTS deleting_empty_tables;
8+
DELIMITER ;;
9+
10+
CREATE PROCEDURE deleting_empty_tables(IN db_name varchar(255))
11+
12+
BEGIN
13+
14+
DECLARE n INT DEFAULT 0;
15+
DECLARE i INT DEFAULT 1;
16+
17+
DROP TABLE IF EXISTS empty_tables;
18+
19+
CREATE TEMPORARY TABLE empty_tables(
20+
table_name varchar(255)
21+
);
22+
23+
INSERT INTO empty_tables
24+
SELECT t.table_name
25+
FROM INFORMATION_SCHEMA.TABLES t
26+
WHERE t.table_schema = db_name AND t.table_rows = 0;
27+
28+
SELECT COUNT(*) FROM empty_tables INTO n;
29+
30+
WHILE i<=n DO
31+
SET @table_name = (SELECT et.table_name FROM empty_tables et LIMIT 1);
32+
SET @qr = (SELECT 'DROP TABLE db.tb');
33+
SET @qr = REPLACE(@qr,'db',db_name);
34+
SET @qr = REPLACE(@qr,'tb',@table_name);
35+
PREPARE statement FROM @qr;
36+
EXECUTE statement;
37+
DEALLOCATE PREPARE statement;
38+
DELETE FROM empty_tables WHERE table_name = @table_name;
39+
END WHILE;
40+
41+
DROP TABLE empty_tables;
42+
43+
END;;
44+
45+
DELIMITER ;

0 commit comments

Comments
 (0)