how to search / find through all databases, tables, columns in MySQL

What will you do if one day some one ask you to find single string in all databases, all tables and in all columns, In MySQL Database? This article presents a practical solution to search across all your MySQL databases, tables, and columns using stored procedures, making the process re-usable and straightforward.

I prepared the dynamic stored procedure to perform the whole MySQL database search.

Step-by-Step Guide to perform MySQL database search

Here is the idea for how to search through all databases – tables – columns:

  1. Create a table for storing output.
  2. Loop through information_schema database’s COLUMNS table to obtain alldatabases, table and column names.
  3. Execute a count(*) query on database.table for each column with appropriate search string in where condition.
  4. If count(*) > 0, that perticular column has the search term.
  5. Insert that triplet (database name, table name, column name) in to a table.
  6. Select * from table to view respective database,table and column names having the search term.

MySQL database search – all columns, tables and databases.

Below is a MySQL database search stored procedure that enables searching through all fields of all databases:

## Procedure for search in all fields of all databases
DELIMITER $$

#Script to loop through all tables using Information_Schema
DROP PROCEDURE IF EXISTS get_table $$
CREATE PROCEDURE get_table(in_search varchar(50))
READS SQL DATA
BEGIN

DECLARE trunc_cmd VARCHAR(50);
DECLARE search_string VARCHAR(250);
DECLARE db,tbl,clmn CHAR(250);
DECLARE done INT DEFAULT 0;
DECLARE COUNTER INT;
DECLARE table_cur CURSOR FOR
SELECT concat('SELECT COUNT(*) INTO @CNT_VALUE FROM `',table_schema,'`.`',table_name,'` WHERE `', column_name,'` REGEXP "',in_search,'"') ,table_schema,table_name,column_name FROM information_schema.COLUMNS WHERE TABLE_SCHEMA NOT IN ('mysql','information_schema', 'performance_schema', 'sys');

DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=1;

#Drop and recreate table for storing the data for new search.
PREPARE trunc_cmd FROM "DROP TABLE IF EXISTS temp_details;";
EXECUTE trunc_cmd ;

CREATE TEMPORARY TABLE temp_details (
db varchar(250),
tbl varchar(250),
clmn varchar(250)
);


OPEN table_cur;

table_loop:LOOP
FETCH table_cur INTO search_string,db,tbl,clmn;
#Executing the search
SET @search_string = search_string;
#SELECT  search_string;
PREPARE search_string FROM @search_string;
EXECUTE search_string;
SET COUNTER = @CNT_VALUE;
#SELECT COUNTER;
IF COUNTER>0 THEN
# Inserting required results from search to table
SET SESSION SQL_MODE='';
INSERT INTO temp_details (db,tbl,clmn) VALUES(db,tbl,clmn);
END IF;
IF done=1 THEN
LEAVE table_loop;

END IF;
END LOOP;
CLOSE table_cur;

#Finally Show Results
SELECT  * FROM temp_details;
END $$
DELIMITER ;



No wonder you will find the variable naming has not been taken care of; but its forgivable!

Download the code here: find in all databases-tables.sql

Well this thing worked for me in 5.0.83-community-nt-log on windows machine. This MySQL database search procedure is also been tested against MySQL 8. I dropped idea of creating temporary table through procedure to store and display results considering a bug and deciding to adopt the easy way out though its very old.

Conclusion

Searching for a specific string across numerous databases, tables, and columns in MySQL can be a complex task. However, by implementing the provided stored procedure, you can efficiently and comprehensively perfom MySQL database search. This approach enhances reusability, saves time, and ensures accurate results, making it an invaluable tool for database administrators and developers.

14 comments
Leave a Reply to sham Cancel reply

Your email address will not be published. Required fields are marked *