準備環境
1.創建數字輔助表
create table nums(id int not null primary key);
delimiter $$
create procedure pFastCreateNums(cnt int)
begin
declare s int default 1;
truncate table nums;
insert into nums select s;
while s*2<=cnt do
insert into nums select id+s from nums;
set s=s*2;
end while;
end $$
delimiter ;
call pFastCreateNums(1000000);
數字輔助表的行數決定最后能生成的表行數的最大值.
2.創建生成隨機字符的函數
-
DROP FUNCTION IF EXISTS rand_string;
-
delimiter //
-
CREATE FUNCTION rand_string(l_num int UNSIGNED,l_type tinyint UNSIGNED)
-
RETURNS varchar(2000)
-
BEGIN
-
-- Function : rand_string
-
-- Author : dbachina#dbachina.com
-
-- Date : 2010/5/30
-
-- l_num : The length of random string
-
-- l_type: The string type
-
-- 1.0-9
-
-- 2.a-z
-
-- 3.A-Z
-
-- 4.a-zA-Z
-
-- 5.0-9a-zA-Z
-
-- :
-
-- mysql> select rand_string(12,5) random_string;
-
-- +---------------+
-
-- | random_string |
-
-- +---------------+
-
-- | 3KzGJCUJUplw |
-
-- +---------------+
-
-- 1 row in set (0.00 sec)
-
DECLARE i int UNSIGNED DEFAULT 0;
-
DECLARE v_chars varchar(64) DEFAULT '0123456789';
-
DECLARE result varchar (2000) DEFAULT '';
-
-
IF l_type = 1 THEN
-
SET v_chars = '0123456789';
-
ELSEIF l_type = 2 THEN
-
SET v_chars = 'abcdefghijklmnopqrstuvwxyz';
-
ELSEIF l_type = 3 THEN
-
SET v_chars = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ';
-
ELSEIF l_type = 4 THEN
-
SET v_chars = 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ';
-
ELSEIF l_type = 5 THEN
-
SET v_chars = '0123456789abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ';
-
ELSE
-
SET v_chars = '0123456789';
-
END IF;
-
-
WHILE i < l_num DO
-
SET result = concat( result,substr(v_chars,ceil(rand()*(length(v_chars)-1)),1) );
-
SET i = i + 1;
-
END WHILE;
-
RETURN result;
-
END;
-
//
-
delimiter ;
準備實驗表.
先創建一些帶有外鍵約束的表.數據庫名稱是 probe
-
CREATE TABLE `t_jvm_info` (
-
`id` bigint(20) NOT NULL AUTO_INCREMENT,
-
`app_name` varchar(32) NOT NULL COMMENT '應用名稱',
-
`host_name` varchar(32) NOT NULL COMMENT '主機名稱',
-
`collect_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '采集時間',
-
`version` varchar(32) NOT NULL DEFAULT '' COMMENT 'jvm版本',
-
`vendor` varchar(32) NOT NULL DEFAULT '' COMMENT '廠商',
-
`java_home` varchar(64) NOT NULL DEFAULT '' COMMENT '客戶端javahome路徑',
-
`loaded_class_count` int(11) NOT NULL DEFAULT '-1' COMMENT '已經加載的類數量',
-
`unloaded_class_count` int(11) NOT NULL DEFAULT '-1' COMMENT '已經卸載的類數量',
-
`total_loaded_class_count` int(11) NOT NULL DEFAULT '-1' COMMENT '累計加載的類數量',
-
`heap_init` float NOT NULL DEFAULT '-1' COMMENT '堆內存初始大小',
-
`heap_committed` bigint(20) NOT NULL DEFAULT '-1' COMMENT 'os分配給jvm的堆內存',
-
`heap_max` bigint(20) NOT NULL DEFAULT '-1' COMMENT '堆內存上限',
-
`heap_used` bigint(20) NOT NULL DEFAULT '-1' COMMENT '已經使用的堆內存大小',
-
`non_heap_init` bigint(20) NOT NULL DEFAULT '-1' COMMENT '非堆內存初始大小',
-
`non_heap_committed` bigint(20) NOT NULL DEFAULT '-1' COMMENT 'os分配給jvm的非堆內存',
-
`non_heap_max` bigint(20) NOT NULL DEFAULT '-1' COMMENT '非堆內存上限',
-
`non_heap_used` bigint(20) NOT NULL DEFAULT '-1' COMMENT '已經使用的非堆內存大小',
-
`current_thread_count` int(11) NOT NULL DEFAULT '-1' COMMENT '當前jvm線程總數',
-
`total_started_thread_count` int(11) NOT NULL DEFAULT '-1' COMMENT '累計啟動過的線程總數',
-
`peak_thread_count` int(11) NOT NULL DEFAULT '-1' COMMENT '線程數量最大值',
-
`daemon_thread_count` int(11) NOT NULL DEFAULT '-1' COMMENT 'daemon線程數量',
-
PRIMARY KEY (`id`),
-
KEY `app_name` (`app_name`,`host_name`,`collect_time`),
-
KEY `host_name` (`host_name`,`collect_time`)
-
) ENGINE=InnoDB AUTO_INCREMENT=2001 DEFAULT CHARSET=utf8mb4 COMMENT='jvm采集信息表';
-
-
CREATE TABLE `t_jvm_gc_info` (
-
`id` bigint(20) NOT NULL AUTO_INCREMENT,
-
`t_jvm_info_id` bigint(20) NOT NULL COMMENT 'jvm采集信息表id',
-
`name` varchar(32) NOT NULL COMMENT 'gc類型名稱',
-
`gctime` bigint(20) NOT NULL DEFAULT '-1' COMMENT 'gc時間',
-
`gccount` bigint(20) NOT NULL DEFAULT '-1' COMMENT 'gc次數',
-
PRIMARY KEY (`id`),
-
KEY `t_jvm_info_id` (`t_jvm_info_id`),
-
CONSTRAINT `t_jvm_gc_info_ibfk_1` FOREIGN KEY (`t_jvm_info_id`) REFERENCES `t_jvm_info` (`id`)
-
) ENGINE=InnoDB AUTO_INCREMENT=101 DEFAULT CHARSET=utf8mb4 COMMENT='jvm gc采集信息表';
創建可以自動生成數據的存儲過程
-
drop procedure if exists auto_fill ;
-
delimiter $$
-
create procedure auto_fill(pDb varchar(32),pTableList varchar(1024))
-
begin
-
declare done int default 0;
-
declare v_dbName varchar(128);
-
declare v_fullTableName varchar(128);
-
declare v_tableName varchar(128);
-
declare v_rowCount int;
-
declare cur_test CURSOR for select dbName,fullTableName,tableName,rowCount from tmp_table_info;
-
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1;
-
-
-- 臨時表,用于保存拆分參數之后的結果.主要信息就是數據庫名稱和表名稱
-
drop table if exists tmp_table_info;
-
create temporary table tmp_table_info
-
select pDb dbName,
-
concat(pDb,'.',substring_index ( value_str,',',1 )) fullTableName ,
-
substring_index ( value_str,',',1 ) tableName,
-
substring_index ( value_str,',',-1 ) rowCount
-
from (
-
select substring_index(substring_index(pTableList,';',b.id),';',-1) value_str
-
from
-
nums b
-
where b.id <= (length(pTableList) - length(replace(pTableList,';',''))+1)
-
) t1;
-
-
-- 禁用外鍵
-
SET FOREIGN_KEY_CHECKS=0;
-
open cur_test;
-
repeat
-
fetch cur_test into v_dbName,v_fullTableName,v_tableName,v_rowCount;
-
if done!=1 then
-
-
set @sql=concat('insert ignore into ',v_dbName,'.',v_tableName,' select ');
-
select
-
@sql:=concat(@sql,
-
case
-
when extra='auto_increment' then concat('id,')
-
when data_type='int' then if(rowCount is null,'round(rand()*2147483647),',concat('round(rand()*',rowCount,'),'))
-
when data_type='bigint' then if(rowCount is null,'round(rand()*9223372036854775807),',concat('round(rand()*',rowCount,'),'))
-
when data_type='smallint' then 'round(rand()*32767),'
-
when data_type='tinyint' then 'round(rand()*127 ),'
-
when data_type='varchar' then concat('rand_string(',CHARACTER_MAXIMUM_LENGTH,',5),')
-
when data_type='date' then 'now()-interval round(90*rand()) day,'
-
when data_type='datetime' then 'now()-interval round(90*rand()) day,'
-
when data_type='timestamp' then 'now()-interval round(90*rand()) day,'
-
when data_type in('double','float') then 'round(rand()*32767,5),'
-
when data_type like '%text%' then concat('rand_string(2048,5),')
-
end
-
) s
-
from (
-
select
-
k.referenced_table_name,
-
k.referenced_column_name,
-
c.table_schema,
-
c.table_name,
-
c.column_name,
-
c.data_type,
-
c.CHARACTER_MAXIMUM_LENGTH,
-
c.extra,
-
t.rowCount
-
from information_schema.columns c
-
left join information_schema.KEY_COLUMN_USAGE k on(
-
c.table_schema=k.table_schema and
-
c.table_name=k.table_name and
-
c.column_name=k.column_name and
-
k.constraint_name
-
in (select constraint_name from information_schema.REFERENTIAL_CONSTRAINTS)
-
)
-
left join tmp_table_info t on(t.dbName=k.table_schema and t.tableName=k.table_name)
-
where (c.table_schema,c.table_name) =(v_dbName,v_tableName)
-
order by c.ORDINAL_POSITION
-
) t2
-
;
-
set @sql=left(@sql,char_length(@sql)-1);
-
select nullif ('please stand by...',@sql:=concat(@sql,' from nums where id<=',v_rowCount,';')) info;
-
prepare statement from @sql;
-
execute statement;
-
commit;
-
end if;
-
until done end repeat;
-
close cur_test;
-
-
-- 恢復外鍵
-
SET FOREIGN_KEY_CHECKS=1;
-
-
-
end ;
-
$$
-
delimiter ;
執行存儲過程填充數據
call auto_fill('probe','t_jvm_gc_info,100000;t_jvm_info,2000');
過程第一個參數是 數據庫名稱
第二個參數是 表名和行數的字符串列表.
測試數據生成自行刪除外鍵約束即可