DROP [GLOBAL|SESSION] BINDING

This statement removes a binding from a specific SQL statement. Bindings can be used to inject a hint into a statement without requiring changes to the underlying query.

A BINDING can be on either a GLOBAL or SESSION basis. The default is SESSION.

Synopsis

DropBindingStmt
DROPGlobalScopeBINDINGFORBindableStmtUSINGBindableStmtSQLDIGESTSqlDigest
GlobalScope
GLOBALSESSION
BindableStmt
SelectStmtUpdateStmtInsertIntoStmtReplaceIntoStmtDeleteStmt

Examples

You can remove a binding according to a SQL statement or sql_digest.

The following example shows how to remove a binding according to a SQL statement.

mysql> CREATE TABLE t1 ( -> id INT NOT NULL PRIMARY KEY auto_increment, -> b INT NOT NULL, -> pad VARBINARY(255), -> INDEX(b) -> ); Query OK, 0 rows affected (0.07 sec) mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM dual; Query OK, 1 row affected (0.01 sec) Records: 1 Duplicates: 0 Warnings: 0 mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; Query OK, 1 row affected (0.00 sec) Records: 1 Duplicates: 0 Warnings: 0 mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; Query OK, 8 rows affected (0.00 sec) Records: 8 Duplicates: 0 Warnings: 0 mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; Query OK, 1000 rows affected (0.04 sec) Records: 1000 Duplicates: 0 Warnings: 0 mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; Query OK, 100000 rows affected (1.74 sec) Records: 100000 Duplicates: 0 Warnings: 0 mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; Query OK, 100000 rows affected (2.15 sec) Records: 100000 Duplicates: 0 Warnings: 0 mysql> INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; Query OK, 100000 rows affected (2.64 sec) Records: 100000 Duplicates: 0 Warnings: 0 mysql> SELECT SLEEP(1); +----------+ | SLEEP(1) | +----------+ | 0 | +----------+ 1 row in set (1.00 sec) mysql> ANALYZE TABLE t1; Query OK, 0 rows affected (1.33 sec) mysql> EXPLAIN ANALYZE SELECT * FROM t1 WHERE b = 123; +-------------------------------+---------+---------+-----------+----------------------+---------------------------------------------------------------------------+-----------------------------------+----------------+------+ | id | estRows | actRows | task | access object | execution info | operator info | memory | disk | +-------------------------------+---------+---------+-----------+----------------------+---------------------------------------------------------------------------+-----------------------------------+----------------+------+ | IndexLookUp_10 | 583.00 | 297 | root | | time:10.545072ms, loops:2, rpc num: 1, rpc time:398.359µs, proc keys:297 | | 109.1484375 KB | N/A | | ├─IndexRangeScan_8(Build) | 583.00 | 297 | cop[tikv] | table:t1, index:b(b) | time:0s, loops:4 | range:[123,123], keep order:false | N/A | N/A | | └─TableRowIDScan_9(Probe) | 583.00 | 297 | cop[tikv] | table:t1 | time:12ms, loops:4 | keep order:false | N/A | N/A | +-------------------------------+---------+---------+-----------+----------------------+---------------------------------------------------------------------------+-----------------------------------+----------------+------+ 3 rows in set (0.02 sec) mysql> CREATE SESSION BINDING FOR -> SELECT * FROM t1 WHERE b = 123 -> USING -> SELECT * FROM t1 IGNORE INDEX (b) WHERE b = 123; Query OK, 0 rows affected (0.00 sec) mysql> EXPLAIN ANALYZE SELECT * FROM t1 WHERE b = 123; +-------------------------+-----------+---------+-----------+---------------+--------------------------------------------------------------------------------+--------------------+---------------+------+ | id | estRows | actRows | task | access object | execution info | operator info | memory | disk | +-------------------------+-----------+---------+-----------+---------------+--------------------------------------------------------------------------------+--------------------+---------------+------+ | TableReader_7 | 583.00 | 297 | root | | time:222.32506ms, loops:2, rpc num: 1, rpc time:222.078952ms, proc keys:301010 | data:Selection_6 | 88.6640625 KB | N/A | | └─Selection_6 | 583.00 | 297 | cop[tikv] | | time:224ms, loops:298 | eq(test.t1.b, 123) | N/A | N/A | | └─TableFullScan_5 | 301010.00 | 301010 | cop[tikv] | table:t1 | time:220ms, loops:298 | keep order:false | N/A | N/A | +-------------------------+-----------+---------+-----------+---------------+--------------------------------------------------------------------------------+--------------------+---------------+------+ 3 rows in set (0.22 sec) mysql> SHOW SESSION BINDINGS\G *************************** 1. row *************************** Original_sql: select * from t1 where b = ? Bind_sql: SELECT * FROM t1 IGNORE INDEX (b) WHERE b = 123 Default_db: test Status: using Create_time: 2020-05-22 14:38:03.456 Update_time: 2020-05-22 14:38:03.456 Charset: utf8mb4 Collation: utf8mb4_0900_ai_ci 1 row in set (0.00 sec) mysql> DROP SESSION BINDING FOR SELECT * FROM t1 WHERE b = 123; Query OK, 0 rows affected (0.00 sec) mysql> EXPLAIN ANALYZE SELECT * FROM t1 WHERE b = 123; +-------------------------------+---------+---------+-----------+----------------------+-------------------------------------------------------------------------+-----------------------------------+----------------+------+ | id | estRows | actRows | task | access object | execution info | operator info | memory | disk | +-------------------------------+---------+---------+-----------+----------------------+-------------------------------------------------------------------------+-----------------------------------+----------------+------+ | IndexLookUp_10 | 583.00 | 297 | root | | time:5.31206ms, loops:2, rpc num: 1, rpc time:665.927µs, proc keys:297 | | 109.1484375 KB | N/A | | ├─IndexRangeScan_8(Build) | 583.00 | 297 | cop[tikv] | table:t1, index:b(b) | time:0s, loops:4 | range:[123,123], keep order:false | N/A | N/A | | └─TableRowIDScan_9(Probe) | 583.00 | 297 | cop[tikv] | table:t1 | time:0s, loops:4 | keep order:false | N/A | N/A | +-------------------------------+---------+---------+-----------+----------------------+-------------------------------------------------------------------------+-----------------------------------+----------------+------+ 3 rows in set (0.01 sec) mysql> SHOW SESSION BINDINGS\G Empty set (0.00 sec)

