MySQL 8.0新特性 — 管理端口的使用簡(jiǎn)介
前言
下面這個(gè)報(bào)錯(cuò),相信大多數(shù)童鞋都遇見過(guò);那么碰到這個(gè)問(wèn)題,我們應(yīng)該怎么辦呢?在MySQL 5.7及之前版本,出現(xiàn)“too many connection”報(bào)錯(cuò),超級(jí)用戶root也無(wú)法登錄上去,除了重啟實(shí)例,沒(méi)有其他更好的解決辦法;不過(guò)在MySQL 8.0版本中,是對(duì)連接管理做了一些優(yōu)化,下面我們就來(lái)看一下。
ERROR 1040 (HY000): Too many connections
連接管理
在MySQL 8.0版本中,對(duì)連接管理這一塊,是先后做了兩個(gè)比較大的改變:一個(gè)是允許額外連接,另一個(gè)是專用的管理端口。
額外連接
在MySQL 8.0版本中,在當(dāng)前連接數(shù)達(dá)到最大連接數(shù)時(shí),服務(wù)端允許1個(gè)額外連接,可以讓具有CONNECTION_ADMIN權(quán)限的用戶連接進(jìn)來(lái),下面簡(jiǎn)單測(cè)試一下。
(1)為了方便測(cè)試,先調(diào)整最大連接數(shù)
mysql> set global max_connections=3; Query OK, 0 rows affected (0.00 sec)
(2)多開幾個(gè)會(huì)話,以達(dá)到最大連接數(shù)
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嘗試連接,報(bào)錯(cuò)too many connections
$ mysql -utest -p -h127.0.0.1 -P10080 Enter password: ERROR 1040 (08004): Too many connections
(4)超級(jí)用戶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)再次查看當(dāng)前連接數(shù),為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)超級(jí)用戶root再次嘗試連接,也報(bào)錯(cuò)too many connections
$ mysql -uroot -p Enter password: ERROR 1040 (HY000): Too many connections
通過(guò)上面測(cè)試可知,在MySQL 8.0中,允許的連接數(shù)為max_connections+1,其中這1個(gè)額外連接,只允許具有CONNECTION_ADMIN權(quán)限的用戶使用。通過(guò)這1個(gè)額外連接,DBA可以使用超級(jí)用戶root連接,進(jìn)行kill會(huì)話等管理操作,以避免直接重啟實(shí)例,降低成本,提高效率。
管理端口
額外連接,在一定程度上,提供了出現(xiàn)too many connection問(wèn)題時(shí)的臨時(shí)解決手段,但額外數(shù)量只有1個(gè),難免會(huì)有一些意外,出現(xiàn)類似"連接被搶用"、“終端異常掉線”等情況。因此,在MySQL 8.0.14版本中,又推出了一個(gè)非常重要的新特性——管理端口;它允許具有SERVICE_CONNECTION_ADMIN權(quán)限的用戶,通過(guò)特定的IP和PORT連接上來(lái),且沒(méi)有連接數(shù)限制。
(1)先介紹下相關(guān)參數(shù)
admin_address:監(jiān)聽I(yíng)P地址 admin_port:監(jiān)聽端口 create_admin_listener_thread:是否創(chuàng)建一個(gè)單獨(dú)的線程來(lái)監(jiān)聽管理連接
(2)通過(guò)配置上述參數(shù),即可啟用管理端口
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)接下來(lái)進(jìn)行測(cè)試
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嘗試連接,報(bào)錯(cuò)too many connections
$ mysql -utest -p -h127.0.0.1 -P10080 Enter password: ERROR 1040 (08004): Too many connections
(5)超級(jí)用戶root嘗試通過(guò)管理端口連接成功
$ 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)繼續(xù)多開幾個(gè)會(huì)話,使用超級(jí)用戶root,通過(guò)管理端口連接成功,不受最大連接數(shù)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)
可以說(shuō),有了管理端口這個(gè)新功能,DBA再也不用擔(dān)心too many connections的問(wèn)題。
總結(jié)
在MySQL 8.0版本中,為了應(yīng)對(duì)too many connections的場(chǎng)景,先后推出了額外連接和管理端口兩個(gè)新功能,可以讓DBA方便、快速地解決問(wèn)題;不過(guò),這始終是一個(gè)臨時(shí)應(yīng)急手段,最根本的原因還是要排查應(yīng)用端的配置(并發(fā)限流、SQL性能、連接池配置等等),以徹底規(guī)避此類問(wèn)題。
以上就是MySQL 8.0新特性 — 管理端口的使用簡(jiǎn)介的詳細(xì)內(nèi)容,更多關(guān)于MySQL 8.0新特性 — 管理端口的資料請(qǐng)關(guān)注腳本之家其它相關(guān)文章!
相關(guān)文章
MySQL之FIELD()與ORDER BY()相結(jié)合實(shí)現(xiàn)對(duì)結(jié)果的自定義排序方式
這篇文章主要介紹了MySQL之FIELD()與ORDER BY()相結(jié)合實(shí)現(xiàn)對(duì)結(jié)果的自定義排序方式,具有很好的參考價(jià)值,希望對(duì)大家有所幫助,如有錯(cuò)誤或未考慮完全的地方,望不吝賜教2024-04-04完美解決mysql in條件語(yǔ)句只讀取一條信息問(wèn)題的2種方案
使用mysql多表查詢時(shí)一個(gè)表中的某個(gè)字段作為另一表的in查詢條件,只能讀取一條信息,而直接用數(shù)字的話可以正常讀取2018-04-04MySQL安裝常見報(bào)錯(cuò)處理方法總結(jié)大全
MySQL數(shù)據(jù)庫(kù)在安裝或卸載的過(guò)程中,常常會(huì)出現(xiàn)一些錯(cuò)誤,這是件讓我們頭疼的事,下面這篇文章主要給大家介紹了關(guān)于MySQL安裝常見報(bào)錯(cuò)處理方法的相關(guān)資料,文中通過(guò)實(shí)例代碼介紹的非常詳細(xì),需要的朋友可以參考下2022-07-07MySQL修改lower_case_table_names參數(shù)的方法實(shí)踐
本文主要介紹了MySQL修改lower_case_table_names參數(shù),文中通過(guò)示例代碼介紹的非常詳細(xì),對(duì)大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價(jià)值,需要的朋友們下面隨著小編來(lái)一起學(xué)習(xí)學(xué)習(xí)吧2024-05-05Mysql中文漢字轉(zhuǎn)拼音的實(shí)現(xiàn)(每個(gè)漢字轉(zhuǎn)換全拼)
這篇文章主要介紹了Mysql中文漢字轉(zhuǎn)拼音的實(shí)現(xiàn),并且每個(gè)漢字會(huì)轉(zhuǎn)換全拼,使用Mysql自定義函數(shù)實(shí)現(xiàn),需要的朋友可以參考下2014-06-06mysql建庫(kù)時(shí)提示Specified key was too long max key length is 1000
本文將詳細(xì)提供mysql建庫(kù)時(shí)提示Specified key was too long max key length is 1000 bytes的問(wèn)題的解決方法,有需求的朋友可以參考2012-11-11mysql 批處理文件出錯(cuò)后繼續(xù)執(zhí)行的實(shí)現(xiàn)方法
下面小編就為大家?guī)?lái)一篇mysql 批處理文件出錯(cuò)后繼續(xù)執(zhí)行的實(shí)現(xiàn)方法。小編覺(jué)得挺不錯(cuò)的,現(xiàn)在就分享給大家,也給大家做個(gè)參考。一起跟隨小編過(guò)來(lái)看看吧2016-10-10MySQL執(zhí)行事務(wù)的語(yǔ)法與流程詳解
這篇文章主要介紹了MySQL執(zhí)行事務(wù)的語(yǔ)法與流程的相關(guān)資料,文中通過(guò)圖文介紹的非常詳細(xì),對(duì)大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價(jià)值,需要的朋友們下面隨著小編來(lái)一起學(xué)習(xí)學(xué)習(xí)吧2021-01-01