Skip to content

Commit

Permalink
FB8-59: Database admission control (facebook#969) (facebook#969)
Browse files Browse the repository at this point in the history
Summary:
JIRA: https://jira.percona.com/browse/FB8-59

Reference patch: facebook@5cbfab0
Reference patch: facebook@0ebaf75
Reference patch: facebook@cf7ce48
Reference patch: facebook@3842a8f
Reference patch: facebook@bcbd77a
Reference patch: facebook@e6c2b87
Reference patch: facebook@928c2a5
Reference patch: facebook@86587af
Reference patch: facebook@7870828
Reference patch: facebook@0151b45
Reference patch: facebook@75de821
Reference patch: facebook@08d4174
Reference patch: facebook@c1e5b4f
Reference patch: facebook@08368d4
Reference patch: facebook@a2198e0
Reference patch: facebook@0730342
Reference patch: facebook@d868c1b
Reference patch: facebook@645fc5e
Reference patch: facebook@0b130f1ebc9
Reference patch: facebook@f49a4a74945

<Comment by Percona developers>

This patch ports Database admission control. The multi-tenancy plugin
changes are not ported. This code will be eventually moved to new plugin
of audit type.

There are possible improvements with code. Below are the deferred items
(makes it easier for review. Can compare with 5.6 code)

1. Remove MT_RESOURCE_ATTRS. we only need database name (also removes the typedefs)
2. Remove enums enum_multi_tenancy_resource_type & enum_multi_tenancy_return_type
3. Remove the usage of 'multi tenancy' word

thd->is_real_trans is not ported from 5.6. Instead an equivalent is used. This is
verified in 5.6 and it works well. (5.6 equivalent is:
 thd->transaction.all.ha_list == NULL;)

"!thd->get_transaction()->is_active(Transaction_ctx::SESSION)" is used instead of
thd->is_real_trans.

The above check seems sufficient but after porting thd->is_real_trans, it should be
possible to replace the above check with thd->is_real_trans
</end>

-------  facebook@5cbfab0 --------

Add two global sys vars max_running_queries and max_waiting_queries.
They control maximum number of running queries on a database and maximum
waiting queries when max_running_queries limit is crossed on that database.
A value of 0 implies no limits are applied for the queries. If max_waiting_queries
limit is crossed, then new queries will simply fail.

For waiting threads SHOW PROCESSLIST will show the state as 'waiting for admission'.
Only dagtabase set at the session level is considered in these checks. Admission checks
are by-passed in the following cases
1. Query is run by super user.
2. Query is run by replication threads.
3. No database is set for the session.
4. max_running_queries is 0.

Performance testing

1. start MySQL using mtr
> mtr --start --mysqld=--default_storage_engine=InnoDB

2. Connect to mysql using
> mysql --socket=mysql-test/var/tmp/mysqld.1.sock --user=root

3. Set innodb_flush_log_at_trx_commit=2.
mysql> set global.innodb_flush_log_at_trx_commit=2

4. Check rows inserted using
> mysqladmin extended-status --user=root -i 1 -r --socket=mysql-test/var/tmp/mysqld.1.sock status | grep "Innodb_rows_inserted"

5. Run mysqlslap using
> mysqlslap --auto-generate-sql --number-of-queries=5000000 --concurrency=$concurrency --auto-generate-sql-load-type=write --auto-generate-sql-add-autoincrement --csv=a --user=root --socket=mysql-test/var/tmp/mysqld.1.sock

== Innodb_rows_inserted with concurrency=100 ==
38106 (max_running_queries=0, max_waiting_queries=0)
38733 (max_running_queries=1000, max_waiting_queries=0)
38365 (max_running_queries=100, max_waiting_queries=0)
40308 (max_running_queries=70, max_waiting_queries=0)
43790 (max_running_queries=50, max_waiting_queries=0)
47321 (max_running_queries=20, max_waiting_queries=0)
49473 (max_running_queries=10, max_waiting_queries=0)
54851 (max_running_queries=5, max_waiting_queries=0)

== Innodb_rows_inserted with concurrency=100 ==
26516 (max_running_queries=0, max_waiting_queries=0)
44494 (max_running_queries=10, max_waiting_queries=0)
51193 (max_running_queries=5, max_waiting_queries=0)

The above numbers show the improvement in quality of service.

== Innodb_rows_inserted with concurrency=20 ==
47228 (max_running_queries=0, max_waiting_queries=0)
47107 (max_running_queries=100, max_waiting_queries=0)
47082 (max_running_queries=20, max_waiting_queries=0)
47515 (max_running_queries=10, max_waiting_queries=0)

* There isn't much difference under low concurrency workloads.

* There isn't much difference with non zero max_waiting_queries values greater than max_running_queries. With values lower than max_running_queries, lots of queries simply fail, so the qps in this scenario is of no value.

Original Reviewers: tianx, kradhakrishnan, jtolmer, jkedgar

-----  facebook@0ebaf75 -----

Added the following status variables:

1. Database_admission_control_aborted_queries gives the total number of queries aborted because of queue overfill.
2. Database_admission_control_running_queries gives the total number of running queries across all the databases.
3. Database_admission_control_waiting_queries gives the total number of waiting queries across all the databases.

-----  facebook@cf7ce48 ------

In order to avoid possible mysqld hangs, we need an option to blacklist
specific commands in admission control. Example usage is

  set global.admission_control_filter='BEGIN,COMMIT,SET';

An empty value for admission_control_filter implies no commands are blacklisted
in the admission control.

---- facebook@bcbd77a ------

Initial version of admission control applied limits on each query statement in multi
query packet. The behavior is modified to the following:

A thread enters admission control when executing the first non-filtered command
in the multi query packet and exits after executing all the query statements in
the multi query packet.

This diff also fixes a bug where admission control limits are not initialized during
mysqld startup.

----- facebook@928c2a5 --------
Get accurate status variables

Hold global admission control locks to get accurate value of running/waiting queries. Initial stats were
not accurate causing test failures

------- facebook@86587af -----------

Added SHOW command filter in admission control.

-------  facebook@7870828 ------

The original ac_map was a map of unique_ptr<Ac_info>.  When accessing the value we had to use a reference to the value.  This diff changes that so that we use a shared_ptr<Ac_info> instead so we can just pass it around have have reference counting automatically.

---- facebook@75de821 ------
Fixing the following two issues in admission control when changing database is
in a multi-statement query:
- If the session hasn't set a database, admission control will allow arbitrary
  number of multi-query packet to run, even the packet starts with `use
  [db_name]`.
- If the session already has a default database, the admission control will use
  the limit of the default database, even if we change database in the
  multi-query packet.

This diff fixes the above issues in the following way:
- The admission control flag (is_in_ac) is reset when a `use` command is
  executed. So in the multi-statement query, the subsequent sub-queries are not
  bypassed.
- Admission control uses the `thd->db` directly instead of attribute map, so
  the attribute map doesn't need to store the session database.
- `USE [db_name]` statement is added to `admission_control_filter`.

In addition, I also changed the multitenancy plugin interface to use a wrapper
object to pass down the connection_attrs_map, query_attrs_map, and session
database info. Attribute maps will not be modified.

--------- facebook@c1e5b4f  --------

Fix resource leaks by admission_control_by_trx

- Rollback will need to mark is_real_trans
- Query resource needs to be released when THD is terminated.
Pull Request resolved: facebook#969

Reviewed By: lloyd

Differential Revision: D14567747 (facebook@03e9575)

Pulled By: lth

fbshipit-source-id: 5c1fdbde73c
  • Loading branch information
satya-bodapati authored and inikep committed Jul 16, 2021
1 parent c556804 commit d31f8c3
Show file tree
Hide file tree
Showing 33 changed files with 2,603 additions and 6 deletions.
115 changes: 115 additions & 0 deletions mysql-test/r/admission_control.result
@@ -0,0 +1,115 @@
create database test_db;
create user 'test_user'@'localhost';
grant all on test_db.* to 'test_user'@'localhost';
grant all on test.* to 'test_user'@'localhost';
use test_db;
set @start_max_running_queries= @@global.max_running_queries;
set @start_max_waiting_queries= @@global.max_waiting_queries;
set @@global.max_running_queries=10;
set @@global.max_waiting_queries=5;
create table t1(a int) engine=InnoDB;
lock table t1 write;
Threads waiting for admission will have appropriate state set in processlist.
Super user is exempted from admission control checks.
select * from t1;
a
set @@global.admission_control_filter = 'USE';
select @@global.admission_control_filter;
@@global.admission_control_filter
USE
Maximum waiting queries reached. So this would hit an error.
use test_db;
select * from t1||||
ERROR HY000: Maximum waiting queries 5 reached for database `test_db`
Maximum waiting queries reached. So this would hit an error.
use test;
create table t1_test(aaa int);
insert into t1_test values (1);
select aaa from t1_test;
drop table t1_test;
use test_db;
select * from t1||||
aaa
1
ERROR HY000: Maximum waiting queries 5 reached for database `test_db`
use test_db;
select * from t1;
ERROR HY000: Maximum waiting queries 5 reached for database `test_db`
set @@global.admission_control_filter = '';
select @@global.admission_control_filter;
@@global.admission_control_filter

Check status variables
aborted_queries = 3
running_queries = 10
waiting_queries = 5
Filled up queues on one db doesn't affect queries on other db.
use test;
set @@global.max_waiting_queries=6;
Kill a thread that is waiting for admission.
select count(*) from t1;
kill ID;
use test_db;
unlock tables;
Verify the waiting queries received wakeup signal.
select count(*) from t1;
count(*)
15
set @save_admission_control_by_trx = @@global.admission_control_by_trx;
select @save_admission_control_by_trx;
@save_admission_control_by_trx
0
set @@global.max_running_queries=5;
set @@global.max_waiting_queries=10;
# By default, open transaction has no effect on running queries
select count(*) from t1;
count(*)
15
# Test: open transactions will take slots in running queries,
# and will not be blocked
set @@global.admission_control_filter = 'BEGIN,COMMIT,ROLLBACK';
select @@global.admission_control_filter;
@@global.admission_control_filter
BEGIN,COMMIT,ROLLBACK
set @@global.admission_control_by_trx = true;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
1
Open transaction is able to continue running queries
connection con_max_wait;
New queries will be rejected (waiting queue is full)
select * from t1;
ERROR HY000: Maximum waiting queries 10 reached for database `test_db`
New transactions will be rejected (waiting queue is full)
begin;
select * from t1;
ERROR HY000: Maximum waiting queries 10 reached for database `test_db`
aborted_queries will increase by 2
Committing a transaction will free up the running query slots
The waiting queries will be unblocked
Check status variables
include/assert.inc [DB Admission control waiting queries should be zero]
include/assert.inc [DB Admission control running queries should be zero]
include/assert.inc [DB Admission control aborted queries should be five]
set @@global.admission_control_by_trx = @save_admission_control_by_trx;
select @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
set @@global.admission_control_filter = '';
select @@global.admission_control_filter;
@@global.admission_control_filter

# End of open transaction test
reset global.max_running_queries and global.max_waiting_queries
set @@global.max_running_queries=10;
set @@global.max_waiting_queries=5;
Run parallel load and drop the database.
set @@global.max_waiting_queries=0;
Cleanup.
Verify there are no waiting threads.
select count(*) from information_schema.processlist where state='waiting for admission';
count(*)
0
set @@global.max_running_queries=@start_max_running_queries;
set @@global.max_waiting_queries=@start_max_waiting_queries;
drop user test_user@localhost;
93 changes: 93 additions & 0 deletions mysql-test/r/admission_control_hang.result
@@ -0,0 +1,93 @@
create database test_db;
create user test_user@localhost;
grant all on test_db.* to test_user@localhost;
set @start_max_running_queries = @@global.max_running_queries;
set @@global.max_running_queries = 4;
set @start_innodb_lock_wait_timeout = @@global.innodb_lock_wait_timeout;
set @@global.innodb_lock_wait_timeout = 10000;
set @start_admission_control_filter = @@global.admission_control_filter;
set @@global.admission_control_filter = 'COMMIT';
create table t1 (a int) engine=innodb;
insert into t1 values(1);
begin;
update t1 set a=2 where a=1;
update t1 set a=2 where a=1;
update t1 set a=2 where a=1;
update t1 set a=2 where a=1;
update t1 set a=2 where a=1;
set @@global.admission_control_filter = 'USE';
select @@global.admission_control_filter;
@@global.admission_control_filter
USE
use test;
use test_db;
set @@global.admission_control_filter = 'ALTER,BEGIN,COMMIT,CREATE,DELETE,DROP,INSERT,LOAD,SELECT,SET,REPLACE,TRUNCATE,UPDATE,SHOW,ROLLBACK';
select @@global.admission_control_filter;
@@global.admission_control_filter
ALTER,BEGIN,COMMIT,CREATE,DELETE,DROP,INSERT,LOAD,SELECT,SET,REPLACE,ROLLBACK,TRUNCATE,UPDATE,SHOW
create table t2(a int) engine=innodb;
begin;
insert into t2 values(1);
update t2 set a=2 where a=1;
commit;
SHOW TABLES LIKE 't2';
Tables_in_test_db (t2)
t2
begin;
alter table t2 rename t3;
select * from t3;
a
2
delete from t3;
set @val = 1;
truncate table t3;
rollback;
drop table t3;
set @save_admission_control_by_trx = @@global.admission_control_by_trx;
select @save_admission_control_by_trx;
@save_admission_control_by_trx
0
# Turn on admission_control_by_trx
set @@global.admission_control_by_trx = true;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
1
create table t2(a int) engine=innodb;
begin;
insert into t2 values(1);
update t2 set a=2 where a=1;
commit;
SHOW TABLES LIKE 't2';
Tables_in_test_db (t2)
t2
begin;
alter table t2 rename t3;
select * from t3;
a
2
delete from t3;
set @val = 1;
truncate table t3;
rollback;
drop table t3;
set @@global.admission_control_filter = default;
select @@global.admission_control_filter;
@@global.admission_control_filter

select count(*) from t1;
count(*)
1
set @@global.admission_control_by_trx = @save_admission_control_by_trx;
select @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
set @@global.admission_control_filter = 'COMMIT';
select @@global.admission_control_filter;
@@global.admission_control_filter
COMMIT
commit;
set @@global.max_running_queries = @start_max_running_queries;
set @@global.innodb_lock_wait_timeout = @start_innodb_lock_wait_timeout;
set @@global.admission_control_filter = @start_admission_control_filter;
drop database test_db;
drop user test_user@localhost;
8 changes: 8 additions & 0 deletions mysql-test/r/admission_control_multi_query.result
@@ -0,0 +1,8 @@
create database test_db;
create user test_user@localhost identified with 'mysql_native_password' BY '';
grant all on test_db.* to test_user@localhost;
grant all on test.* to test_user@localhost;
use test_db;
create table t1 (a int primary key, b int) engine=InnoDB;
drop database test_db;
drop user test_user@localhost;
5 changes: 5 additions & 0 deletions mysql-test/r/admission_control_stress.result
@@ -0,0 +1,5 @@
Test setup.
Generate load. Toggle max_running_queries and randomly kill a query.
Cleanup
set global max_connections = @start_max_connections;
set global max_running_queries = @start_max_running_queries;
3 changes: 3 additions & 0 deletions mysql-test/r/information_schema_ci.result
Expand Up @@ -774,6 +774,9 @@ mysql user 0 0
show status where variable_name like "%database%";
Variable_name Value
Com_show_databases 3
Database_admission_control_aborted_queries 0
Database_admission_control_running_queries 0
Database_admission_control_waiting_queries 0
show variables where variable_name like "skip_show_databas";
Variable_name Value
show global status like "Threads_running";
Expand Down
3 changes: 3 additions & 0 deletions mysql-test/r/information_schema_cs.result
Expand Up @@ -774,6 +774,9 @@ mysql user 0 0
show status where variable_name like "%database%";
Variable_name Value
Com_show_databases 3
Database_admission_control_aborted_queries 0
Database_admission_control_running_queries 0
Database_admission_control_waiting_queries 0
show variables where variable_name like "skip_show_databas";
Variable_name Value
show global status like "Threads_running";
Expand Down
17 changes: 17 additions & 0 deletions mysql-test/r/mysqld--help-notwin.result
Expand Up @@ -43,6 +43,13 @@ The following options may be given as the first argument:
--admin-tls-version=name
TLS version for --admin-port, permitted values are TLSv1,
TLSv1.1, TLSv1.2, TLSv1.3
--admission-control-by-trx
Allow open transactions to go through admission control
--admission-control-filter=name
Commands that are skipped in admission control checks.
The legal values are: ALTER, BEGIN, COMMIT, CREATE,
DELETE, DROP, INSERT, LOAD, SELECT, SET, REPLACE,
ROLLBACK, TRUNCATE, UPDATE, SHOW and empty string
--allow-noncurrent-db-rw=name
Switch to allow/deny reads and writes to a table not in
the current database.
Expand Down Expand Up @@ -704,6 +711,9 @@ The following options may be given as the first argument:
If non-zero: relay log will be rotated automatically when
the size exceeds this value; if zero: when the size
exceeds max_binlog_size
--max-running-queries=#
The maximum number of running queries allowed for a
database. If this value is 0, no such limits are applied.
--max-seeks-for-key=#
Limit assumed max number of seeks when looking up rows
based on a key
Expand All @@ -715,6 +725,9 @@ The following options may be given as the first argument:
--max-user-connections=#
The maximum number of active connections for a single
user (0 = no limit)
--max-waiting-queries=#
The maximum number of waiting queries allowed for a
database.If this value is 0, no such limits are applied.
--max-write-lock-count=#
After this many write locks, allow some read locks to run
in between
Expand Down Expand Up @@ -1583,6 +1596,8 @@ admin-ssl-crl (No default value)
admin-ssl-crlpath (No default value)
admin-ssl-key (No default value)
admin-tls-ciphersuites (No default value)
admission-control-by-trx FALSE
admission-control-filter
allow-noncurrent-db-rw ON
allow-suspicious-udfs FALSE
auto-increment-increment 1
Expand Down Expand Up @@ -1755,10 +1770,12 @@ max-nonsuper-connections 0
max-points-in-geometry 65536
max-prepared-stmt-count 16382
max-relay-log-size 0
max-running-queries 0
max-seeks-for-key 18446744073709551615
max-sort-length 1024
max-sp-recursion-depth 0
max-user-connections 0
max-waiting-queries 0
max-write-lock-count 18446744073709551615
memlock FALSE
min-examined-row-limit 0
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/suite/perfschema/r/dml_setup_instruments.result
Expand Up @@ -21,6 +21,7 @@ where name like 'Wait/Synch/Rwlock/sql/%'
'wait/synch/rwlock/sql/LOCK_named_pipe_full_access_group')
order by name limit 10;
NAME ENABLED TIMED PROPERTIES VOLATILITY DOCUMENTATION
wait/synch/rwlock/sql/AC::rwlock YES YES singleton 0 NULL
wait/synch/rwlock/sql/Binlog_relay_IO_delegate::lock YES YES singleton 0 NULL
wait/synch/rwlock/sql/Binlog_storage_delegate::lock YES YES singleton 0 NULL
wait/synch/rwlock/sql/Binlog_transmit_delegate::lock YES YES singleton 0 NULL
Expand All @@ -30,7 +31,6 @@ wait/synch/rwlock/sql/channel_to_filter_lock YES YES 0 NULL
wait/synch/rwlock/sql/gtid_commit_rollback YES YES singleton 0 NULL
wait/synch/rwlock/sql/gtid_mode_lock YES YES singleton 0 NULL
wait/synch/rwlock/sql/gtid_retrieved YES YES singleton 0 NULL
wait/synch/rwlock/sql/LOCK_sys_init_connect YES YES singleton 0 NULL
select * from performance_schema.setup_instruments
where name like 'Wait/Synch/Cond/sql/%'
and name not in (
Expand Down
42 changes: 42 additions & 0 deletions mysql-test/suite/sys_vars/r/admission_control_by_trx_basic.result
@@ -0,0 +1,42 @@
SET @start_admission_control_by_trx = @@global.admission_control_by_trx;
SELECT @start_admission_control_by_trx;
@start_admission_control_by_trx
0
SET @@global.admission_control_by_trx = DEFAULT;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
SET @@global.admission_control_by_trx = false;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
SET @@global.admission_control_by_trx = true;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
1
SET @@global.admission_control_by_trx = 1;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
1
SET @@global.admission_control_by_trx = 0;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
SET @@global.admission_control_by_trx = -1;
ERROR 42000: Variable 'admission_control_by_trx' can't be set to the value of '-1'
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
SET @@global.admission_control_by_trx = 100;
ERROR 42000: Variable 'admission_control_by_trx' can't be set to the value of '100'
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
SET @@session.admission_control_by_trx = 10;
ERROR HY000: Variable 'admission_control_by_trx' is a GLOBAL variable and should be set with SET GLOBAL
SELECT @@session.admission_control_by_trx;
ERROR HY000: Variable 'admission_control_by_trx' is a GLOBAL variable
SET @@global.admission_control_by_trx = @start_admission_control_by_trx;
SELECT @@global.admission_control_by_trx;
@@global.admission_control_by_trx
0
30 changes: 30 additions & 0 deletions mysql-test/suite/sys_vars/r/admission_control_filter_basic.result
@@ -0,0 +1,30 @@
set @@global.admission_control_filter = default;
select @@global.admission_control_filter;
@@global.admission_control_filter

set @saved_admission_control_filter = @@global.admission_control_filter;
SELECT @@global.admission_control_filter;
@@global.admission_control_filter

SET GLOBAL ADMISSION_CONTROL_FILTER='';
SELECT @@global.admission_control_filter;
@@global.admission_control_filter

SET GLOBAL ADMISSION_CONTROL_FILTER='';
SELECT @@global.admission_control_filter;
@@global.admission_control_filter

SET GLOBAL ADMISSION_CONTROL_FILTER='COMMIT,BEGIN,ALTER';
SELECT @@global.admission_control_filter;
@@global.admission_control_filter
ALTER,BEGIN,COMMIT
SET GLOBAL ADMISSION_CONTROL_FILTER='ALTER,BEGIN,COMMIT,CREATE,DELETE,DROP,INSERT,LOAD,SELECT,SET,REPLACE,TRUNCATE,UPDATE,SHOW';
SELECT @@global.admission_control_filter;
@@global.admission_control_filter
ALTER,BEGIN,COMMIT,CREATE,DELETE,DROP,INSERT,LOAD,SELECT,SET,REPLACE,TRUNCATE,UPDATE,SHOW
SET GLOBAL ADMISSION_CONTROL_FILTER='TRUNCATE,REPLACE,DROP,NONEXISTING_BIT';
ERROR 42000: Variable 'admission_control_filter' can't be set to the value of 'NONEXISTING_BIT'
SELECT @@global.admission_control_filter;
@@global.admission_control_filter
ALTER,BEGIN,COMMIT,CREATE,DELETE,DROP,INSERT,LOAD,SELECT,SET,REPLACE,TRUNCATE,UPDATE,SHOW
set global admission_control_filter = @saved_admission_control_filter;

0 comments on commit d31f8c3

Please sign in to comment.