The following example shows how to remove a binding according to sql_digest.

mysql> CREATE TABLE t(id INT PRIMARY KEY , a INT, KEY(a)); Query OK, 0 rows affected (0.06 sec) mysql> SELECT /*+ IGNORE_INDEX(t, a) */ * FROM t WHERE a = 1; Empty set (0.01 sec) mysql> SELECT plan_digest FROM INFORMATION_SCHEMA.STATEMENTS_SUMMARY WHERE QUERY_SAMPLE_TEXT = 'SELECT /*+ IGNORE_INDEX(t, a) */ * FROM t WHERE a = 1'; +------------------------------------------------------------------+ | plan_digest | +------------------------------------------------------------------+ | 4e3159169cc63c14b139a4e7d72eae1759875c9a9581f94bb2079aae961189cb | +------------------------------------------------------------------+ 1 row in set (0.01 sec) mysql> CREATE BINDING FROM HISTORY USING PLAN DIGEST '4e3159169cc63c14b139a4e7d72eae1759875c9a9581f94bb2079aae961189cb'; Query OK, 0 rows affected (0.02 sec) mysql> SELECT * FROM t WHERE a = 1; Empty set (0.01 sec) mysql> SELECT @@LAST_PLAN_FROM_BINDING; +--------------------------+ | @@LAST_PLAN_FROM_BINDING | +--------------------------+ | 1 | +--------------------------+ 1 row in set (0.01 sec) mysql> SHOW BINDINGS\G; *************************** 1. row *************************** Original_sql: select * from `test` . `t` where `a` = ? Bind_sql: SELECT /*+ use_index(@`sel_1` `test`.`t` ) ignore_index(`t` `a`)*/ * FROM `test`.`t` WHERE `a` = 1 Default_db: test Status: enabled Create_time: 2022-12-14 15:26:22.277 Update_time: 2022-12-14 15:26:22.277 Charset: utf8mb4 Collation: utf8mb4_general_ci Source: history Sql_digest: 6909a1bbce5f64ade0a532d7058dd77b6ad5d5068aee22a531304280de48349f Plan_digest: 4e3159169cc63c14b139a4e7d72eae1759875c9a9581f94bb2079aae961189cb 1 row in set (0.02 sec) ERROR: No query specified mysql> DROP BINDING FOR SQL DIGEST '6909a1bbce5f64ade0a532d7058dd77b6ad5d5068aee22a531304280de48349f'; Query OK, 0 rows affected (0.00 sec) mysql> SHOW BINDINGS\G; Empty set (0.01 sec) ERROR: No query specified

MySQL compatibility

This statement is a TiDB extension to MySQL syntax.

See also