├── LICENSE.txt ├── README.md ├── populate.sql └── populate_fk.sql /LICENSE.txt: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Kedar M Vaijanapurkar (kedar@nitty-witty.com) 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # mysql-random-data-generator 2 | This is the easiest MySQL Random Data Generator tool. Load the procedure and execute to auto detect column types and load data in it. 3 | 4 | 5 | # Usage: 6 | 7 | 1) Download random data generator (populate.sql and populate_fk.sql) from website or git. 8 | - http://kedar.nitty-witty.com/blog/generate-random-test-data-for-mysql-using-routines 9 | 10 | 2) Load it to mysql 11 | 12 | ``` 13 | mysql -uUSER -p DBNAME < populate.sql 14 | mysql -uUSER -p DBNAME < populate_fk.sql 15 | ``` 16 | 17 | 3) Use: 18 | ``` 19 | mysql>use DBNAME 20 | 21 | mysql>call populate('sakila','film',100,'N'); 22 | mysql>call populate_fk('sakila','child_table',100,'N'); 23 | ``` 24 | 25 | - Parameters are: `database-name`, `table-name`, `number-of-records`, `debug-mode` 26 | - Setting `debug-mode` as `Y` will print all the insert statements that are being executed. 27 | 28 | -------------------------------------------------------------------------------- /populate.sql: -------------------------------------------------------------------------------- 1 | 2 | DELIMITER $$ 3 | 4 | DROP PROCEDURE IF EXISTS populate $$ 5 | CREATE PROCEDURE populate(in_db varchar(100), in_table varchar(100), in_rows int, in_debug char(1)) 6 | BEGIN 7 | /* 8 | | 9 | | Developer: Kedar Vaijanapurkar 10 | | USAGE: call populate('DATABASE-NAME','TABLE-NAME',NUMBER-OF-ROWS,DEBUG-MODE); 11 | | EXAMPLE: call populate('sakila','film',100,'N'); 12 | | Debug-mode will print an SQL that's executed and iterated. 13 | | The data is being loaded in bulk of 500 rows which is hardcoded for now. 14 | | 15 | */ 16 | 17 | DECLARE col_name VARCHAR(100); 18 | DECLARE col_type VARCHAR(100); 19 | DECLARE col_datatype VARCHAR(100); 20 | DECLARE col_maxlen VARCHAR(100); 21 | DECLARE col_extra VARCHAR(100); 22 | DECLARE col_num_precision VARCHAR(100); 23 | DECLARE col_num_scale VARCHAR(100); 24 | DECLARE func_query VARCHAR(5000); 25 | DECLARE i INT; 26 | DECLARE batch_size INT; 27 | 28 | DECLARE done INT DEFAULT 0; 29 | DECLARE cur_datatype cursor FOR 30 | SELECT column_name,COLUMN_TYPE,data_type,CHARACTER_MAXIMUM_LENGTH,EXTRA,NUMERIC_PRECISION,NUMERIC_SCALE FROM information_schema.columns WHERE table_name=in_table AND table_schema=in_db ORDER BY ORDINAL_POSITION; 31 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; 32 | 33 | 34 | SET func_query=''; 35 | OPEN cur_datatype; 36 | datatype_loop: loop 37 | 38 | FETCH cur_datatype INTO col_name, col_type, col_datatype, col_maxlen, col_extra, col_num_precision, col_num_scale; 39 | #SELECT CONCAT(col_name,"-", col_type,"-", col_datatype,"-", IFNULL(col_maxlen,'NULL'),"-", IFNULL(col_extra,'NULL')) AS VALS; 40 | IF (done = 1) THEN 41 | leave datatype_loop; 42 | END IF; 43 | 44 | CASE 45 | WHEN col_extra='auto_increment' THEN SET func_query=concat(func_query,'NULL, '); 46 | WHEN col_datatype in ('double','int','bigint') THEN SET func_query=concat(func_query,'get_int(), '); 47 | WHEN col_datatype in ('varchar','char') THEN SET func_query=concat(func_query,'get_string(',ifnull(col_maxlen,0),'), '); 48 | WHEN col_datatype in ('tinyint', 'smallint','year') or col_datatype='mediumint' THEN SET func_query=concat(func_query,'get_tinyint(), '); 49 | WHEN col_datatype in ('datetime','timestamp') THEN SET func_query=concat(func_query,'get_datetime(), '); 50 | WHEN col_datatype in ('date') THEN SET func_query=concat(func_query,'get_date(), '); 51 | WHEN col_datatype in ('float', 'decimal') THEN SET func_query=concat(func_query,'get_float(',col_num_precision,',',col_num_scale,'), '); 52 | WHEN col_datatype in ('enum','set') THEN SET func_query=concat(func_query,'get_enum("',col_type,'"), '); 53 | WHEN col_datatype in ('GEOMETRY','POINT','LINESTRING','POLYGON','MULTIPOINT','MULTILINESTRING','MULTIPOLYGON','GEOMETRYCOLLECTION') THEN SET func_query=concat(func_query,'NULL, '); 54 | ELSE SET func_query=concat(func_query,'get_varchar(',ifnull(col_maxlen,0),'), '); 55 | END CASE; 56 | 57 | 58 | end loop datatype_loop; 59 | close cur_datatype; 60 | 61 | SET func_query=trim(trailing ', ' FROM func_query); 62 | SET @func_query=concat("INSERT INTO ", in_db,".",in_table," VALUES (",func_query,");"); 63 | SET @func_query=concat("INSERT IGNORE INTO ", in_db,".",in_table," VALUES (",func_query,")"); 64 | 65 | SET batch_size = 500; 66 | while batch_size > 0 DO 67 | set batch_size = batch_size - 1; 68 | set @func_query = CONCAT( @func_query , " ,(",func_query,")" ); 69 | END WHILE; 70 | set @func_query = CONCAT( @func_query , ";" ); 71 | IF in_debug='Y' THEN 72 | select @func_query; 73 | END IF; 74 | SET i=in_rows; 75 | SET batch_size=500; 76 | populate :loop 77 | WHILE (i>batch_size) DO 78 | PREPARE t_stmt FROM @func_query; 79 | EXECUTE t_stmt; 80 | SET i = i - batch_size; 81 | END WHILE; 82 | SET @func_query=concat("INSERT INTO ", in_db,".",in_table," VALUES (",func_query,");"); 83 | WHILE (i>0) DO 84 | PREPARE t_stmt FROM @func_query; 85 | EXECUTE t_stmt; 86 | SET i = i - 1; 87 | END WHILE; 88 | LEAVE populate; 89 | END LOOP populate; 90 | -- SELECT "Kedar Vaijanapurkar" AS "Developed by"; 91 | END 92 | $$ 93 | DELIMITER ; 94 | 95 | 96 | /************************ 97 | END OF STORED PROCEDURE 98 | *************************/ 99 | 100 | 101 | 102 | /* 103 | | Developer: Kedar Vaijanapurkar 104 | | MySQL set of function to get random values generated for individual data-types. 105 | */ 106 | 107 | ## MySQL function to generate random string of specified length 108 | DROP function if exists get_string; 109 | delimiter $$ 110 | CREATE FUNCTION get_string(in_strlen int) RETURNS VARCHAR(500) DETERMINISTIC 111 | BEGIN 112 | set @var:=''; 113 | IF (in_strlen>500) THEN SET in_strlen=500; END IF; 114 | while(in_strlen>0) do 115 | set @var:=concat(@var,IFNULL(ELT(1+FLOOR(RAND() * 53), 'a','b','c','d','e','f','g','h','i','j','k','l','m','n','o','p','q','r','s','t','u','v','w','x','y','z',' ','A','B','C','D','E','F','G','H','I','J','K','L','M','N','O','P','Q','R','S','T','U','V','W','X','Y','Z'),'Kedar')); 116 | set in_strlen:=in_strlen-1; 117 | end while; 118 | RETURN @var; 119 | END $$ 120 | delimiter ; 121 | 122 | 123 | ## MySQL function to generate random Enum-ID from specified enum definition 124 | DELIMITER $$ 125 | DROP FUNCTION IF EXISTS get_enum $$ 126 | CREATE FUNCTION get_enum(col_type varchar(100)) RETURNS VARCHAR(100) DETERMINISTIC 127 | RETURN if((@var:=ceil(rand()*10)) > (length(col_type)-length(replace(col_type,',',''))+1),(length(col_type)-length(replace(col_type,',',''))+1),@var); 128 | $$ 129 | DELIMITER ; 130 | 131 | 132 | ## MySQL function to generate random float value from specified precision and scale. 133 | DELIMITER $$ 134 | DROP FUNCTION IF EXISTS get_float $$ 135 | CREATE FUNCTION get_float(in_precision int, in_scale int) RETURNS VARCHAR(100) DETERMINISTIC 136 | RETURN round(rand()*pow(10,(in_precision-in_scale)),in_scale) 137 | $$ 138 | DELIMITER ; 139 | 140 | 141 | 142 | ## MySQL function to generate random date (of year 2012). 143 | DELIMITER $$ 144 | DROP FUNCTION IF EXISTS get_date $$ 145 | CREATE FUNCTION get_date() RETURNS VARCHAR(10) DETERMINISTIC 146 | RETURN DATE(FROM_UNIXTIME(RAND() * (1356892200 - 1325356200) + 1325356200)) 147 | # Below will generate random data for random years 148 | # RETURN DATE(FROM_UNIXTIME(RAND() * (1577817000 - 946665000) + 1325356200)) 149 | $$ 150 | DELIMITER ; 151 | 152 | 153 | ## MySQL function to generate random time. 154 | DELIMITER $$ 155 | DROP FUNCTION IF EXISTS get_time $$ 156 | CREATE FUNCTION get_time() RETURNS INTEGER DETERMINISTIC 157 | RETURN TIME(FROM_UNIXTIME(RAND() * (1356892200 - 1325356200) + 1325356200)) 158 | $$ 159 | DELIMITER ; 160 | 161 | ## MySQL function to generate random int. 162 | DELIMITER $$ 163 | DROP FUNCTION IF EXISTS get_int $$ 164 | CREATE FUNCTION get_int() RETURNS INTEGER DETERMINISTIC 165 | RETURN floor(rand()*10000000) 166 | $$ 167 | DELIMITER ; 168 | 169 | ## MySQL function to generate random tinyint. 170 | DELIMITER $$ 171 | DROP FUNCTION IF EXISTS get_tinyint $$ 172 | CREATE FUNCTION get_tinyint() RETURNS INTEGER DETERMINISTIC 173 | RETURN floor(rand()*100) 174 | $$ 175 | DELIMITER ; 176 | 177 | ## MySQL function to generate random varchar column of specified length(alpha-numeric string). 178 | DELIMITER $$ 179 | DROP FUNCTION IF EXISTS get_varchar $$ 180 | CREATE FUNCTION get_varchar(in_length varchar(500)) RETURNS VARCHAR(500) DETERMINISTIC 181 | RETURN SUBSTRING(MD5(RAND()) FROM 1 FOR in_length) 182 | $$ 183 | DELIMITER ; 184 | 185 | ## MySQL function to generate random datetime value (any datetime of year 2012). 186 | DELIMITER $$ 187 | DROP FUNCTION IF EXISTS get_datetime $$ 188 | CREATE FUNCTION get_datetime() RETURNS VARCHAR(30) DETERMINISTIC 189 | RETURN FROM_UNIXTIME(ROUND(RAND() * (1356892200 - 1325356200)) + 1325356200) 190 | $$ 191 | DELIMITER ; 192 | -------------------------------------------------------------------------------- /populate_fk.sql: -------------------------------------------------------------------------------- 1 | /************** 2 | | poplate_fk : script to generate random data into a child table with 3 | | Note that this script will require the original random data generator populate procedure(populate.sql) 4 | | https://github.com/kedarvj/mysql-random-data-generator/blob/master/populate.sql 5 | | 6 | | USAGE: call populate_fk('DATABASE-NAME','CHILD-TABLE-NAME',NUMBER-OF-ROWS,DEBUG-MODE); 7 | | EXAMPLE: call populate_fk('databasename','child',100,'N'); 8 | | Developer: Kedar Vaijanapurkar 9 | | Website: http://kedar.nitty-witty.com/ 10 | | 11 | **************/ 12 | DELIMITER $$ 13 | 14 | DROP PROCEDURE IF EXISTS populate_fk $$ 15 | CREATE PROCEDURE populate_fk(in_db varchar(50), in_table varchar(50), in_rows int, in_debug char(1)) 16 | fk_load:BEGIN 17 | 18 | #select CONCAT("UPDATE ",TABLE_NAME," SET ",COLUMN_NAME,"=(SELECT ",REFERENCED_COLUMN_NAME," FROM ",REFERENCED_TABLE_SCHEMA,".",REFERENCED_TABLE_NAME," ORDER BY RAND() LIMIT 1);") into @query from information_schema.key_column_usage where TABLE_NAME=in_table AND TABLE_SCHEMA=in_db AND CONSTRAINT_NAME <> 'PRIMARY'; 19 | select concat("UPDATE ",in_table," SET ", (select GROUP_CONCAT(COLUMN_NAME,"=(SELECT ",REFERENCED_COLUMN_NAME," FROM ",REFERENCED_TABLE_SCHEMA,".",REFERENCED_TABLE_NAME," ORDER BY RAND() LIMIT 1)") from information_schema.key_column_usage where TABLE_NAME=in_table AND TABLE_SCHEMA=in_db AND CONSTRAINT_NAME <> 'PRIMARY' group by table_name),";" ) into @query; 20 | IF in_debug='Y' THEN 21 | select @query; 22 | END IF; 23 | if @query is null then 24 | select "No referential information found." as Error; 25 | LEAVE fk_load; 26 | end if; 27 | 28 | set foreign_key_checks=0; 29 | call populate(in_db,in_table,in_rows,'N'); 30 | PREPARE t_stmt FROM @query; 31 | EXECUTE t_stmt; 32 | 33 | set foreign_key_checks=1; 34 | 35 | END 36 | $$ 37 | DELIMITER ; 38 | --------------------------------------------------------------------------------