Carry の Blog Carry の Blog
首页
  • Nginx
  • Prometheus
  • Iptables
  • Systemd
  • Firewalld
  • Docker
  • Sshd
  • DBA工作笔记
  • MySQL
  • Redis
  • TiDB
  • Elasticsearch
  • Python
  • Shell
  • MySQL8-SOP手册
  • 分类
  • 标签
  • 归档
GitHub (opens new window)

Carry の Blog

好记性不如烂键盘
首页
  • Nginx
  • Prometheus
  • Iptables
  • Systemd
  • Firewalld
  • Docker
  • Sshd
  • DBA工作笔记
  • MySQL
  • Redis
  • TiDB
  • Elasticsearch
  • Python
  • Shell
  • MySQL8-SOP手册
  • 分类
  • 标签
  • 归档
GitHub (opens new window)
  • MySQL

    • MySQL8一键安装配置优化
    • MySQL导出CSV格式解决乱码
    • MySQL 角色管理
    • MySQL网络抓包审计
    • MySQL性能压测
    • MySQL配合Consul读写分离
    • Gh-ost重建表,清除表碎片率
    • MySQL MGR配合MySQL-router实现innodb-cluster
    • MySQL 快速分析binlog定位问题
    • MySQL执行计划分析
    • DBA常用SQL和命令整理备查
      • 新建表后校验
      • 修改表结构后校验
      • 添加索引后校验
      • 查看表创建时间
      • 查看大于10000000行的表
      • KILL数据库链接
        • 杀掉空闲时间大于2000s的链接
        • 杀掉处于某状态的链接
        • 杀掉某个用户的链接
      • 拼接创建数据库语句(排除系统库)
      • 拼接创建用户语句(排除系统用户)
      • 用于批量修改密码
      • 重命名库名
      • 查看整个实例空间占用大小
      • 查看各个库占用大小
      • 查看单个库占用空间大小
      • 查看单个表占用空间大小
      • 查看指定数据库各表容量大小
      • 查看某个库下所有表的碎片情况
      • 收缩表,减少碎片
      • 查找某一个库无主键表
      • 查找除系统库外无主键表
    • mysqldump实时同步数据
    • MySQL的事务隔离级别
    • MySQL存储过程批量生成数据
    • MySQL insert on duplicate key update,replace into , insert ignore的理解
    • MySQL不同字符集之间的区别和选择
    • MySQL为什么有时候会选错索引
    • MySQL死锁问题
    • MySQL使用SQL语句查重去重
    • MySQLdump逻辑备份
    • MySQL主从跳过异常GITD
    • MySQL8设置slowlog记录所有语句
    • MySQL8快速克隆插件使用指南
    • MySQL8双1设置保障安全
    • MySQL锁
    • innodb cluster安装
    • MySQL里的left join 和right join以及inner join
    • optimize table和 analyze table的区别
    • MySQL 字段的区分度计算公式
    • MySQLReplicaSet 安装
    • 脚本实现MySQL ReplicaSet 高可用
    • MySQL 的Left join,Right join和Inner join 的区别
    • MySQL45讲学习笔记
  • Redis

  • Keydb

  • TiDB

  • MongoDB

  • Elasticsearch

  • Kafka

  • victoriametrics

  • BigData

  • Sqlserver

  • 数据库
  • MySQL
Carry の Blog
2022-03-10
目录

DBA常用SQL和命令整理备查原创

# DBA常用SQL和命令整理备查

# 新建表后校验

SELECT TABLE_SCHEMA, TABLE_NAME 
FROM INFORMATION_SCHEMA.tables 
WHERE table_name = 'my_table_name';
1
2
3

# 修改表结构后校验

SELECT TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, DATA_TYPE, CHARACTER_MAXIMUM_LENGTH 
FROM INFORMATION_SCHEMA.COLUMNS 
WHERE table_name = 'my_table_name' 
AND COLUMN_NAME IN ('my_column_name1', 'my_column_name2');
1
2
3
4

