From f47d9fd60e79fbd8aa42249f3f28d77dc59d770b Mon Sep 17 00:00:00 2001 From: chenbd Date: Wed, 24 May 2023 16:09:20 +0800 Subject: [PATCH] dolphin ignore index request --- doc/src/sgml/ref/select.sgmlin | 2 +- src/common/backend/parser/gram.y | 9 +- src/common/backend/parser/parser.cpp | 28 +- src/gausskernel/optimizer/util/pathnode.cpp | 44 +- src/include/nodes/parsenodes_common.h | 3 +- src/include/optimizer/pathnode.h | 3 + src/test/regress/expected/mysql_indexhint.out | 410 ++++++++++++++++++ src/test/regress/sql/mysql_indexhint.sql | 206 +++++++++ 8 files changed, 687 insertions(+), 18 deletions(-) diff --git a/doc/src/sgml/ref/select.sgmlin b/doc/src/sgml/ref/select.sgmlin index e57abfa47..91a3808c2 100644 --- a/doc/src/sgml/ref/select.sgmlin +++ b/doc/src/sgml/ref/select.sgmlin @@ -71,7 +71,7 @@ SUBPARTITION { ( subpartition_name ) | FOR ( subpartition_value [, ...] )} where nlssort_expression_clause can be: NLSSORT ( column_name, ' NLS_SORT = { SCHINESE_PINYIN_M | generic_m_ci } ' ) where index_hints can be: -FORCE { INDEX | KEY } ( index_name [, ...] ) +{ FORCE | IGNORE } { INDEX | KEY } ( index_name [, ...] ) | USE { INDEX | KEY } ( [ index_name [, ...] ] ) NOTICE: [into_option] is only available in CENTRALIZED mode and B-format database. NOTICE: [index_hints] is only available in CENTRALIZED mode and B-format database. diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index 6da38e9ce..e39236fa3 100644 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -970,7 +970,7 @@ static void setDelimiterName(core_yyscan_t yyscanner, char*input, VariableSetStm END_OF_PROC EVENT_TRIGGER NOT_IN NOT_BETWEEN NOT_LIKE NOT_ILIKE NOT_SIMILAR - FORCE_INDEX USE_INDEX + FORCE_INDEX USE_INDEX IGNORE_INDEX /* Precedence: lowest to highest */ %nonassoc COMMENT @@ -14457,6 +14457,13 @@ index_hint_definition: n->indexnames = $3; $$ = (Node*)n; } + | IGNORE_INDEX '(' key_usage_list ')' + { + IndexHintDefinition* n = makeNode(IndexHintDefinition); + n->index_type = INDEX_HINT_IGNORE; + n->indexnames = $3; + $$ = (Node*)n; + } ; index_hint_list: diff --git a/src/common/backend/parser/parser.cpp b/src/common/backend/parser/parser.cpp index a8b8ce44d..4b7ff6899 100644 --- a/src/common/backend/parser/parser.cpp +++ b/src/common/backend/parser/parser.cpp @@ -619,8 +619,8 @@ int base_yylex(YYSTYPE* lvalp, YYLTYPE* llocp, core_yyscan_t yyscanner) break; case USE_P: /* - * USE INDEX \USE KEY must be reduced to one token,to allow KEY\USE as table / column alias. - */ + * USE INDEX \USE KEY must be reduced to one token,to allow KEY\USE as table / column alias. + */ GET_NEXT_TOKEN(); switch (next_token) { @@ -641,8 +641,8 @@ int base_yylex(YYSTYPE* lvalp, YYLTYPE* llocp, core_yyscan_t yyscanner) break; case FORCE: /* - * FORCE INDEX \FORCE KEY must be reduced to one token,to allow KEY\FORCE as table / column alias. - */ + * FORCE INDEX \FORCE KEY must be reduced to one token,to allow KEY\FORCE as table / column alias. + */ GET_NEXT_TOKEN(); switch (next_token) { @@ -661,6 +661,26 @@ int base_yylex(YYSTYPE* lvalp, YYLTYPE* llocp, core_yyscan_t yyscanner) break; } break; + case IGNORE: + /* + * IGNORE INDEX \IGNORE KEY must be reduced to one token,to allow KEY\IGNORE as table / column alias. + */ + GET_NEXT_TOKEN(); + + switch (next_token) { + case KEY: + case INDEX: + cur_token = IGNORE_INDEX; + break; + default: + /* save the lookahead token for next time */ + SET_LOOKAHEAD_TOKEN(); + /* and back up the output info to cur_token */ + lvalp->core_yystype = cur_yylval; + *llocp = cur_yylloc; + break; + } + break; default: break; } diff --git a/src/gausskernel/optimizer/util/pathnode.cpp b/src/gausskernel/optimizer/util/pathnode.cpp index 6317cc957..54e2891c5 100755 --- a/src/gausskernel/optimizer/util/pathnode.cpp +++ b/src/gausskernel/optimizer/util/pathnode.cpp @@ -1357,18 +1357,28 @@ void set_hint_value(RelOptInfo* join_rel, Path* new_path, HintState* hstate) } } -bool find_index_hint_value(List* indexhintList, Oid pathindexOid, bool* isUse) +/* + * @Description: find index_hint to this new path. + * Level of the ignore index is the highest + */ +bool find_index_hint_value(List* indexhintList, Oid pathindexOid, short* hintMask) { ListCell* lc = NULL; Oid indexOid; + bool result = false; foreach(lc, indexhintList) { indexOid = ((IndexHintRelationData*)lfirst(lc))->indexOid; - *isUse = (((IndexHintRelationData*)lfirst(lc))->index_type == INDEX_HINT_USE); + if (((IndexHintRelationData*)lfirst(lc))->index_type == INDEX_HINT_USE) { + *hintMask |= HINT_MATCH_USE; + } if (pathindexOid == indexOid) { - return true; + if (((IndexHintRelationData*)lfirst(lc))->index_type == INDEX_HINT_IGNORE) { + *hintMask |= HINT_MATCH_IGNORE; + } + result = true; } } - return false; + return result; } void set_index_hint_value(Path* new_path, List* indexhintList) @@ -1376,8 +1386,9 @@ void set_index_hint_value(Path* new_path, List* indexhintList) if (indexhintList == NULL) return ; IndexPath* index_path = (IndexPath*)new_path; - bool useIndex = false; - bool hintUse = false; + bool matchIndex = false; + bool isIndexScan = false; + short hintMask = 0; switch (new_path->pathtype) { case T_SeqScan: @@ -1387,21 +1398,32 @@ void set_index_hint_value(Path* new_path, List* indexhintList) #endif /* ENABLE_MULTIPLE_NODES */ case T_SubqueryScan: case T_ForeignScan: { - useIndex = find_index_hint_value(indexhintList, InvalidOid, &hintUse); + matchIndex = find_index_hint_value(indexhintList, InvalidOid, &hintMask); break; } case T_IndexScan: case T_IndexOnlyScan: { - useIndex = find_index_hint_value(indexhintList, index_path->indexinfo->indexoid, &hintUse); + isIndexScan = true; + matchIndex = find_index_hint_value(indexhintList, index_path->indexinfo->indexoid, &hintMask); break; } default: break; } - if (useIndex) - new_path->hint_value++; - else if (hintUse) + if (matchIndex) { + if ((hintMask & HINT_MATCH_IGNORE) > 0) { + /* ignore index is the top level concerned any hint shoule be reset to zero */ + if (new_path->hint_value > 0) { + new_path->hint_value = 0; + } + new_path->hint_value--; + } else { + new_path->hint_value++; + } + } else if ((hintMask & HINT_MATCH_USE) > 0 && !isIndexScan) { + /* use index should both add seqscan and when matched*/ new_path->hint_value++; + } return ; } diff --git a/src/include/nodes/parsenodes_common.h b/src/include/nodes/parsenodes_common.h index e0d87fd5c..c2ec540ed 100644 --- a/src/include/nodes/parsenodes_common.h +++ b/src/include/nodes/parsenodes_common.h @@ -2465,7 +2465,8 @@ typedef struct AutoIncrement { } AutoIncrement; typedef enum IndexHintType { - INDEX_HINT_USE =1, + INDEX_HINT_IGNORE = 0, + INDEX_HINT_USE = 1, INDEX_HINT_FORCE, INDEX_HINT_MIX, INDEX_HINT_NOT_EXISTS diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h index 6ff21d600..8cce2273a 100644 --- a/src/include/optimizer/pathnode.h +++ b/src/include/optimizer/pathnode.h @@ -24,6 +24,9 @@ #define FUZZY_FACTOR 1.01 #define SMALL_FUZZY_FACTOR 1.0000000001 +/* micros used in index hints check*/ +#define HINT_MATCH_USE 1 +#define HINT_MATCH_IGNORE 2 typedef enum { COSTS_EQUAL, /* path costs are fuzzily equal */ COSTS_BETTER1, /* first path is cheaper than second */ diff --git a/src/test/regress/expected/mysql_indexhint.out b/src/test/regress/expected/mysql_indexhint.out index 040b48621..96363d251 100644 --- a/src/test/regress/expected/mysql_indexhint.out +++ b/src/test/regress/expected/mysql_indexhint.out @@ -454,6 +454,416 @@ explain (costs off)select user_no from list_list subpartition for (100,4) use i Selected Subpartitions: 1:1 (6 rows) +--ignore index test +create table db_1130449_tb (col1 int ,col2 int,col3 int,col4 varchar(10),primary key(col1)); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "db_1130449_tb_pkey" for table "db_1130449_tb" +insert into db_1130449_tb values(1,1,1,'a'); +insert into db_1130449_tb values(2,2,2,'a'); +insert into db_1130449_tb values(3,3,2,'a'); +insert into db_1130449_tb values(4,4,3,'b'); +insert into db_1130449_tb values(5,5,3,'b'); +insert into db_1130449_tb values(6,6,6,'b'); +insert into db_1130449_tb values(7,7,7,'a'); +insert into db_1130449_tb values(8,8,8,'c'); +insert into db_1130449_tb values(9,9,9,'c'); +insert into db_1130449_tb values(10,null,1,'c'); +create unique index index_1130449 on db_1130449_tb (col2); +analyze db_1130449_tb; +select * from db_1130449_tb ignore index (index_1130449) where col2= 3; + col1 | col2 | col3 | col4 +------+------+------+------ + 3 | 3 | 2 | a +(1 row) + +select * from db_1130449_tb ignore index (index_1130449) where col2= 3 and col4 = 'a'; + col1 | col2 | col3 | col4 +------+------+------+------ + 3 | 3 | 2 | a +(1 row) + +select * from db_1130449_tb IGNORE INDEX (index_1130449) where col2= 3; + col1 | col2 | col3 | col4 +------+------+------+------ + 3 | 3 | 2 | a +(1 row) + +explain (costs off )select * from db_1130449_tb ignore index (index_1130449) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130449_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130449_tb ignore index (index_1130449) where col2= 3 and col4 = 'a'; + QUERY PLAN +------------------------------------------------------- + Seq Scan on db_1130449_tb + Filter: ((col2 = 3) AND ((col4)::text = 'a'::text)) +(2 rows) + +explain (costs off) select * from db_1130449_tb IGNORE INDEX (index_1130449) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130449_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off) select * from db_1130449_tb FORCE INDEX (index_1130449) IGNORE INDEX (index_1130449) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130449_tb + Filter: (col2 = 3) +(2 rows) + +--multi index ignored gram test +create table db_1130452_tb (col1 int ,col2 int,col3 int,col4 varchar(10)); +insert into db_1130452_tb values(1,1,1,'a'); +insert into db_1130452_tb values(1,2,2,'a'); +insert into db_1130452_tb values(2,2,2,'a'); +insert into db_1130452_tb values(2,2,3,'b'); +insert into db_1130452_tb values(2,3,3,'b'); +insert into db_1130452_tb values(3,3,4,'b'); +insert into db_1130452_tb values(3,3,4,'a'); +insert into db_1130452_tb values(3,4,5,'c'); +insert into db_1130452_tb values(4,4,5,'c'); +insert into db_1130452_tb values(4,null,1,'c'); +create index index_1130452_1 on db_1130452_tb (col1); +create index index_1130452_2 on db_1130452_tb (col2); +create index index_1130452_3 on db_1130452_tb (col3); +create index index_1130452_4 on db_1130452_tb (col4); +analyze db_1130452_tb; +select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2) where col2= 3 order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b + 3 | 3 | 4 | b + 3 | 3 | 4 | a +(3 rows) + +select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_1) where col2= 3 order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b + 3 | 3 | 4 | b + 3 | 3 | 4 | a +(3 rows) + +select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_2) where col2= 3 order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b + 3 | 3 | 4 | b + 3 | 3 | 4 | a +(3 rows) + +select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2)ignore index (index_1130452_3) ignore index (index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b' order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b +(1 row) + +select * from db_1130452_tb ignore index (index_1130452_1, index_1130452_2) where col2= 3 order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b + 3 | 3 | 4 | b + 3 | 3 | 4 | a +(3 rows) + +select * from db_1130452_tb ignore index (index_1130452_2, index_1130452_1) where col2= 3 order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b + 3 | 3 | 4 | b + 3 | 3 | 4 | a +(3 rows) + +select * from db_1130452_tb ignore index (index_1130452_2, index_1130452_2) where col2= 3 order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b + 3 | 3 | 4 | b + 3 | 3 | 4 | a +(3 rows) + +select * from db_1130452_tb ignore index (index_1130452_1, index_1130452_2, index_1130452_3, index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b' order by 1,2,3; + col1 | col2 | col3 | col4 +------+------+------+------ + 2 | 3 | 3 | b +(1 row) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130452_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_1) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130452_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_2) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130452_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2)ignore index (index_1130452_3) ignore index (index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b'; + QUERY PLAN +------------------------------------------------------------------------------------- + Seq Scan on db_1130452_tb + Filter: ((col2 = 3) AND (col3 = 3) AND (col1 = 2) AND ((col4)::text = 'b'::text)) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1 ,index_1130452_2) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130452_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2 ,index_1130452_1) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130452_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2, index_1130452_2) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1130452_tb + Filter: (col2 = 3) +(2 rows) + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1, index_1130452_2, index_1130452_3, index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b'; + QUERY PLAN +------------------------------------------------------------------------------------- + Seq Scan on db_1130452_tb + Filter: ((col2 = 3) AND (col3 = 3) AND (col1 = 2) AND ((col4)::text = 'b'::text)) +(2 rows) + +--error report +create table db_1130456_tb (col1 int ,col2 int,col3 int,col4 varchar(10)); +insert into db_1130456_tb values(1,1,1,'a'); +insert into db_1130456_tb values(1,2,2,'a'); +insert into db_1130456_tb values(2,2,2,'a'); +insert into db_1130456_tb values(2,2,3,'b'); +insert into db_1130456_tb values(2,3,3,'b'); +insert into db_1130456_tb values(3,3,4,'b'); +insert into db_1130456_tb values(3,3,4,'a'); +insert into db_1130456_tb values(3,4,5,'c'); +insert into db_1130456_tb values(4,4,5,'c'); +insert into db_1130456_tb values(4,null,1,'c'); +create index index_1130456_1 on db_1130456_tb (col1); +create index index_1130456_2 on db_1130456_tb (col2); +create index index_1130456_3 on db_1130456_tb (col3); +create index index_1130456_4 on db_1130456_tb (col4); +analyze db_1130456_tb; +create table db_1130456_tb_1 as select * from db_1130456_tb; +create index index_1130456_5 on db_1130456_tb_1 (col1); +select * from db_1130456_tb ignore index (index_1130456_5) where col2= 3; +ERROR: index not exists in relation db_1130456_tb +select * from db_1130456_tb ignore index (index_1130456_6) where col2= 3; +ERROR: index not exists in relation db_1130456_tb +--in partition table +CREATE TABLE db_1130473_tb +( +col1 INTEGER NOT NULL, +col2 INTEGER NOT NULL, +col3 INTEGER , +CA_STREET_NAME VARCHAR(60) , +CA_STREET_TYPE CHAR(15) , +CA_SUITE_NUMBER CHAR(10) , +CA_CITY VARCHAR(60) , +CA_COUNTY VARCHAR(30) , +CA_STATE CHAR(2) , +CA_ZIP CHAR(10) , +CA_COUNTRY VARCHAR(20) , +CA_GMT_OFFSET DECIMAL(5,2) , +CA_LOCATION_TYPE CHAR(20) +) +PARTITION BY list(col1) +( +partition p1 values (4), +partition p2 values (5), +partition p3 values (1), +partition p4 values (2), +partition p5 values (3)); +CREATE INDEX ds_db_1130473_tb_index2 ON db_1130473_tb(col1) LOCAL ; +insert into db_1130473_tb select 1,v,v from generate_series(1,120) as v; +insert into db_1130473_tb select 2,v,v from generate_series(1,200) as v; +insert into db_1130473_tb select 3,v,v from generate_series(1,100) as v; +insert into db_1130473_tb select 4,v,v from generate_series(1,300) as v; +insert into db_1130473_tb select 5,v,v from generate_series(1,500) as v; +create index "Index_1130473%%_1" on db_1130473_tb (col1) local; +create index INDEX_1130473_2 on db_1130473_tb (col2); +analyze db_1130473_tb; +select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") where col1>= 3 ; + ?column? +---------- + 501 +(1 row) + +select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + ?column? +---------- + 501 +(1 row) + +explain (costs off) select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") where col1>= 3 ; + QUERY PLAN +-------------------------------------------------------------------------- + Result + InitPlan 1 (returns $0) + -> Limit + -> Index Scan Backward using index_1130473_2 on db_1130473_tb + Filter: (col1 >= 3) +(5 rows) + +explain (costs off) select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + QUERY PLAN +----------------------------------------------------- + Aggregate + -> Partition Iterator + Iterations: 5 + -> Partitioned Seq Scan on db_1130473_tb + Filter: ((col2 >= 3) AND (col1 >= 3)) + Selected Partitions: 1..5 +(6 rows) + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") where col1>= 3 ; + ?column? +---------- + 301 +(1 row) + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + ?column? +---------- + 301 +(1 row) + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") where col1>= 3 ; + QUERY PLAN +--------------------------------------------- + Aggregate + -> Partitioned Seq Scan on db_1130473_tb + Filter: (col1 >= 3) + Selected Partitions: 4 +(4 rows) + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + QUERY PLAN +----------------------------------------------- + Aggregate + -> Partitioned Seq Scan on db_1130473_tb + Filter: ((col2 >= 3) AND (col1 >= 3)) + Selected Partitions: 4 +(4 rows) + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) where col1>= 3 ; + ?column? +---------- + 301 +(1 row) + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + ?column? +---------- + 301 +(1 row) + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) where col1>= 3 ; + QUERY PLAN +--------------------------------------------- + Aggregate + -> Partitioned Seq Scan on db_1130473_tb + Filter: (col1 >= 3) + Selected Partitions: 4 +(4 rows) + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + QUERY PLAN +----------------------------------------------- + Aggregate + -> Partitioned Seq Scan on db_1130473_tb + Filter: ((col2 >= 3) AND (col1 >= 3)) + Selected Partitions: 4 +(4 rows) + +-- with scan hint +create table db_1131004_tb (col1 int ,col2 int,col3 int,col4 varchar(10),primary key(col1)); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "db_1131004_tb_pkey" for table "db_1131004_tb" +insert into db_1131004_tb values(1,1,1,'a'); +insert into db_1131004_tb values(2,2,2,'a'); +insert into db_1131004_tb values(3,3,2,'a'); +insert into db_1131004_tb values(4,4,3,'b'); +insert into db_1131004_tb values(5,5,3,'b'); +insert into db_1131004_tb values(6,6,6,'b'); +insert into db_1131004_tb values(7,7,7,'a'); +insert into db_1131004_tb values(8,8,8,'c'); +insert into db_1131004_tb values(9,9,9,'c'); +insert into db_1131004_tb values(10,null,1,'c'); +create unique index index_1131004 on db_1131004_tb (col2); +analyze db_1131004_tb; +select /*+ indexscan(db_1131004_tb ) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + col1 | col2 | col3 | col4 +------+------+------+------ + 3 | 3 | 2 | a +(1 row) + +explain (costs off) select /*+ indexscan(db_1131004_tb ) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1131004_tb + Filter: (col2 = 3) +(2 rows) + +select /*+ indexonlyscan(db_1131004_tb ) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + col2 +------ + 3 +(1 row) + +explain (costs off) select /*+ indexonlyscan(db_1131004_tb ) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1131004_tb + Filter: (col2 = 3) +(2 rows) + +select /*+ indexscan(db_1131004_tb index_1131004 ) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + col1 | col2 | col3 | col4 +------+------+------+------ + 3 | 3 | 2 | a +(1 row) + +explain (costs off) select /*+ indexscan(db_1131004_tb index_1131004) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1131004_tb + Filter: (col2 = 3) +(2 rows) + +select /*+ indexonlyscan(db_1131004_tb index_1131004) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + col2 +------ + 3 +(1 row) + +explain (costs off) select /*+ indexonlyscan(db_1131004_tb index_1131004) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + QUERY PLAN +--------------------------- + Seq Scan on db_1131004_tb + Filter: (col2 = 3) +(2 rows) + \c postgres DROP DATABASE IF EXISTS db_1097149; DROP DATABASE IF EXISTS db_ID1097168; diff --git a/src/test/regress/sql/mysql_indexhint.sql b/src/test/regress/sql/mysql_indexhint.sql index 5e3e13938..5f7f98462 100644 --- a/src/test/regress/sql/mysql_indexhint.sql +++ b/src/test/regress/sql/mysql_indexhint.sql @@ -250,6 +250,212 @@ analyze list_list; explain (costs off) select user_no from list_list subpartition (pa1) use index (idx_list) where user_no = 1; explain (costs off)select user_no from list_list subpartition for (100,4) use index (idx_list) where user_no = 1; +--ignore index test +create table db_1130449_tb (col1 int ,col2 int,col3 int,col4 varchar(10),primary key(col1)); +insert into db_1130449_tb values(1,1,1,'a'); +insert into db_1130449_tb values(2,2,2,'a'); +insert into db_1130449_tb values(3,3,2,'a'); +insert into db_1130449_tb values(4,4,3,'b'); +insert into db_1130449_tb values(5,5,3,'b'); +insert into db_1130449_tb values(6,6,6,'b'); +insert into db_1130449_tb values(7,7,7,'a'); +insert into db_1130449_tb values(8,8,8,'c'); +insert into db_1130449_tb values(9,9,9,'c'); +insert into db_1130449_tb values(10,null,1,'c'); + +create unique index index_1130449 on db_1130449_tb (col2); +analyze db_1130449_tb; + +select * from db_1130449_tb ignore index (index_1130449) where col2= 3; + +select * from db_1130449_tb ignore index (index_1130449) where col2= 3 and col4 = 'a'; + +select * from db_1130449_tb IGNORE INDEX (index_1130449) where col2= 3; + +explain (costs off )select * from db_1130449_tb ignore index (index_1130449) where col2= 3; + +explain (costs off )select * from db_1130449_tb ignore index (index_1130449) where col2= 3 and col4 = 'a'; + +explain (costs off) select * from db_1130449_tb IGNORE INDEX (index_1130449) where col2= 3; + +explain (costs off) select * from db_1130449_tb FORCE INDEX (index_1130449) IGNORE INDEX (index_1130449) where col2= 3; + +--multi index ignored gram test +create table db_1130452_tb (col1 int ,col2 int,col3 int,col4 varchar(10)); +insert into db_1130452_tb values(1,1,1,'a'); +insert into db_1130452_tb values(1,2,2,'a'); +insert into db_1130452_tb values(2,2,2,'a'); +insert into db_1130452_tb values(2,2,3,'b'); +insert into db_1130452_tb values(2,3,3,'b'); +insert into db_1130452_tb values(3,3,4,'b'); +insert into db_1130452_tb values(3,3,4,'a'); +insert into db_1130452_tb values(3,4,5,'c'); +insert into db_1130452_tb values(4,4,5,'c'); +insert into db_1130452_tb values(4,null,1,'c'); + +create index index_1130452_1 on db_1130452_tb (col1); +create index index_1130452_2 on db_1130452_tb (col2); +create index index_1130452_3 on db_1130452_tb (col3); +create index index_1130452_4 on db_1130452_tb (col4); +analyze db_1130452_tb; + +select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2) where col2= 3 order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_1) where col2= 3 order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_2) where col2= 3 order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2)ignore index (index_1130452_3) ignore index (index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b' order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_1, index_1130452_2) where col2= 3 order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_2, index_1130452_1) where col2= 3 order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_2, index_1130452_2) where col2= 3 order by 1,2,3; + +select * from db_1130452_tb ignore index (index_1130452_1, index_1130452_2, index_1130452_3, index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b' order by 1,2,3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2) where col2= 3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_1) where col2= 3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2) ignore index (index_1130452_2) where col2= 3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1) ignore index (index_1130452_2)ignore index (index_1130452_3) ignore index (index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b'; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1 ,index_1130452_2) where col2= 3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2 ,index_1130452_1) where col2= 3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_2, index_1130452_2) where col2= 3; + +explain (costs off )select * from db_1130452_tb ignore index (index_1130452_1, index_1130452_2, index_1130452_3, index_1130452_4) where col2= 3 and col1 = 2 and col3 = 3 and col4='b'; + +--error report +create table db_1130456_tb (col1 int ,col2 int,col3 int,col4 varchar(10)); +insert into db_1130456_tb values(1,1,1,'a'); +insert into db_1130456_tb values(1,2,2,'a'); +insert into db_1130456_tb values(2,2,2,'a'); +insert into db_1130456_tb values(2,2,3,'b'); +insert into db_1130456_tb values(2,3,3,'b'); +insert into db_1130456_tb values(3,3,4,'b'); +insert into db_1130456_tb values(3,3,4,'a'); +insert into db_1130456_tb values(3,4,5,'c'); +insert into db_1130456_tb values(4,4,5,'c'); +insert into db_1130456_tb values(4,null,1,'c'); + +create index index_1130456_1 on db_1130456_tb (col1); +create index index_1130456_2 on db_1130456_tb (col2); +create index index_1130456_3 on db_1130456_tb (col3); +create index index_1130456_4 on db_1130456_tb (col4); +analyze db_1130456_tb; + +create table db_1130456_tb_1 as select * from db_1130456_tb; + +create index index_1130456_5 on db_1130456_tb_1 (col1); + +select * from db_1130456_tb ignore index (index_1130456_5) where col2= 3; + +select * from db_1130456_tb ignore index (index_1130456_6) where col2= 3; + +--in partition table +CREATE TABLE db_1130473_tb +( +col1 INTEGER NOT NULL, +col2 INTEGER NOT NULL, +col3 INTEGER , +CA_STREET_NAME VARCHAR(60) , +CA_STREET_TYPE CHAR(15) , +CA_SUITE_NUMBER CHAR(10) , +CA_CITY VARCHAR(60) , +CA_COUNTY VARCHAR(30) , +CA_STATE CHAR(2) , +CA_ZIP CHAR(10) , +CA_COUNTRY VARCHAR(20) , +CA_GMT_OFFSET DECIMAL(5,2) , +CA_LOCATION_TYPE CHAR(20) +) +PARTITION BY list(col1) +( +partition p1 values (4), +partition p2 values (5), +partition p3 values (1), +partition p4 values (2), +partition p5 values (3)); + + + +CREATE INDEX ds_db_1130473_tb_index2 ON db_1130473_tb(col1) LOCAL ; +insert into db_1130473_tb select 1,v,v from generate_series(1,120) as v; +insert into db_1130473_tb select 2,v,v from generate_series(1,200) as v; +insert into db_1130473_tb select 3,v,v from generate_series(1,100) as v; +insert into db_1130473_tb select 4,v,v from generate_series(1,300) as v; +insert into db_1130473_tb select 5,v,v from generate_series(1,500) as v; + +create index "Index_1130473%%_1" on db_1130473_tb (col1) local; +create index INDEX_1130473_2 on db_1130473_tb (col2); + +analyze db_1130473_tb; + +select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") where col1>= 3 ; + +select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + +explain (costs off) select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") where col1>= 3 ; + +explain (costs off) select max(col2)+1 from db_1130473_tb ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") where col1>= 3 ; + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") where col1>= 3 ; + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index ("Index_1130473%%_1") ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) where col1>= 3 ; + +select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) where col1>= 3 ; + +explain (costs off) select max(col2)+1 from db_1130473_tb partition (p1) ignore index (ds_db_1130473_tb_index2) ignore index (INDEX_1130473_2) where col2>= 3 and col1 >=3 ; + + +-- with scan hint + +create table db_1131004_tb (col1 int ,col2 int,col3 int,col4 varchar(10),primary key(col1)); +insert into db_1131004_tb values(1,1,1,'a'); +insert into db_1131004_tb values(2,2,2,'a'); +insert into db_1131004_tb values(3,3,2,'a'); +insert into db_1131004_tb values(4,4,3,'b'); +insert into db_1131004_tb values(5,5,3,'b'); +insert into db_1131004_tb values(6,6,6,'b'); +insert into db_1131004_tb values(7,7,7,'a'); +insert into db_1131004_tb values(8,8,8,'c'); +insert into db_1131004_tb values(9,9,9,'c'); +insert into db_1131004_tb values(10,null,1,'c'); + +create unique index index_1131004 on db_1131004_tb (col2); +analyze db_1131004_tb; + +select /*+ indexscan(db_1131004_tb ) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + +explain (costs off) select /*+ indexscan(db_1131004_tb ) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + +select /*+ indexonlyscan(db_1131004_tb ) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + +explain (costs off) select /*+ indexonlyscan(db_1131004_tb ) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + + +select /*+ indexscan(db_1131004_tb index_1131004 ) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + +explain (costs off) select /*+ indexscan(db_1131004_tb index_1131004) */* from db_1131004_tb ignore index (index_1131004) where col2= 3; + +select /*+ indexonlyscan(db_1131004_tb index_1131004) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + +explain (costs off) select /*+ indexonlyscan(db_1131004_tb index_1131004) */col2 from db_1131004_tb ignore index (index_1131004) where col2= 3; + \c postgres DROP DATABASE IF EXISTS db_1097149;