暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

ERROR 1040 (HY000): Too many connections 8.0.17出现的新特性端口管理额外通道的连接

原创 是赐赐啊! 2022-12-14
721

ERROR 1040 (HY000): Too many connections

连接管理

在MySQL 8.0版本中,对连接管理这一块,是先后做了两个比较大的改变:一个是允许额外连接,另一个是专用的管理端口。

额外连接

在MySQL 8.0版本中,在当前连接数达到最大连接数时,服务端允许1个额外连接,可以让具有CONNECTION_ADMIN权限的用户连接进来,下面简单测试一下。

(1)为了方便测试,先调整最大连接数

mysql> set global max_connections=3;

Query OK, 0 rows affected (0.00 sec)

(2)多开几个会话,以达到最大连接数

mysql> show processlist;

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| Id | User | Host | db | Command | Time | State | Info |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| 15 | event_scheduler | localhost | NULL | Daemon | 154190 | Waiting on empty queue | NULL |

| 54 | root | localhost | NULL | Query | 0 | starting | show processlist |

| 55 | test | 127.0.0.1:59120 | NULL | Sleep | 19 | | NULL |

| 56 | test | 127.0.0.1:59136 | NULL | Sleep | 9 | | NULL |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

4 rows in set (0.00 sec)

mysql> show global status like 'threads_connected';

+-------------------+-------+

| Variable_name | Value |

+-------------------+-------+

| Threads_connected | 3 |

+-------------------+-------+

4 rows in set (0.01 sec)

(3)普通用户test尝试连接,报错too many connections

$ mysql -utest -p -h127.0.0.1 -P10080

Enter password:

ERROR 1040 (08004): Too many connections

(4)超级用户root尝试连接成功

$ mysql -uroot -p

Enter password:

Welcome to the MySQL monitor. Commands end with ; or \g.

Your MySQL connection id is 60

Server version: 8.0.20 MySQL Community Server - GPL

Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its

affiliates. Other names may be trademarks of their respective

owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql>

(5)再次查看当前连接数,为max_connections+1

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| Id | User | Host | db | Command | Time | State | Info |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| 15 | event_scheduler | localhost | NULL | Daemon | 155064 | Waiting on empty queue | NULL |

| 54 | root | localhost | NULL | Query | 0 | starting | show processlist |

| 55 | test | 127.0.0.1:59120 | NULL | Sleep | 893 | | NULL |

| 56 | test | 127.0.0.1:59136 | NULL | Sleep | 883 | | NULL |

| 60 | root | localhost | NULL | Sleep | 141 | | NULL |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

5 rows in set (0.00 sec)

mysql> show global status like 'threads_connected';

+-------------------+-------+

| Variable_name | Value |

+-------------------+-------+

| Threads_connected | 4 |

+-------------------+-------+

4 rows in set (0.00 sec)

(6)超级用户root再次尝试连接,也报错too many connections

$ mysql -uroot -p

Enter password:

ERROR 1040 (HY000): Too many connections

通过上面测试可知,在MySQL 8.0中,允许的连接数为max_connections+1,其中这1个额外连接,只允许具有CONNECTION_ADMIN权限的用户使用。通过这1个额外连接,DBA可以使用超级用户root连接,进行kill会话等管理操作,以避免直接重启实例,降低成本,提高效率。

管理端口

额外连接,在一定程度上,提供了出现too many connection问题时的临时解决手段,但额外数量只有1个,难免会有一些意外,出现类似"连接被抢用"、“终端异常掉线”等情况。因此,在MySQL 8.0.14版本中,又推出了一个非常重要的新特性——管理端口;它允许具有SERVICE_CONNECTION_ADMIN权限的用户,通过特定的IP和PORT连接上来,且没有连接数限制。

(1)先介绍下相关参数

admin_address:监听IP地址

admin_port:监听端口

create_admin_listener_thread:是否创建一个单独的线程来监听管理连接

(2)通过配置上述参数,即可启用管理端口

mysql> show global variables like 'admin%';

+---------------+-----------+

| Variable_name | Value |

+---------------+-----------+

| admin_address | 127.0.0.1 |

| admin_port | 33062 |

+---------------+-----------+

2 rows in set (0.00 sec)

# netstat -lntp | grep 33062

tcp 0 0 127.0.0.1:33062 0.0.0.0:* LISTEN 20042/mysqld

(3)接下来进行测试

mysql> show processlist;

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| Id | User | Host | db | Command | Time | State | Info |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| 15 | event_scheduler | localhost | NULL | Daemon | 168750 | Waiting on empty queue | NULL |

| 54 | root | localhost | NULL | Query | 0 | starting | show processlist |

| 55 | test | 127.0.0.1:59120 | NULL | Sleep | 14579 | | NULL |

| 56 | test | 127.0.0.1:59136 | NULL | Sleep | 14569 | | NULL |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

4 rows in set (0.00 sec)

mysql> show global status like 'threads_connected';

+-------------------+-------+

| Variable_name | Value |

+-------------------+-------+

| Threads_connected | 3 |

+-------------------+-------+

1 row in set (0.00 sec)

(4)普通用户test尝试连接,报错too many connections

$ mysql -utest -p -h127.0.0.1 -P10080

Enter password:

ERROR 1040 (08004): Too many connections

(5)超级用户root尝试通过管理端口连接成功

$ mysql -uroot -p -h127.0.0.1 -P33062

Enter password:

Welcome to the MySQL monitor. Commands end with ; or \g.

Your MySQL connection id is 62

Server version: 8.0.20 MySQL Community Server - GPL

Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its

affiliates. Other names may be trademarks of their respective

owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql>

(6)继续多开几个会话,使用超级用户root,通过管理端口连接成功,不受最大连接数max_connections限制

mysql> show processlist;

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| Id | User | Host | db | Command | Time | State | Info |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

| 15 | event_scheduler | localhost | NULL | Daemon | 169035 | Waiting on empty queue | NULL |

| 54 | root | localhost | NULL | Query | 0 | starting | show processlist |

| 55 | test | 127.0.0.1:59120 | NULL | Sleep | 14864 | | NULL |

| 56 | test | 127.0.0.1:59136 | NULL | Sleep | 14854 | | NULL |

| 62 | root | 127.0.0.1:47660 | NULL | Sleep | 151 | | NULL |

| 63 | root | 127.0.0.1:47760 | NULL | Sleep | 52 | | NULL |

| 64 | root | 127.0.0.1:47768 | NULL | Sleep | 43 | | NULL |

| 65 | root | 127.0.0.1:47780 | NULL | Sleep | 35 | | NULL |

| 66 | root | 127.0.0.1:47790 | NULL | Sleep | 24 | | NULL |

| 67 | root | 127.0.0.1:47800 | NULL | Sleep | 16 | | NULL |

| 68 | root | 127.0.0.1:47808 | NULL | Sleep | 8 | | NULL |

+----+-----------------+-----------------+------+---------+--------+------------------------+------------------+

11 rows in set (0.00 sec)

mysql> show global status like 'threads_connected';

+-------------------+-------+

| Variable_name | Value |

+-------------------+-------+

| Threads_connected | 10 |

+-------------------+-------+

1 row in set (0.00 sec)

可以说,有了管理端口这个新功能,DBA再也不用担心too many connections的问题。

总结

在MySQL 8.0版本中,为了应对too many connections的场景,先后推出了额外连接和管理端口两个新功能,可以让DBA方便、快速地解决问题;不过,这始终是一个临时应急手段,最根本的原因还是要排查应用端的配置(并发限流、SQL性能、连接池配置等等),以彻底规避此类问题。

最后修改时间:2022-12-14 10:44:06
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论