# 添加索引后校验

SELECT s.table_schema, s.table_name, s.index_name, s.column_name 
FROM information_schema.STATISTICS s 
WHERE index_name = 'idx_myindex';
1
2
3

# 查看表创建时间

-- 所有表
SELECT table_name, create_time 
FROM information_schema.TABLES;

-- 指定表
SELECT table_name, create_time 
FROM information_schema.TABLES 
WHERE table_name = 'table_name';
1
2
3
4
5
6
7
8

# 查看大于10000000行的表

SELECT table_schema, table_name, table_rows 
FROM information_schema.TABLES 
WHERE table_schema NOT IN ('information_schema', 'mysql', 'performance_schema', 'sys') 
AND table_rows > 10000000 
ORDER BY table_rows DESC;
1
2
3
4
5

# KILL数据库链接

# 杀掉空闲时间大于2000s的链接

SELECT CONCAT('KILL ', id, ';') 
FROM information_schema.`processlist` 
WHERE command = 'Sleep' AND time > 2000;
1
2
3

# 杀掉处于某状态的链接

SELECT CONCAT('KILL ', id, ';') 
FROM information_schema.`processlist` 
WHERE state LIKE 'Creating sort index';
1
2
3

# 杀掉某个用户的链接

SELECT CONCAT('KILL ', id, ';') 
FROM information_schema.`processlist` 
WHERE user = 'root';
1
2
3

# 拼接创建数据库语句(排除系统库)

SELECT CONCAT(
        'CREATE DATABASE ',
        '`',
        schema_name,
        '`',
        ' DEFAULT CHARACTER SET ',
        default_character_set_name,
        ';'
    ) AS CreateDatabaseQuery
FROM information_schema.schemata
WHERE schema_name NOT IN (
        'information_schema',
        'performance_schema',
        'mysql',
        'sys'
    );
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16

# 拼接创建用户语句(排除系统用户)

SELECT CONCAT(
        'CREATE USER \'',
        user,
        '\'@\'',
        host,
        '\' IDENTIFIED WITH \'mysql_native_password\' AS \'',
        authentication_string,
        '\' REQUIRE NONE PASSWORD EXPIRE DEFAULT ACCOUNT UNLOCK PASSWORD HISTORY DEFAULT PASSWORD REUSE INTERVAL DEFAULT PASSWORD REQUIRE CURRENT DEFAULT;'
    )
FROM mysql.`user`
WHERE `User` NOT IN ('root', 'mysql.session', 'mysql.sys');
1
2
3
4
5
6
7
8
9
10
11

# 用于批量修改密码

SELECT CONCAT(
        'CREATE USER ',
        user,
        '_v1@',
        '`',
        host,
        '`',
        ' IDENTIFIED BY ',
        "'",
        RIGHT(TO_BASE64(authentication_string), 12),
        "';"
    )
FROM mysql.user
WHERE host NOT IN ('localhost', '127.0.0.1')
AND user NOT LIKE '%_v1'
ORDER BY user;
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16

# 重命名库名

SELECT CONCAT(
        "CREATE TABLE ", TABLE_SCHEMA, "_bak.", TABLE_NAME, " LIKE ", TABLE_SCHEMA, ".", TABLE_NAME, ";"
    ) 
FROM information_schema.columns 
WHERE TABLE_SCHEMA NOT IN ('information_schema', 'mysql', 'performance_schema', 'sys') 
GROUP BY TABLE_SCHEMA, TABLE_NAME;
1
2
3
4
5
6

# 查看整个实例空间占用大小

SELECT 
    CONCAT(ROUND(SUM(data_length) / 1024 / 1024, 2), ' MB') AS data_length_MB,
    CONCAT(ROUND(SUM(index_length) / 1024 / 1024, 2), ' MB') AS index_length_MB
FROM information_schema.`TABLES`;
1
2
3
4

# 查看各个库占用大小

