From 66d42f4fe6fb59b3495a9a34f0fc4ef4602d5b89 Mon Sep 17 00:00:00 2001 From: Ran Date: Tue, 1 Aug 2023 10:52:40 +0800 Subject: [PATCH 1/5] Add temp.md --- temp.md | 1 + 1 file changed, 1 insertion(+) create mode 100644 temp.md diff --git a/temp.md b/temp.md new file mode 100644 index 0000000000000..af27ff4986a7b --- /dev/null +++ b/temp.md @@ -0,0 +1 @@ +This is a test file. \ No newline at end of file From b39aa4e1d3c61b5de7e2590fd407e99128321bc2 Mon Sep 17 00:00:00 2001 From: Ran Date: Tue, 1 Aug 2023 10:52:44 +0800 Subject: [PATCH 2/5] Delete temp.md --- temp.md | 1 - 1 file changed, 1 deletion(-) delete mode 100644 temp.md diff --git a/temp.md b/temp.md deleted file mode 100644 index af27ff4986a7b..0000000000000 --- a/temp.md +++ /dev/null @@ -1 +0,0 @@ -This is a test file. \ No newline at end of file From eaadec12860d881beab2815728c62baf95fcd31a Mon Sep 17 00:00:00 2001 From: Ran Date: Tue, 1 Aug 2023 15:58:23 +0800 Subject: [PATCH 3/5] add translation Signed-off-by: Ran --- optimizer-hints.md | 50 ++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 50 insertions(+) diff --git a/optimizer-hints.md b/optimizer-hints.md index c398097f7e10c..f17b317d9010e 100644 --- a/optimizer-hints.md +++ b/optimizer-hints.md @@ -96,6 +96,14 @@ select /*+ MERGE_JOIN(t1, t2) */ * from t1, t2 where t1.id = t2.id; > > `TIDB_SMJ` is the alias for `MERGE_JOIN` in TiDB 3.0.x and earlier versions. If you are using any of these versions, you must apply the `TIDB_SMJ(t1_name [, tl_name ...])` syntax for the hint. For the later versions of TiDB, `TIDB_SMJ` and `MERGE_JOIN` are both valid names for the hint, but `MERGE_JOIN` is recommended. +### NO_MERGE_JOIN(t1_name [, tl_name ...]) + +The `NO_MERGE_JOIN(t1_name [, tl_name ...])` hint tells the optimizer not to use the sort-merge join algorithm for the given table(s). For example: + +```sql +SELECT /*+ NO_MERGE_JOIN(t1, t2) */ * FROM t1, t2 WHERE t1.id = t2.id; +``` + ### INL_JOIN(t1_name [, tl_name ...]) The `INL_JOIN(t1_name [, tl_name ...])` hint tells the optimizer to use the index nested loop join algorithm for the given table(s). This algorithm might consume less system resources and take shorter processing time in some scenarios and might produce an opposite result in other scenarios. If the result set is less than 10,000 rows after the outer table is filtered by the `WHERE` condition, it is recommended to use this hint. For example: @@ -112,10 +120,30 @@ The parameter(s) given in `INL_JOIN()` is the candidate table for the inner tabl > > `TIDB_INLJ` is the alias for `INL_JOIN` in TiDB 3.0.x and earlier versions. If you are using any of these versions, you must apply the `TIDB_INLJ(t1_name [, tl_name ...])` syntax for the hint. For the later versions of TiDB, `TIDB_INLJ` and `INL_JOIN` are both valid names for the hint, but `INL_JOIN` is recommended. +### NO_INDEX_JOIN(t1_name [, tl_name ...]) + +The `NO_INDEX_JOIN(t1_name [, tl_name ...])` hint tells the optimizer not to use the index nested loop join algorithm for the given table(s). For example: + +```sql +SELECT /*+ NO_INDEX_JOIN(t1, t2) */ * FROM t1, t2 WHERE t1.id = t2.id; +``` + ### INL_HASH_JOIN The `INL_HASH_JOIN(t1_name [, tl_name])` hint tells the optimizer to use the index nested loop hash join algorithm. The conditions for using this algorithm are the same with the conditions for using the index nested loop join algorithm. The difference between the two algorithms is that `INL_JOIN` creates a hash table on the joined inner table, but `INL_HASH_JOIN` creates a hash table on the joined outer table. `INL_HASH_JOIN` has a fixed limit on memory usage, while the memory used by `INL_JOIN` depends on the number of rows matched in the inner table. +### NO_INDEX_HASH_JOIN(t1_name [, tl_name ...]) + +The `NO_INDEX_HASH_JOIN(t1_name [, tl_name ...])` hint tells the optimizer not to use the index nested loop hash join algorithm for the given table(s). + +### INL_MERGE_JOIN + +The `INL_MERGE_JOIN(t1_name [, tl_name])` hint tells the optimizer to use the index nested loop merge join algorithm. The conditions for using this algorithm are the same with the conditions for using the index nested loop join algorithm. + +### NO_INDEX_MERGE_JOIN(t1_name [, tl_name ...]) + +The `NO_INDEX_MERGE_JOIN(t1_name [, tl_name ...])` hint tells the optimizer not to use the index nested loop merge join algorithm for the given table(s). + ### HASH_JOIN(t1_name [, tl_name ...]) The `HASH_JOIN(t1_name [, tl_name ...])` hint tells the optimizer to use the hash join algorithm for the given table(s). This algorithm allows the query to be executed concurrently with multiple threads, which achieves a higher processing speed but consumes more memory. For example: @@ -130,6 +158,14 @@ select /*+ HASH_JOIN(t1, t2) */ * from t1, t2 where t1.id = t2.id; > > `TIDB_HJ` is the alias for `HASH_JOIN` in TiDB 3.0.x and earlier versions. If you are using any of these versions, you must apply the `TIDB_HJ(t1_name [, tl_name ...])` syntax for the hint. For the later versions of TiDB, `TIDB_HJ` and `HASH_JOIN` are both valid names for the hint, but `HASH_JOIN` is recommended. +### NO_HASH_JOIN(t1_name [, tl_name ...]) + +The `NO_HASH_JOIN(t1_name [, tl_name ...])` hint tells the optimizer not to use the hash join algorithm for the given table(s). For example: + +```sql +SELECT /*+ NO_HASH_JOIN(t1, t2) */ * FROM t1, t2 WHERE t1.id = t2.id; +``` + ### HASH_JOIN_BUILD(t1_name [, tl_name ...]) The `HASH_JOIN_BUILD(t1_name [, tl_name ...])` hint tells the optimizer to use the hash join algorithm on specified tables with these tables working as the build side. In this way, you can build hash tables using specific tables. For example: @@ -821,3 +857,17 @@ EXPLAIN SELECT /*+ leading(t1, t3), inl_join(t3) */ * FROM t1, t2, t3 WHERE t1.i +---------------------------------+----------+-----------+---------------+---------------------------------------------------------------------------------------------------------------------+ 9 rows in set (0.01 sec) ``` + +### Using hints causes the `Can't find a proper physical plan for this query` error + +The `Can't find a proper physical plan for this query` error might occur in the following scenarios: + +- The query itself does not require reading indexes in order. That is, the optimizer does not generate a plan to read indexes in order in any case without using hints. In this case, if the `ORDER_INDEX` hint is specified, this error occurs. To resolve this issue, remove the corresponding `ORDER_INDEX` hint. +- All possible join methods are excluded by using `NO_JOIN` hints. + +```sql +CREATE TABLE t1 (a INT); +CREATE TABLE t2 (a INT); +EXPLAIN SELECT /*+ NO_HASH_JOIN(t1), NO_MERGE_JOIN(t1) */ * FROM t1, t2 WHERE t1.a=t2.a; +ERROR 1815 (HY000): Internal : Can't find a proper physical plan for this query +``` From 119d2a38fcc097d58b6af55b2fb1834c769db7c3 Mon Sep 17 00:00:00 2001 From: Ran Date: Thu, 3 Aug 2023 16:44:20 +0800 Subject: [PATCH 4/5] Update optimizer-hints.md Co-authored-by: Grace Cai --- optimizer-hints.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/optimizer-hints.md b/optimizer-hints.md index f17b317d9010e..097448f066bd7 100644 --- a/optimizer-hints.md +++ b/optimizer-hints.md @@ -862,7 +862,7 @@ EXPLAIN SELECT /*+ leading(t1, t3), inl_join(t3) */ * FROM t1, t2, t3 WHERE t1.i The `Can't find a proper physical plan for this query` error might occur in the following scenarios: -- The query itself does not require reading indexes in order. That is, the optimizer does not generate a plan to read indexes in order in any case without using hints. In this case, if the `ORDER_INDEX` hint is specified, this error occurs. To resolve this issue, remove the corresponding `ORDER_INDEX` hint. +- A query itself does not require reading indexes in order. That is, for this query, the optimizer does not generate a plan to read indexes in order in any case without using hints. In this case, if the `ORDER_INDEX` hint is specified, this error occurs. To resolve this issue, remove the corresponding `ORDER_INDEX` hint. - All possible join methods are excluded by using `NO_JOIN` hints. ```sql From d9d369165ba0acf43fc84f80307c46cbb81e6569 Mon Sep 17 00:00:00 2001 From: Ran Date: Thu, 3 Aug 2023 16:44:31 +0800 Subject: [PATCH 5/5] Update optimizer-hints.md Co-authored-by: Grace Cai --- optimizer-hints.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/optimizer-hints.md b/optimizer-hints.md index 097448f066bd7..1e5afafd00fe6 100644 --- a/optimizer-hints.md +++ b/optimizer-hints.md @@ -863,7 +863,7 @@ EXPLAIN SELECT /*+ leading(t1, t3), inl_join(t3) */ * FROM t1, t2, t3 WHERE t1.i The `Can't find a proper physical plan for this query` error might occur in the following scenarios: - A query itself does not require reading indexes in order. That is, for this query, the optimizer does not generate a plan to read indexes in order in any case without using hints. In this case, if the `ORDER_INDEX` hint is specified, this error occurs. To resolve this issue, remove the corresponding `ORDER_INDEX` hint. -- All possible join methods are excluded by using `NO_JOIN` hints. +- A query excludes all possible join methods by using the `NO_JOIN` related hints. ```sql CREATE TABLE t1 (a INT);