环境信息
MySQL 5.7.21
文件系统 ext3
问题描述
单表idb文件达到2T(ext3文件系统单文件最大限制),当表insert时会报错 the table is full,开发紧急delete掉6万行数据后,ibd文件大小未减小,insert新数据继续报错 the table is full 。(ps:临时应急:在未改变文件系统ext3的情况下,rename 旧表,建同名新表,确保增量插入可用,并进行存量数据迁移)
应用报错截图:
错误日志报错截图:
数据清理语句:
delete语句:
DELETE FROM release
WHERE AppId
="120685" AND ClusterName
="default" AND NamespaceName
="F-HMP.CLIENT" AND id<44425775 (二次确认已删除成功了)
表结构:
CREATE TABLE `release` (
`Id` int(10) unsigned NOT NULL AUTO_INCREMENT COMMENT '',
`ReleaseKey` varchar(64) CHARACTER SET utf8mb4 NOT NULL DEFAULT '' COMMENT '',
`Name` varchar(64) CHARACTER SET utf8mb4 NOT NULL DEFAULT 'default' COMMENT '',
`Comment` varchar(256) CHARACTER SET utf8mb4 DEFAULT NULL COMMENT '',
`AppId` varchar(500) CHARACTER SET utf8mb4 NOT NULL DEFAULT 'default' COMMENT '',
`ClusterName` varchar(500) CHARACTER SET utf8mb4 NOT NULL DEFAULT 'default' COMMENT '',
`NamespaceName` varchar(500) CHARACTER SET utf8mb4 NOT NULL DEFAULT 'default' COMMENT '',
`Configurations` longtext CHARACTER SET utf8mb4 NOT NULL COMMENT '',
`IsAbandoned` bit(1) NOT NULL DEFAULT b'0' COMMENT '',
`IsDeleted` bit(1) NOT NULL DEFAULT b'0' COMMENT '',
`DataChange_CreatedBy` varchar(32) CHARACTER SET utf8mb4 NOT NULL DEFAULT 'default' COMMENT '',
`DataChange_CreatedTime` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '',
`DataChange_LastModifiedBy` varchar(32) CHARACTER SET utf8mb4 DEFAULT '' COMMENT '',
`DataChange_LastTime` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '',
`Ucm` longtext COLLATE utf8mb4_bin COMMENT '',
PRIMARY KEY (`Id`),
KEY `AppId_ClusterName_GroupName` (`AppId`(191),`ClusterName`(191),`NamespaceName`(191)),
KEY `DataChange_LastTime` (`DataChange_LastTime`),
KEY `IX_ReleaseKey` (`ReleaseKey`)
) ENGINE=InnoDB AUTO_INCREMENT=46041420 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin COMMENT=''
表ibd大小:
cmc-0018-0:/data/mysql_data/data/apolloconfigdb # ls -l release.ibd
-rw-r----- 1 mysql mysql 2194719883264 May 13 08:55 release.ibd
疑问1: 单表idb文件达到文件系统上限后,delete 清理6万数据后,为什么仍无法执行insert操作?
一个extent 在16KB page size 的情况下是1MB,删除的行未必位于相同的extent( where 条件有很多其他的条件 说明删除不是按照主键递增做严格的范围扫描清理数据),即使innodb purge 处理过之后,仍然无法腾出完整的若干个extent,让文件系统可以复用若干16KB的空间
疑问2:单表idb文件达到文件系统上限后,有办法能直接让该表能继续新增数据吗?
按照where 条件只有自增主键做范围扫描的数据清理,Innodb可以把数据文件中全空的extent 或者page 复用起来(测试复现如下)
mysql> show create table t_user_1_1000_10000\G
*************************** 1. row ***************************
Table: t_user_1_1000_10000
Create Table: CREATE TABLE `t_user_1_1000_10000` (
`id` int NOT NULL AUTO_INCREMENT,
`c_name` varchar(1000) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=40000 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
1 row in set (0.00 sec)
mysql> select count(*) from t_user_1_1000_10000;
+----------+
| count(*) |
+----------+
| 30000 |
+----------+
1 row in set (0.04 sec)
mysql> select min(id),max(id) from t_user_1_1000_10000;
+---------+---------+
| min(id) | max(id) |
+---------+---------+
| 1 | 30000 |
+---------+---------+
1 row in set (0.00 sec)
mysql> delete from t_user_1_1000_10000 where id < 10000 and id > 20000;
Query OK, 9999 rows affected (0.20 sec)
mysql> call add_t_user_1_1000_10000(5000);
Query OK, 1 row affected (39.79 sec)
mysql> call add_t_user_1_1000_10000(4999);
Query OK, 1 row affected (39.35 sec)
mysql> select count(*) from t_user_1_1000_10000;
+----------+
| count(*) |
+----------+
| 30000 |
+----------+
1 row in set (0.04 sec)
[root@test_greatsql_01 bbb]# du -h t_user_1_1000_10000.ibd
45M t_user_1_1000_10000.ibd
[root@test_greatsql_01 bbb]#
[root@test_greatsql_01 bbb]# du -h t_user_1_1000_10000.ibd
45M t_user_1_1000_10000.ibd
造数脚本:
CREATE TABLE `t_user_1_1000_10000` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`c_name` varchar(1000) NOT NULL,
PRIMARY KEY (`id`)
) CHARSET=utf8mb4;
# 创建随机字符串
delimiter $$
DROP FUNCTION IF EXISTS `randStr` $$
CREATE DEFINER=`root`@`%` FUNCTION `randStr`(n INT) RETURNS varchar(1000) CHARSET utf8mb4
DETERMINISTIC
BEGIN
DECLARE chars_str varchar(100) DEFAULT 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789';
DECLARE return_str varchar(1000) DEFAULT '' ;
DECLARE i INT DEFAULT 0;
WHILE i < n DO
SET return_str = concat(return_str, substring(chars_str, FLOOR(1 + RAND() * 62), 1));
SET i = i + 1;
END WHILE;
RETURN return_str;
END$$
# 创建插入数据存储过程
delimiter $$
CREATE DEFINER=`root`@`%` PROCEDURE `add_t_user_1_1000_10000`(IN n int)
BEGIN
DECLARE i INT DEFAULT 1;
WHILE (i <= n) DO
INSERT INTO t_user_1_1000_10000 (c_name) VALUES ( randStr(1000));
SET i = i + 1;
END WHILE;
END $$
delimiter ;
call add_t_user_1_1000_10000(30000);