SELECT 
    TABLE_SCHEMA,
    CONCAT(TRUNCATE(SUM(data_length) / 1024 / 1024, 2), ' MB') AS data_size,
    CONCAT(TRUNCATE(SUM(index_length) / 1024 / 1024, 2), ' MB') AS index_size
FROM information_schema.`TABLES`
GROUP BY TABLE_SCHEMA;
1
2
3
4
5
6

# 查看单个库占用空间大小

SELECT 
    CONCAT(ROUND(SUM(data_length) / 1024 / 1024, 2), ' MB') AS data_length_MB,
    CONCAT(ROUND(SUM(index_length) / 1024 / 1024, 2), ' MB') AS index_length_MB
FROM information_schema.`TABLES`
WHERE table_schema = 'test_db';
1
2
3
4
5

# 查看单个表占用空间大小

SELECT 
    CONCAT(ROUND(SUM(data_length) / 1024 / 1024, 2), ' MB') AS data_length_MB,
    CONCAT(ROUND(SUM(index_length) / 1024 / 1024, 2), ' MB') AS index_length_MB
FROM information_schema.`TABLES`
WHERE table_schema = 'test_db'
AND table_name = 'tbname';
1
2
3
4
5
6

# 查看指定数据库各表容量大小

SELECT 
    table_schema AS '数据库',
    table_name AS '表名',
    table_rows AS '记录数',
    TRUNCATE(data_length / 1024 / 1024, 2) AS '数据容量(MB)',
    TRUNCATE(index_length / 1024 / 1024, 2) AS '索引容量(MB)'
FROM information_schema.tables
WHERE table_schema = 'mysql'
ORDER BY data_length DESC, index_length DESC;
1
2
3
4
5
6
7
8
9

# 查看某个库下所有表的碎片情况

SELECT 
    t.TABLE_SCHEMA,
    t.TABLE_NAME,
    t.TABLE_ROWS,
    CONCAT(ROUND(t.DATA_LENGTH / 1024 / 1024, 2), ' MB') AS size,
    t.INDEX_LENGTH,
    CONCAT(ROUND(t.DATA_FREE / 1024 / 1024, 2), ' MB') AS datafree
FROM information_schema.`TABLES` t
WHERE t.TABLE_SCHEMA = 'callcenter'
ORDER BY datafree DESC;
1
2
3
4
5
6
7
8
9
10

# 收缩表,减少碎片

ALTER TABLE tb_name ENGINE = InnoDB;
OPTIMIZE TABLE tb_name;
1
2

# 查找某一个库无主键表

SELECT 
    table_schema,
    table_name
FROM information_schema.`TABLES`
WHERE table_schema = 'test_db'
AND table_name NOT IN (
    SELECT table_name
    FROM information_schema.table_constraints t
    JOIN information_schema.key_column_usage k USING (constraint_name, table_schema, table_name)
    WHERE t.constraint_type = 'PRIMARY KEY'
    AND t.table_schema = 'test_db'
);
1
2
3
4
5
6
7
8
9
10
11
12

# 查找除系统库外无主键表

SELECT 
    t1.table_schema,
    t1.table_name
FROM information_schema.`TABLES` t1
LEFT OUTER JOIN information_schema.TABLE_CONSTRAINTS t2 ON t1.table_schema = t2.TABLE_SCHEMA
AND t1.table_name = t2.TABLE_NAME
AND t2.CONSTRAINT_NAME IN ('PRIMARY')
WHERE t2.table_name IS NULL
AND t1.TABLE_SCHEMA NOT IN ('information_schema', 'performance_schema', 'mysql', 'sys');
1
2
3
4
5
6
7
8
9
#SQL#数据库管理
上次更新: 4/24/2025

← MySQL执行计划分析 mysqldump实时同步数据→

最近更新
01
tidb fast ddl
04-04
02
TiDB配置文件调优 原创
04-03
03
如何移除TiDB中的表分区 原创
04-03
更多文章>
Theme by Vdoing
  • 跟随系统
  • 浅色模式
  • 深色模式
  • 阅读模式