Before MySQL 4.0.2, the only means of limiting use of MySQL server
resources is to set the global
max_user_connections
system
variable to a nonzero value. This limits the number of
simultaneous connections that can be made by any given account,
but places no limits on what a client can do once connected. In
addition, this method is strictly global, and does not allow for
management of individual accounts. Both types of control are of
interest to many MySQL administrators, particularly those working
for Internet Service Providers.
Starting from MySQL 4.0.2, you can limit access to the following server resources for individual accounts:
The number of queries that an account can issue per hour
The number of updates that an account can issue per hour
The number of times an account can connect to the server per hour
Any statement that a client can issue counts against the query limit (unless its results are served from the query cache). Only statements that modify databases or tables count against the update limit.
An “account” in this context is assessed against the
actual host from which a user connects. Suppose that there is a
row in the user
table that has
User
and Host
values of
usera
and %.example.com
, to
allow usera
to connect from any host in the
example.com
domain. If usera
connects simultaneously from host1.example.com
and host2.example.com
, the server applies the
account resource limits separately to each connection. If
usera
connects again from
host1.example.com
, the server applies the
limits for that connection together with the existing connection
from that host.
The server limits account resources based on the resource-related
columns of the user
table in the
mysql
database:
max_questions
, max_updates
,
max_connections
, and
max_user_connections
. If your
user
table does not have these columns, it must
be upgraded; see Section 4.4.5, “mysql_fix_privilege_tables — Upgrade MySQL System Tables”.
To set resource limits for an account, use the
GRANT
statement (see
Section 12.4.1.2, “GRANT
Syntax”). Provide a WITH
clause
that names each resource to be limited. For example, to create a
new account that can access the customer
database, but only in a limited fashion, issue this statement:
mysql>GRANT ALL ON customer.* TO 'francis'@'localhost'
->IDENTIFIED BY 'frank'
->WITH MAX_QUERIES_PER_HOUR 20
->MAX_UPDATES_PER_HOUR 10
->MAX_CONNECTIONS_PER_HOUR 5;
The limit types need not all be named in the
WITH
clause, but those named can be present in
any order. The value for each per-hour limit should be an integer
representing a count per hour. If the
GRANT
statement has no
WITH
clause, the limits are each set to the
default value of zero (that is, no limit).
To modify existing limits for an account, use a
GRANT USAGE
statement at the global level (ON *.*
). The
following statement changes the query limit for
francis
to 100:
mysql>GRANT USAGE ON *.* TO 'francis'@'localhost'
->WITH MAX_QUERIES_PER_HOUR 100;
The statement modifies only the limit value specified and leaves the account otherwise unchanged.
To remove a limit, set its value to zero. For example, to remove
the limit on how many times per hour francis
can connect, use this statement:
mysql>GRANT USAGE ON *.* TO 'francis'@'localhost'
->WITH MAX_CONNECTIONS_PER_HOUR 0;
The server stores resource limits for an account in the
user
table row corresponding to the account.
The max_questions
,
max_updates
, and
max_connections
columns store the per-hour
limits. (See Section 5.5.2, “Privilege System Grant Tables”.)
Resource-use counting takes place when any account has a nonzero limit placed on its use of any of the resources.
As the server runs, it counts the number of times each account uses resources. If an account reaches its limit on number of connections within the last hour, further connections for the account are rejected until that hour is up. Similarly, if the account reaches its limit on the number of queries or updates, further queries or updates are rejected until the hour is up. In all such cases, an appropriate error message is issued.
The current per-hour resource-use counts can be reset globally for all accounts, or individually for a given account:
To reset the current counts to zero for all accounts, issue a
FLUSH
USER_RESOURCES
statement. The counts also can be
reset by reloading the grant tables (for example, with a
FLUSH
PRIVILEGES
statement or a mysqladmin
reload command).
The counts for an individual account can be set to zero by
re-granting it any of its limits. To do this, use
GRANT USAGE
as described earlier and specify a limit value equal to the
value that the account currently has.
All counts begin at zero when the server starts; counts are not carried over through a restart.
User Comments
There doesn't appear to be a way to get the current number of queries, updates, etc. e.g. to use in a dashboard. For that, you have to roll your own.
Add your own comment.