From 978f6515d83f568072f05415b021bdcd7559aadf Mon Sep 17 00:00:00 2001 From: lukeman Date: Tue, 27 Feb 2024 14:39:31 +0800 Subject: [PATCH] =?UTF-8?q?=E9=9C=80=E6=B1=82=EF=BC=9ASELECT=E8=AF=AD?= =?UTF-8?q?=E5=8F=A5=E6=94=AF=E6=8C=81sample=E5=AD=90=E5=8F=A5=EF=BC=8C?= =?UTF-8?q?=E5=AE=9E=E7=8E=B0=E6=95=B0=E6=8D=AE=E9=87=87=E6=A0=B7?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- src/common/backend/parser/gram.y | 36 ++ src/common/backend/parser/parse_clause.cpp | 8 +- src/gausskernel/optimizer/path/allpaths.cpp | 22 +- src/gausskernel/optimizer/plan/initsplan.cpp | 255 +++++++++- src/gausskernel/optimizer/plan/planmain.cpp | 6 +- .../runtime/executor/nodeSamplescan.cpp | 12 +- .../storage/access/heap/heapam.cpp | 2 +- src/include/executor/node/nodeSamplescan.h | 6 +- src/include/optimizer/paths.h | 2 +- src/include/optimizer/planmain.h | 2 +- src/test/regress/expected/tablesample_3.out | 148 +++--- src/test/regress/expected/tablesample_4.out | 458 ++++++++++++++++++ src/test/regress/parallel_schedule0 | 4 +- src/test/regress/parallel_schedule0B | 2 +- src/test/regress/sql/tablesample_4.sql | 207 ++++++++ 15 files changed, 1057 insertions(+), 113 deletions(-) create mode 100644 src/test/regress/expected/tablesample_4.out create mode 100755 src/test/regress/sql/tablesample_4.sql diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index af1ebaa2d..8f67df5b3 100644 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -24584,6 +24584,42 @@ table_ref: relation_expr %prec UMINUS $1->indexhints = $7; $$ = (Node *)$1; } + | relation_expr PARTITION '(' name ')' tablesample_clause + { + RangeTableSample *n = (RangeTableSample *) $6; + $1->partitionname = $4; + $1->ispartition = true; + /* relation_expr goes inside the RangeTableSample node */ + n->relation = (Node *) $1; + $$ = (Node *) n; + } + | relation_expr SUBPARTITION '(' name ')' tablesample_clause + { + RangeTableSample *n = (RangeTableSample *) $6; + $1->subpartitionname = $4; + $1->issubpartition = true; + /* relation_expr goes inside the RangeTableSample node */ + n->relation = (Node *) $1; + $$ = (Node *) n; + } + | relation_expr PARTITION_FOR '(' expr_list ')' tablesample_clause + { + RangeTableSample *n = (RangeTableSample *) $6; + $1->partitionKeyValuesList = $4; + $1->ispartition = true; + /* relation_expr goes inside the RangeTableSample node */ + n->relation = (Node *) $1; + $$ = (Node *) n; + } + | relation_expr SUBPARTITION_FOR '(' expr_list ')' tablesample_clause + { + RangeTableSample *n = (RangeTableSample *) $6; + $1->partitionKeyValuesList = $4; + $1->issubpartition = true; + /* relation_expr goes inside the RangeTableSample node */ + n->relation = (Node *) $1; + $$ = (Node *) n; + } | func_table %prec UMINUS { RangeFunction *n = makeNode(RangeFunction); diff --git a/src/common/backend/parser/parse_clause.cpp b/src/common/backend/parser/parse_clause.cpp index 81689f832..42710183c 100644 --- a/src/common/backend/parser/parse_clause.cpp +++ b/src/common/backend/parser/parse_clause.cpp @@ -793,7 +793,7 @@ static TableSampleClause* transformRangeTableSample(ParseState* pstate, RangeTab Node* arg = (Node*)lfirst(larg); arg = transformExpr(pstate, arg, EXPR_KIND_FROM_FUNCTION); - arg = coerce_to_specific_type(pstate, arg, FLOAT4OID, "TABLESAMPLE"); + arg = coerce_to_specific_type(pstate, arg, FLOAT8OID, "TABLESAMPLE"); assign_expr_collations(pstate, arg); fargs = lappend(fargs, arg); } @@ -982,11 +982,11 @@ Node* transformFromClauseItem(ParseState* pstate, Node* n, RangeTblEntry** top_r rtr = (RangeTblRef*)rel; rte = rt_fetch(rtr->rtindex, pstate->p_rtable); - /* We only support this on plain relations */ - if (rte->relkind != RELKIND_RELATION) { + /* We only support this on plain relations and views, materialized views and join views with kp-tables */ + if (rte->relkind != RELKIND_RELATION && rte->relkind != RELKIND_MATVIEW && rte->relkind != RELKIND_VIEW) { ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("TABLESAMPLE clause can only be applied to tables."), + errmsg("TABLESAMPLE clause can only be applied to tables, materialized views and key-preserved join views."), parser_errposition(pstate, exprLocation(rts->relation)))); } diff --git a/src/gausskernel/optimizer/path/allpaths.cpp b/src/gausskernel/optimizer/path/allpaths.cpp index cb7b1221f..e1ee31512 100755 --- a/src/gausskernel/optimizer/path/allpaths.cpp +++ b/src/gausskernel/optimizer/path/allpaths.cpp @@ -68,7 +68,7 @@ const int max_parallel_maintenance_workers = 32; static bool check_func_walker(Node* node, bool* found); static bool check_func(Node* node); -static void set_base_rel_pathlists(PlannerInfo* root); +static void set_base_rel_pathlists(PlannerInfo* root, Relids non_keypreserved); static void set_correlated_rel_pathlist(PlannerInfo* root, RelOptInfo* rel); static void set_rel_pathlist(PlannerInfo* root, RelOptInfo* rel, Index rti, RangeTblEntry* rte); static void set_plain_rel_size(PlannerInfo* root, RelOptInfo* rel, RangeTblEntry* rte); @@ -183,7 +183,7 @@ static inline void updateRelOptInfoMinSecurity(RelOptInfo* rel) * Finds all possible access paths for executing a query, returning a * single rel that represents the join of all base rels in the query. */ -RelOptInfo* make_one_rel(PlannerInfo* root, List* joinlist) +RelOptInfo* make_one_rel(PlannerInfo* root, List* joinlist, Relids non_keypreserved) { RelOptInfo* rel = NULL; int rti; @@ -283,7 +283,7 @@ RelOptInfo* make_one_rel(PlannerInfo* root, List* joinlist) u_sess->opt_cxt.op_work_mem = Min(root->glob->estiopmem, OPT_MAX_OP_MEM); Assert(u_sess->opt_cxt.op_work_mem > 0); } - set_base_rel_pathlists(root); + set_base_rel_pathlists(root, non_keypreserved); u_sess->opt_cxt.op_work_mem = work_mem_orig; root->glob->estiopmem = esti_op_mem_orig; @@ -459,11 +459,16 @@ static Path *make_predpush_subpath(PlannerInfo* root, RelOptInfo* rel, Path *pat * Sequential scan and any available indices are considered. * Each useful path is attached to its relation's 'pathlist' field. */ -static void set_base_rel_pathlists(PlannerInfo* root) +static void set_base_rel_pathlists(PlannerInfo* root, Relids non_keypreserved) { int rti; - - for (rti = 1; rti < root->simple_rel_array_size; rti++) { + TableSampleClause* tsc= NULL; + bool needTablesample = root->simple_rel_array[1] == NULL && root->simple_rte_array[1]->tablesample != NULL; + int pos = bms_first_member(non_keypreserved); + if (needTablesample) { + tsc = root->simple_rte_array[1]->tablesample; + } + for (rti = root->simple_rel_array_size - 1; rti >= 1; rti--) { RelOptInfo* rel = root->simple_rel_array[rti]; RangeTblEntry* rte = root->simple_rte_array[rti]; @@ -476,7 +481,10 @@ static void set_base_rel_pathlists(PlannerInfo* root) /* ignore RTEs that are "other rels" */ if (rel->reloptkind != RELOPT_BASEREL) continue; - + if ((pos == -1 || pos == rti) && needTablesample && !rte->tablesample) { + rte->tablesample = tsc; + pos = 0; + } set_rel_pathlist(root, rel, rti, root->simple_rte_array[rti]); /* diff --git a/src/gausskernel/optimizer/plan/initsplan.cpp b/src/gausskernel/optimizer/plan/initsplan.cpp index 21a407fa0..0a280203d 100644 --- a/src/gausskernel/optimizer/plan/initsplan.cpp +++ b/src/gausskernel/optimizer/plan/initsplan.cpp @@ -34,6 +34,8 @@ #include "parser/parsetree.h" #include "rewrite/rewriteManip.h" #include "utils/lsyscache.h" +#include "catalog/index.h" +#include "catalog/pg_amop.h" /* Elements of the postponed_qual_list used during deconstruct_recurse */ typedef struct PostponedQual @@ -43,7 +45,7 @@ typedef struct PostponedQual } PostponedQual; static void extract_lateral_references(PlannerInfo *root, RelOptInfo *brel, Index rtindex); static List* deconstruct_recurse( - PlannerInfo* root, Node* jtnode, bool below_outer_join, Relids* qualscope, Relids* inner_join_rels, List **postponed_qual_list); + PlannerInfo* root, Node* jtnode, bool below_outer_join, Relids* qualscope, Relids* inner_join_rels, List **postponed_qual_list, Relids* non_keypreserved = NULL); static SpecialJoinInfo* make_outerjoininfo( PlannerInfo* root, Relids left_rels, Relids right_rels, Relids inner_join_rels, JoinType jointype, List* clause); static bool check_outerjoin_delay(PlannerInfo* root, Relids* relids_p, Relids* nullable_relids_p, bool is_pushed_down); @@ -462,7 +464,7 @@ void add_lateral_info(PlannerInfo *root, Index rhs, Relids lhs) * clauses appearing above it. This forces those clauses to be delayed until * application of the outer join (or maybe even higher in the join tree). */ -List* deconstruct_jointree(PlannerInfo* root) +List* deconstruct_jointree(PlannerInfo* root, Relids* non_keypreserved) { List *result = NIL; Relids qualscope = NULL; @@ -474,7 +476,7 @@ List* deconstruct_jointree(PlannerInfo* root) root->parse->jointree != NULL && IsA(root->parse->jointree, FromExpr), MOD_OPT, "From expression is required."); result = deconstruct_recurse(root, (Node *) root->parse->jointree, false, - &qualscope, &inner_join_rels, &postponed_qual_list); + &qualscope, &inner_join_rels, &postponed_qual_list, non_keypreserved); /* Shouldn't be any leftover quals */ Assert(postponed_qual_list == NIL); @@ -529,6 +531,228 @@ static void process_security_barrier_quals( Assert(security_level <= root->qualSecurityLevel); } +#define JATTR_TAB_HASH_SIZE 64 + +typedef struct JoinAttrEntry { + Index relidx; + Bitmapset* attrs; +} JoinAttrEntry; + +static bool is_equals_operator(int operid) +{ + bool result = false; + CatCList* catlist = NULL; + int i; + /* + * Search pg_amop to see if the operid is registered as the "=" + */ + catlist = SearchSysCacheList1(AMOPOPID, ObjectIdGetDatum(operid)); + for (i = 0; i < catlist->n_members; i++) { + HeapTuple tuple = t_thrd.lsc_cxt.FetchTupleFromCatCList(catlist, i); + Form_pg_amop aform = (Form_pg_amop)GETSTRUCT(tuple); + if (aform->amopstrategy == BTEqualStrategyNumber) { + result = true; + break; + } + } + ReleaseSysCacheList(catlist); + return result; + +} + +static bool rel_is_member_of_non_keypreserved(PlannerInfo* root, Index relidx, Relids non_keypreserved) +{ + Relids tmpset = bms_copy(non_keypreserved); + int x = 0; + Oid relid = root->simple_rte_array[relidx]->relid; + while ((x = bms_first_member(tmpset)) >= 0) { + if (relid == root->simple_rte_array[x]->relid) { + bms_free_ext(tmpset); + return true; + } + } + bms_free_ext(tmpset); + return false; +} + +static void find_non_keypreservered_rels(PlannerInfo* root, HTAB* htab, Relids* non_keypreserved, + JoinType type, RangeTblRef* leftpart, RangeTblRef* rightpart) +{ + HASH_SEQ_STATUS status; + JoinAttrEntry *entry = NULL; + hash_seq_init(&status, htab); + bool left_is_key_preserved = true; + bool right_is_key_preserved = true; + while ((entry = (JoinAttrEntry *) hash_seq_search(&status)) != NULL) { + if (bms_num_members(*non_keypreserved) > 1) { + ereport(ERROR, (errcode(ERRCODE_DATA_EXCEPTION), + errmsg("Cannot sample a join view without a key-preserved table"))); + } + Index relidx = entry->relidx; + Oid relid = root->simple_rte_array[relidx]->relid; + Relids jattrs = entry->attrs; + Relation relation = relation_open(relid, AccessShareLock); + Assert(!RelationIsBucket(relation) && !RelationIsPartition(relation)); + /* Fast path if definitely no indexes */ + if (!RelationGetForm(relation)->relhasindex) { + *non_keypreserved = bms_add_member(*non_keypreserved, relidx); + relation_close(relation, AccessShareLock); + continue; + } + List* indexoidlist = NIL; + ListCell* l = NULL; + Oid relpkindex; + bool is_key_preserved = false; + /* Get cached list of index OIDs */ + indexoidlist = RelationGetIndexList(relation); + /* Fall out if no indexes (but relhasindex was set) */ + if (indexoidlist == NIL) { + *non_keypreserved = bms_add_member(*non_keypreserved, relidx); + relation_close(relation, AccessShareLock); + continue; + } + relpkindex = relation->rd_pkindex; + foreach (l, indexoidlist) { + Oid indexOid = lfirst_oid(l); + Relation indexDesc; + IndexInfo* indexInfo = NULL; + int i; + bool isKey = false; /* candidate key */ + bool isPK; /* primary key */ + Bitmapset* uindexattrs = NULL; + Bitmapset* pkindexattrs = NULL; /* columns in the primary index */ + indexDesc = index_open(indexOid, AccessShareLock); + /* Extract index key information from the index's pg_index row */ + indexInfo = BuildIndexInfo(indexDesc); + /* Is this a primary key? */ + isPK = (indexOid == relpkindex); + /* Can this index be referenced by a foreign key? */ + isKey = indexInfo->ii_Unique && indexInfo->ii_Expressions == NIL && indexInfo->ii_Predicate == NIL; + if (!isPK && !isKey) { + index_close(indexDesc, AccessShareLock); + continue; + } + /* Collect simple attribute references */ + for (i = 0; i < indexInfo->ii_NumIndexAttrs; i++) { + int attrnum = indexInfo->ii_KeyAttrNumbers[i]; + if (attrnum != 0) { + if (isKey && i < indexInfo->ii_NumIndexKeyAttrs) { + uindexattrs = bms_add_member(uindexattrs, attrnum); + } + if (isPK) { + pkindexattrs = bms_add_member(pkindexattrs, attrnum); + } + } + } + index_close(indexDesc, AccessShareLock); + if ((!bms_is_empty(uindexattrs) && bms_is_subset(uindexattrs, jattrs)) || + (!bms_is_empty(pkindexattrs) && bms_is_subset(pkindexattrs, jattrs))) { /* the rel is key-preserved*/ + is_key_preserved = true; + break; + } + } + if (leftpart && !is_key_preserved && relidx == leftpart->rtindex) { + left_is_key_preserved = false; + } + if (rightpart && !is_key_preserved && relidx == rightpart->rtindex) { + right_is_key_preserved = false; + } + if ((!is_key_preserved && rel_is_member_of_non_keypreserved(root, relidx, *non_keypreserved)) || + (type == JOIN_LEFT && !right_is_key_preserved) || + (type == JOIN_INNER && !right_is_key_preserved && !left_is_key_preserved)) { + ereport(ERROR, (errcode(ERRCODE_DATA_EXCEPTION), + errmsg("Cannot sample a join view without a key-preserved table"))); + } + if (!is_key_preserved) { + *non_keypreserved = bms_add_member(*non_keypreserved, relidx); + } + relation_close(relation, AccessShareLock); + } +} + +static void handle_join_view_operand(PlannerInfo* root, Var* operand, HTAB* htab, RangeTblRef* rtref) +{ + if (!rtref) { + return; + } + Index varno = ((Var*)operand)->varno; + AttrNumber varattno = ((Var*)operand)->varattno; + RangeTblEntry* rte = root->simple_rte_array[varno]; + JoinAttrEntry* attrentry = NULL; + Bitmapset* attrs; + Assert(rte->rtekind == RTE_RELATION); + bool found = false; + /* Lookup current element in hashtable, adding it if new */ + attrentry = (JoinAttrEntry*)hash_search(htab, &varno, HASH_ENTER, &found); + if (found) { + attrs = attrentry->attrs; + attrs = bms_add_member(attrs, varattno); + } else { + attrs = bms_make_singleton(varattno); + attrentry->attrs = attrs; + } +} + +static void check_join_view_quals(PlannerInfo* root, List* quals, Relids* non_keypreserved, + JoinType type, RangeTblRef* leftpart, RangeTblRef* rightpart) +{ + HASHCTL ctl; + HTAB* htab = NULL; + errno_t rc = EOK; + rc = memset_s(&ctl, sizeof(ctl), 0, sizeof(ctl)); + securec_check(rc, "\0", "\0"); + MemoryContext tmp_hash_context = AllocSetContextCreate(CurrentMemoryContext, + "hashtable temporary context", + ALLOCSET_DEFAULT_MINSIZE, + ALLOCSET_DEFAULT_INITSIZE, + ALLOCSET_DEFAULT_MAXSIZE); + ctl.keysize = sizeof(Index); + ctl.entrysize = sizeof(JoinAttrEntry); + ctl.hash = oid_hash; + ctl.hcxt = tmp_hash_context; + htab = hash_create( + "table's attrs of quals", JATTR_TAB_HASH_SIZE, &ctl, HASH_ELEM | HASH_FUNCTION | HASH_CONTEXT); + ListCell* l; + foreach (l, quals) { + Node* qual = (Node*)lfirst(l); + Node* left_operand; + Node* right_operand; + VariableStatData leftvar; + VariableStatData rightvar; + /* If it's a binary opclause, check operator and operand*/ + if (is_opclause(qual) && list_length(((OpExpr*)qual)->args) == 2) { + Oid opno = ((OpExpr*)qual)->opno; + left_operand = get_leftop((Expr*)qual); + right_operand = get_rightop((Expr*)qual); + examine_variable(root, left_operand, 0, &leftvar); + examine_variable(root, right_operand, 0, &rightvar); + if (is_equals_operator(opno)) { /* equal operator */ + if (IsA(leftvar.var, Var) && IsA(rightvar.var, Var)) { + handle_join_view_operand(root, (Var*)leftvar.var, htab, leftpart); + handle_join_view_operand(root, (Var*)rightvar.var, htab, rightpart); + } else if (IsA(leftvar.var, Var) && IsA(rightvar.var, Const)) { + handle_join_view_operand(root, (Var*)leftvar.var, htab, leftpart); + } else if (IsA(rightvar.var, Var) && IsA(leftvar.var, Const)) { + handle_join_view_operand(root, (Var*)rightvar.var, htab, rightpart); + } else { + ereport(ERROR, (errcode(ERRCODE_DATA_EXCEPTION), + errmsg("Cannot sample a join view without a key-preserved table"))); + } + } + } + ReleaseVariableStats(leftvar); + ReleaseVariableStats(rightvar); + } + /* Check if at most one of the tables associated with the current join is non-key-prereserved */ + find_non_keypreservered_rels(root, htab, non_keypreserved, type, leftpart, rightpart); + if (bms_num_members(*non_keypreserved) > 1) { + ereport(ERROR, (errcode(ERRCODE_DATA_EXCEPTION), + errmsg("Cannot sample a join view without a key-preserved table"))); + } + /* Done with the hash table. */ + hash_destroy(htab); +} + /* * deconstruct_recurse * One recursion level of deconstruct_jointree processing. @@ -550,7 +774,7 @@ static void process_security_barrier_quals( */ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, bool below_outer_join, Relids* qualscope, - Relids* inner_join_rels, List **postponed_qual_list) + Relids* inner_join_rels, List **postponed_qual_list, Relids* non_keypreserved) { List* joinlist = NIL; @@ -592,7 +816,7 @@ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, int sub_members; sub_joinlist = deconstruct_recurse(root, (Node*)lfirst(l), below_outer_join, - &sub_qualscope, inner_join_rels, &child_postponed_quals); + &sub_qualscope, inner_join_rels, &child_postponed_quals, non_keypreserved); *qualscope = bms_add_members(*qualscope, sub_qualscope); sub_members = list_length(sub_joinlist); remaining--; @@ -665,10 +889,10 @@ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, case JOIN_INNER: leftjoinlist = deconstruct_recurse(root, j->larg, below_outer_join, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); rightjoinlist = deconstruct_recurse(root, j->rarg, below_outer_join, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); *qualscope = bms_union(leftids, rightids); *inner_join_rels = *qualscope; /* Inner join adds no restrictions for quals */ @@ -679,10 +903,10 @@ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, case JOIN_LEFT_ANTI_FULL: leftjoinlist = deconstruct_recurse(root, j->larg, below_outer_join, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); rightjoinlist = deconstruct_recurse(root, j->rarg, true, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); *qualscope = bms_union(leftids, rightids); *inner_join_rels = bms_union(left_inners, right_inners); nonnullable_rels = leftids; @@ -690,10 +914,10 @@ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, case JOIN_SEMI: leftjoinlist = deconstruct_recurse(root, j->larg, below_outer_join, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); rightjoinlist = deconstruct_recurse(root, j->rarg, below_outer_join, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); *qualscope = bms_union(leftids, rightids); *inner_join_rels = bms_union(left_inners, right_inners); /* Semi join adds no restrictions for quals */ @@ -702,10 +926,10 @@ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, case JOIN_FULL: leftjoinlist = deconstruct_recurse(root, j->larg, true, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); rightjoinlist = deconstruct_recurse(root, j->rarg, true, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, non_keypreserved); *qualscope = bms_union(leftids, rightids); *inner_join_rels = bms_union(left_inners, right_inners); /* each side is both outer and inner */ @@ -723,6 +947,11 @@ static List* deconstruct_recurse(PlannerInfo* root, Node* jtnode, leftjoinlist = rightjoinlist = NIL; } break; } + if (root->simple_rel_array[1] == NULL && root->simple_rte_array[1]->tablesample != NULL) { + Node* leftpart = (list_length(leftjoinlist) == 1) ? (Node*)linitial(leftjoinlist) : NULL; + Node* rightpart = (list_length(rightjoinlist) == 1) ? (Node*)linitial(rightjoinlist) : NULL; + check_join_view_quals(root, (List*)j->quals, non_keypreserved, j->jointype, (RangeTblRef*)leftpart, (RangeTblRef*)rightpart); + } /* * For an OJ, form the SpecialJoinInfo now, because we need the OJ's diff --git a/src/gausskernel/optimizer/plan/planmain.cpp b/src/gausskernel/optimizer/plan/planmain.cpp index 1410b7a7c..4da32633f 100755 --- a/src/gausskernel/optimizer/plan/planmain.cpp +++ b/src/gausskernel/optimizer/plan/planmain.cpp @@ -79,6 +79,7 @@ RelOptInfo* query_planner(PlannerInfo* root, List* tlist, RelOptInfo* final_rel = NULL; Index rti; double total_pages; + Relids non_keypreserved = NULL; /* * Init planner lists to empty. @@ -180,7 +181,7 @@ RelOptInfo* query_planner(PlannerInfo* root, List* tlist, find_lateral_references(root); - joinlist = deconstruct_jointree(root); + joinlist = deconstruct_jointree(root, &non_keypreserved); process_security_clause_appendrel(root); @@ -276,7 +277,8 @@ RelOptInfo* query_planner(PlannerInfo* root, List* tlist, /* * Ready to do the primary planning. */ - final_rel = make_one_rel(root, joinlist); + final_rel = make_one_rel(root, joinlist, non_keypreserved); + bms_free(non_keypreserved); if (final_rel == NULL || final_rel->cheapest_total_path == NIL) { ereport(ERROR, diff --git a/src/gausskernel/runtime/executor/nodeSamplescan.cpp b/src/gausskernel/runtime/executor/nodeSamplescan.cpp index 6ed3d360c..6127d2b39 100644 --- a/src/gausskernel/runtime/executor/nodeSamplescan.cpp +++ b/src/gausskernel/runtime/executor/nodeSamplescan.cpp @@ -189,6 +189,7 @@ TupleTableSlot* HbktSeqSampleNext(SeqScanState* node) void BaseTableSample::getSeed() { Datum datum; + double input; bool isnull = false; ExprContext* econtext = sampleScanState->ps.ps_ExprContext; ExprState* repeatable = sampleScanState->sampleScanInfo.repeatable; @@ -201,6 +202,11 @@ void BaseTableSample::getSeed() errmsg("TABLESAMPLE REPEATABLE parameter cannot be null"))); } + input = DatumGetFloat8(datum); + if (input < MIN_SEED_ARG || input > MAX_SEED_ARG || isnan(input)) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_TABLESAMPLE_ARGUMENT), errmsg("sample seed must be in the range [0,4294967295]"))); + } /* * The REPEATABLE parameter has been coerced to float8 by the parser. * The reason for using float8 at the SQL level is that it will @@ -252,11 +258,11 @@ void BaseTableSample::getPercent() ERROR, (errcode(ERRCODE_INVALID_TABLESAMPLE_ARGUMENT), errmsg("TABLESAMPLE parameter cannot be null"))); } - percent[i] = DatumGetFloat4(params[i]); + percent[i] = DatumGetFloat8(params[i]); - if (percent[i] < MIN_PERCENT_ARG || percent[i] > MAX_PERCENT_ARG || isnan(percent[i])) { + if (percent[i] < MIN_PERCENT_ARG || percent[i] >= MAX_PERCENT_ARG || isnan(percent[i])) { ereport(ERROR, - (errcode(ERRCODE_INVALID_TABLESAMPLE_ARGUMENT), errmsg("sample percentage must be between 0 and 100"))); + (errcode(ERRCODE_INVALID_TABLESAMPLE_ARGUMENT), errmsg("sample percentage must be in the range [0.000001,100)"))); } i++; diff --git a/src/gausskernel/storage/access/heap/heapam.cpp b/src/gausskernel/storage/access/heap/heapam.cpp index d438db805..366331f02 100755 --- a/src/gausskernel/storage/access/heap/heapam.cpp +++ b/src/gausskernel/storage/access/heap/heapam.cpp @@ -1842,7 +1842,7 @@ TableScanDesc heap_beginscan_internal(Relation relation, Snapshot snapshot, int */ if (!RelationIsPartitioned(relation)) { RelationIncrementReferenceCount(relation); - } else { + } else if ((flags & SO_TYPE_SAMPLESCAN) == 0) { /* * If the table is a partition table, the current scan must be used by * bitmapscan to scan tuples using GPI. Therefore, diff --git a/src/include/executor/node/nodeSamplescan.h b/src/include/executor/node/nodeSamplescan.h index 58e02e36c..e2d818dec 100644 --- a/src/include/executor/node/nodeSamplescan.h +++ b/src/include/executor/node/nodeSamplescan.h @@ -33,9 +33,13 @@ #define NEWBLOCK 0 /* Identify we have got a new block. */ #define NONEWBLOCK 1 /* Identify we are under scanning tuple in old block. */ -#define MIN_PERCENT_ARG 0 /* Minimum value of percent. */ +#define MIN_PERCENT_ARG 0.000001 /* Minimum value of percent. */ #define MAX_PERCENT_ARG 100 /* Maxmum value of percent. */ +#define MIN_SEED_ARG 0 /* Minimum value of seed. */ +#define MAX_SEED_ARG 4294967295 /* Maxmum value of seed. */ + + /* The flag identify the tuple or block is valid or not for sample scan. */ typedef enum { VALIDDATA, NEXTDATA, INVALIDBLOCKNO, INVALIDOFFSET } ScanValid; diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h index 3dbf6a5c3..e1fe18cdf 100644 --- a/src/include/optimizer/paths.h +++ b/src/include/optimizer/paths.h @@ -33,7 +33,7 @@ typedef void (*set_join_pathlist_hook_type) (PlannerInfo *root, List *restrictlist); extern THR_LOCAL PGDLLIMPORT set_join_pathlist_hook_type set_join_pathlist_hook; -extern RelOptInfo* make_one_rel(PlannerInfo* root, List* joinlist); +extern RelOptInfo* make_one_rel(PlannerInfo* root, List* joinlist, Relids non_keypreserved = NULL); extern RelOptInfo* standard_join_search(PlannerInfo* root, int levels_needed, List* initial_rels); extern void set_base_rel_sizes(PlannerInfo* root, bool onlyRelatinalTable = false); diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h index 733a6b3c6..a79d8df0d 100755 --- a/src/include/optimizer/planmain.h +++ b/src/include/optimizer/planmain.h @@ -158,7 +158,7 @@ extern void add_vars_to_targetlist(PlannerInfo* root, List* vars, Relids where_n extern void find_lateral_references(PlannerInfo *root); extern void create_lateral_join_info(PlannerInfo *root); extern void add_lateral_info(PlannerInfo *root, Index rhs, Relids lhs); -extern List* deconstruct_jointree(PlannerInfo* root); +extern List* deconstruct_jointree(PlannerInfo* root, Relids* non_keypreserved = NULL); extern void distribute_restrictinfo_to_rels(PlannerInfo* root, RestrictInfo* restrictinfo); extern void process_security_clause_appendrel(PlannerInfo *root); extern void process_implied_equality(PlannerInfo* root, Oid opno, Oid collation, Expr* item1, Expr* item2, diff --git a/src/test/regress/expected/tablesample_3.out b/src/test/regress/expected/tablesample_3.out index fa6cff64c..a592ef2b0 100755 --- a/src/test/regress/expected/tablesample_3.out +++ b/src/test/regress/expected/tablesample_3.out @@ -20,16 +20,15 @@ select count(*) from ((select * from test_tablesample tablesample SYSTEM(20) REP (1 row) explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- - Hash Anti Join - Hash Cond: (test_tablesample.id = test_tablesample2.id) + QUERY PLAN +--------------------------------------------------------------------------------------- + Nested Loop Anti Join + Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) - -> Hash - -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) -(7 rows) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) + -> Sample Scan on test_tablesample2 + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) +(6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; id | name | salary | id | name | salary @@ -38,19 +37,15 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_hashjoin to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- - Merge Anti Join - Merge Cond: (test_tablesample.id = test_tablesample2.id) - -> Sort - Sort Key: test_tablesample.id - -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) - -> Sort - Sort Key: test_tablesample2.id - -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) -(10 rows) + QUERY PLAN +--------------------------------------------------------------------------------------- + Nested Loop Anti Join + Join Filter: (test_tablesample.id = test_tablesample2.id) + -> Sample Scan on test_tablesample + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) + -> Sample Scan on test_tablesample2 + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) +(6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; id | name | salary | id | name | salary @@ -59,16 +54,15 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_mergejoin to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------- Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) - -> Materialize - -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) -(7 rows) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) + -> Sample Scan on test_tablesample2 + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) +(6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; id | name | salary | id | name | salary @@ -77,14 +71,14 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_material to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------- Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -93,14 +87,14 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j (0 rows) explain (costs off) select * from test_tablesample tablesample SYSTEM(50) REPEATABLE (200) left join test_tablesample2 tablesample SYSTEM(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ------------------------------------------------------------------------- + QUERY PLAN +------------------------------------------------------------------------------------ Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: system (50::real) REPEATABLE (200::double precision) + Sampling: system (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: system (50::real) REPEATABLE (200::double precision) + Sampling: system (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample SYSTEM(50) REPEATABLE (200) left join test_tablesample2 tablesample SYSTEM(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -130,15 +124,15 @@ select count(*) from ((select * from test_tablesample tablesample SYSTEM(30) REP (1 row) explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------------- Row Adapter -> Vector Nest Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> VecSample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> VecSample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (7 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -148,15 +142,15 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_hashjoin to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------------- Row Adapter -> Vector Nest Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> VecSample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> VecSample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (7 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -166,15 +160,15 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_mergejoin to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------------- Row Adapter -> Vector Nest Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> VecSample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> VecSample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (7 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -184,15 +178,15 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_material to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------------- Row Adapter -> Vector Nest Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> VecSample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> VecSample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (7 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -201,15 +195,15 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j (0 rows) explain (costs off) select * from test_tablesample tablesample SYSTEM(50) REPEATABLE (200) left join test_tablesample2 tablesample SYSTEM(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ------------------------------------------------------------------------------- + QUERY PLAN +------------------------------------------------------------------------------------------ Row Adapter -> Vector Nest Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> VecSample Scan on test_tablesample - Sampling: system (50::real) REPEATABLE (200::double precision) + Sampling: system (50::double precision) REPEATABLE (200::double precision) -> VecSample Scan on test_tablesample2 - Sampling: system (50::real) REPEATABLE (200::double precision) + Sampling: system (50::double precision) REPEATABLE (200::double precision) (7 rows) select * from test_tablesample tablesample SYSTEM(50) REPEATABLE (200) left join test_tablesample2 tablesample SYSTEM(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -239,14 +233,14 @@ select count(*) from ((select * from test_tablesample tablesample SYSTEM(70) REP (1 row) explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------- Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -256,14 +250,14 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_hashjoin to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------- Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -273,14 +267,14 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_mergejoin to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------- Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -290,14 +284,14 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j set enable_material to off; explain (costs off) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ---------------------------------------------------------------------------- + QUERY PLAN +--------------------------------------------------------------------------------------- Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: bernoulli (50::real) REPEATABLE (200::double precision) + Sampling: bernoulli (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left join test_tablesample2 tablesample BERNOULLI(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; @@ -306,14 +300,14 @@ select * from test_tablesample tablesample BERNOULLI(50) REPEATABLE (200) left j (0 rows) explain (costs off) select * from test_tablesample tablesample SYSTEM(50) REPEATABLE (200) left join test_tablesample2 tablesample SYSTEM(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; - QUERY PLAN ------------------------------------------------------------------------- + QUERY PLAN +------------------------------------------------------------------------------------ Nested Loop Anti Join Join Filter: (test_tablesample.id = test_tablesample2.id) -> Sample Scan on test_tablesample - Sampling: system (50::real) REPEATABLE (200::double precision) + Sampling: system (50::double precision) REPEATABLE (200::double precision) -> Sample Scan on test_tablesample2 - Sampling: system (50::real) REPEATABLE (200::double precision) + Sampling: system (50::double precision) REPEATABLE (200::double precision) (6 rows) select * from test_tablesample tablesample SYSTEM(50) REPEATABLE (200) left join test_tablesample2 tablesample SYSTEM(50) REPEATABLE (200) on test_tablesample.id=test_tablesample2.id where test_tablesample2.id is NULL; diff --git a/src/test/regress/expected/tablesample_4.out b/src/test/regress/expected/tablesample_4.out new file mode 100644 index 000000000..54b330d6c --- /dev/null +++ b/src/test/regress/expected/tablesample_4.out @@ -0,0 +1,458 @@ +create schema tablesample_schema5; +set current_schema = tablesample_schema5; +-- 创建普通表 +CREATE TABLE test ( + id int PRIMARY KEY, + some_timestamp timestamptz, + some_text text +); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_pkey" for table "test" +-- 插入数据 +INSERT INTO test (id, some_timestamp, some_text) + SELECT + i, + now() - random() * '1 year'::INTERVAL, + 'depesz #' || i + FROM + generate_series(1,100) i; +-- 分析表的块(页)数 +analyze test; +-- 测试SAMPLE子句 +SELECT count(*) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 100 +(1 row) + +SELECT avg(id) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (1); + avg +--------------------- + 50.5000000000000000 +(1 row) + +SELECT sum(id) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (1); + sum +------ + 5050 +(1 row) + +-- 测试SAMPLE BLOCK子句 +SELECT count(*) FROM test tablesample system (99.9) REPEATABLE(1); + count +------- + 100 +(1 row) + +SELECT avg(id) FROM test tablesample system (99.9) REPEATABLE (1); + avg +--------------------- + 50.5000000000000000 +(1 row) + +SELECT sum(id) FROM test tablesample system (99.9) REPEATABLE (1); + sum +------ + 5050 +(1 row) + +-- 添加其他过滤条件 +SELECT count(*) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (105) limit 5; + count +------- + 100 +(1 row) + +SELECT count(*) FROM test tablesample system ( 99.9 ) REPEATABLE (105) where id < 5; + count +------- + 4 +(1 row) + +SELECT count(*) FROM test tablesample system ( 99.9 ) REPEATABLE (105) limit 5; + count +------- + 100 +(1 row) + + +-- 分区表 +--- 一级分区表 +create table part_list_t1( +id number, +name varchar2(20), +age int) +partition by list(age)( +partition age_10 values(10) , +partition age_20 values(20), +partition age_default values(default)); + +insert into part_list_t1 values (1,'aa',10); +insert into part_list_t1 values (2,'bb',10); +insert into part_list_t1 values (3,'cc',20); +insert into part_list_t1 values (4,'dd',20); +insert into part_list_t1 values (5,'ee',20); +insert into part_list_t1 values (6,'ff',30); +insert into part_list_t1 values (7,'gg',100); +insert into part_list_t1 values (8,'hh',110); + +analyze part_list_t1; + +select count(*) from part_list_t1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 8 +(1 row) + +select count(*) from part_list_t1 tablesample bernoulli ( 99.9 ) REPEATABLE (1) where id > 5; + count +------- + 3 +(1 row) + +select count(*) from part_list_t1 partition (age_10) tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 2 +(1 row) + +select count(*) from part_list_t1 partition for (20) tablesample system ( 99.9 ) REPEATABLE (1); + count +------- + 3 +(1 row) + + +--- 二级分区表 +create table pt_range_hash_test( + pid number(10), + pname varchar2(30), + sex varchar2(10), + create_date date +) partition by range(create_date) + subpartition by hash(pid) subpartitions 4( + partition p1 values less than(to_date('2020-01-01', 'YYYY-MM-DD')) , + partition p2 values less than(to_date('2021-01-01', 'YYYY-MM-DD')) , + partition p3 values less than(to_date('2022-01-01', 'YYYY-MM-DD')) , + partition p4 values less than(maxvalue) + ); + +insert into pt_range_hash_test(pid, pname, sex, create_date) values(1, '瑶瑶', 'WOMAN', to_date('2018-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(2, '壮壮', 'MAN', to_date('2019-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(3, '晴晴', 'WOMAN', to_date('2020-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(4, '琳琳', 'WOMAN', to_date('2020-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(5, '强强', 'MAN', to_date('2021-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(6, '团团', 'WOMAN', to_date('2022-01-01', 'YYYY-MM-DD')); + +analyze pt_range_hash_test; + +select count(*) from pt_range_hash_test tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 6 +(1 row) + +select count(*) from pt_range_hash_test tablesample bernoulli ( 99.9 ) REPEATABLE (1) where pid < 4; + count +------- + 3 +(1 row) + +select count(*) from pt_range_hash_test partition (P2) tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 2 +(1 row) + +select count(*) from pt_range_hash_test subpartition for(to_date('2020-01-01', 'YYYY-MM-DD'),3) tablesample system ( 99.9 ) REPEATABLE (1); + count +------- + 1 +(1 row) + + +-- 物化视图 +CREATE TABLE base_table +( + base_table_id INTEGER, + base_table_field NUMERIC(10,4) +); + +insert into base_table values(1,2); +insert into base_table values(3,4); +insert into base_table values(5,6); + +CREATE MATERIALIZED VIEW master_view1 AS + SELECT + base_table_id AS id, + base_table_field AS field + FROM base_table; + +analyze base_table; +analyze master_view1; + + +SELECT count(*) FROM master_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 3 +(1 row) + +SELECT avg(id) FROM master_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + avg +-------------------- + 3.0000000000000000 +(1 row) + +SELECT sum(id) FROM master_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + sum +----- + 9 +(1 row) + + +SELECT count(*) FROM master_view1 tablesample system (99.9) REPEATABLE (1); + count +------- + 3 +(1 row) + +SELECT avg(id) FROM master_view1 tablesample system (99.9) REPEATABLE (1); + avg +-------------------- + 3.0000000000000000 +(1 row) + +SELECT sum(id) FROM master_view1 tablesample system (99.9) REPEATABLE (1); + sum +----- + 9 +(1 row) + + +-- 普通视图 +CREATE OR REPLACE VIEW master_view2 AS + SELECT + base_table_id AS id, + base_table_field AS field + FROM base_table; + +SELECT count(*) FROM master_view2 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 3 +(1 row) + +SELECT count(*) FROM master_view2 tablesample system (99.9) REPEATABLE (1); + count +------- + 3 +(1 row) + + +CREATE OR REPLACE VIEW dependent_view1 AS + SELECT + id AS dependent_id, + field AS dependent_field + FROM master_view2; + +SELECT count(*) FROM dependent_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + count +------- + 3 +(1 row) + +SELECT count(*) FROM dependent_view1 tablesample system (99.9) REPEATABLE (1); + count +------- + 3 +(1 row) + + +-- 连接视图 +CREATE OR REPLACE VIEW join_view1 AS + SELECT + a.id AS join_id, + base_table_field AS join_field + FROM test a join base_table b on a.id = b.base_table_id; + +explain (costs off) SELECT count(*) FROM join_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + QUERY PLAN +--------------------------------------------------------------- + Aggregate + -> Merge Join + Merge Cond: (a.id = b.base_table_id) + -> Index Only Scan using test_pkey on test a + -> Sort + Sort Key: b.base_table_id + -> Sample Scan on base_table b + Sampling: bernoulli (99.9) REPEATABLE (1) +(8 rows) + +SELECT count(*) FROM join_view1 tablesample system (99.9); + count +------- + 3 +(1 row) + + +CREATE OR REPLACE VIEW join_view1 AS + SELECT + a.id AS join_id, + base_table_field AS join_field + FROM base_table b join test a on b.base_table_id = a.id; + +explain (costs off) SELECT count(*) FROM join_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + QUERY PLAN +--------------------------------------------------------------- + Aggregate + -> Merge Join + Merge Cond: (a.id = b.base_table_id) + -> Index Only Scan using test_pkey on test a + -> Sort + Sort Key: b.base_table_id + -> Sample Scan on base_table b + Sampling: bernoulli (99.9) REPEATABLE (1) +(8 rows) + +SELECT count(*) FROM join_view1 tablesample system (99.9); + count +------- + 3 +(1 row) + + +CREATE OR REPLACE VIEW join_view2 AS + SELECT + b.base_table_id AS nest_join_id, + join_field AS nest_join_field + FROM join_view1 a join base_table b on a.join_id = b.base_table_id; + +explain (costs off) SELECT count(*) FROM join_view2 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +ERROR: Cannot sample a join view without a key-preserved table +SELECT count(*) FROM join_view2 tablesample system (99.9); +ERROR: Cannot sample a join view without a key-preserved table + +CREATE OR REPLACE VIEW join_view2 AS + SELECT + b.id AS nest_join_id, + join_field AS nest_join_field + FROM join_view1 a join test b on a.join_id = b.id; + +explain (costs off) SELECT count(*) FROM join_view2 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Merge Join + Merge Cond: (b.base_table_id = b.id) + -> Merge Join + Merge Cond: (a.id = b.base_table_id) + -> Index Only Scan using test_pkey on test a + -> Sort + Sort Key: b.base_table_id + -> Sample Scan on base_table b + Sampling: bernoulli (99.9) REPEATABLE (1) + -> Index Only Scan using test_pkey on test b +(11 rows) + +SELECT count(*) FROM join_view2 tablesample system (99.9) REPEATABLE (1); + count +------- + 3 +(1 row) + + +CREATE TABLE base_table2 +( + base_table_id INTEGER, + base_table_field NUMERIC(10,4) +); + +insert into base_table2 values(1,1); +insert into base_table2 values(2,2); +insert into base_table2 values(3,3); + +analyze base_table2; + +CREATE OR REPLACE VIEW join_view3 AS + SELECT + a.base_table_id AS id, + b.some_text AS some_text, + c.base_table_field AS field + FROM base_table a join test b on a.base_table_id = b.id + join base_table2 c on a.base_table_id = c.base_table_id; + +explain (costs off) SELECT count(*) FROM join_view3 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +ERROR: Cannot sample a join view without a key-preserved table +SELECT count(*) FROM join_view3 tablesample system (99.9) REPEATABLE (1); +ERROR: Cannot sample a join view without a key-preserved table + +ALTER TABLE base_table ADD CONSTRAINT xx PRIMARY KEY (base_table_id); +NOTICE: ALTER TABLE / ADD PRIMARY KEY will create implicit index "xx" for table "base_table" +explain (costs off) SELECT count(*) FROM join_view3 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Merge Join + Merge Cond: (b.id = a.base_table_id) + -> Merge Join + Merge Cond: (b.id = c.base_table_id) + -> Index Only Scan using test_pkey on test b + -> Sort + Sort Key: c.base_table_id + -> Sample Scan on base_table2 c + Sampling: bernoulli (99.9) REPEATABLE (1) + -> Sort + Sort Key: a.base_table_id + -> Seq Scan on base_table a +(13 rows) + +SELECT count(*) FROM join_view3 tablesample system (99.9) REPEATABLE (1); + count +------- + 2 +(1 row) + + +ALTER TABLE base_table DROP CONSTRAINT xx; +ALTER TABLE base_table2 ADD CONSTRAINT yy PRIMARY KEY(base_table_id); +NOTICE: ALTER TABLE / ADD PRIMARY KEY will create implicit index "yy" for table "base_table2" +explain (costs off) SELECT count(*) FROM join_view3 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + QUERY PLAN +--------------------------------------------------------------- + Aggregate + -> Merge Join + Merge Cond: (b.id = a.base_table_id) + -> Merge Join + Merge Cond: (b.id = c.base_table_id) + -> Index Only Scan using test_pkey on test b + -> Sort + Sort Key: c.base_table_id + -> Seq Scan on base_table2 c + -> Sort + Sort Key: a.base_table_id + -> Sample Scan on base_table a + Sampling: bernoulli (99.9) REPEATABLE (1) +(13 rows) + +SELECT count(*) FROM join_view3 tablesample system (99.9) REPEATABLE (1); + count +------- + 2 +(1 row) + + +reset search_path; +drop schema tablesample_schema5 cascade; +NOTICE: drop cascades to 11 other objects +DETAIL: drop cascades to table tablesample_schema5.test +drop cascades to table tablesample_schema5.part_list_t1 +drop cascades to table tablesample_schema5.pt_range_hash_test +drop cascades to table tablesample_schema5.base_table +drop cascades to materialized view tablesample_schema5.master_view1 +drop cascades to view tablesample_schema5.master_view2 +drop cascades to view tablesample_schema5.dependent_view1 +drop cascades to view tablesample_schema5.join_view1 +drop cascades to view tablesample_schema5.join_view2 +drop cascades to table tablesample_schema5.base_table2 +drop cascades to view tablesample_schema5.join_view3 + diff --git a/src/test/regress/parallel_schedule0 b/src/test/regress/parallel_schedule0 index 2bddcfe01..a46154a14 100644 --- a/src/test/regress/parallel_schedule0 +++ b/src/test/regress/parallel_schedule0 @@ -723,7 +723,7 @@ test: sqlbypass_partition_prepare # Please fell free to execute each case independently test: srf_fusion srf_fusion_basic srf_fusion_agg -test: string_digit_to_numeric tablesample_3 +test: string_digit_to_numeric tablesample_3 tablesample_4 # Another group of parallel tests # ---------- #test: collate tablesample tablesample_1 tablesample_2 matview @@ -1126,4 +1126,4 @@ test: enable_expr_fusion_flatten # test for on update timestamp and generated column test: on_update_session1 on_update_session2 -test: ts_gb18030_utf8 \ No newline at end of file +test: ts_gb18030_utf8 diff --git a/src/test/regress/parallel_schedule0B b/src/test/regress/parallel_schedule0B index c23b89934..abb385c51 100644 --- a/src/test/regress/parallel_schedule0B +++ b/src/test/regress/parallel_schedule0B @@ -243,7 +243,7 @@ test: sqlbypass_partition_prepare # Please fell free to execute each case independently test: srf_fusion srf_fusion_basic srf_fusion_agg -test: string_digit_to_numeric tablesample_3 +test: string_digit_to_numeric tablesample_3 tablesample_4 # Another group of parallel tests # ---------- #test: collate tablesample tablesample_1 tablesample_2 matview diff --git a/src/test/regress/sql/tablesample_4.sql b/src/test/regress/sql/tablesample_4.sql new file mode 100755 index 000000000..dea760cc6 --- /dev/null +++ b/src/test/regress/sql/tablesample_4.sql @@ -0,0 +1,207 @@ +create schema tablesample_schema5; +set current_schema = tablesample_schema5; + +-- 创建普通表 +CREATE TABLE test ( + id int PRIMARY KEY, + some_timestamp timestamptz, + some_text text +); +-- 插入数据 +INSERT INTO test (id, some_timestamp, some_text) + SELECT + i, + now() - random() * '1 year'::INTERVAL, + 'depesz #' || i + FROM + generate_series(1,100) i; +-- 分析表的块(页)数 +analyze test; +-- 测试SAMPLE子句 +SELECT count(*) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT avg(id) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT sum(id) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (1); +-- 测试SAMPLE BLOCK子句 +SELECT count(*) FROM test tablesample system (99.9) REPEATABLE(1); +SELECT avg(id) FROM test tablesample system (99.9) REPEATABLE (1); +SELECT sum(id) FROM test tablesample system (99.9) REPEATABLE (1); +-- 添加其他过滤条件 +SELECT count(*) FROM test tablesample bernoulli ( 99.9 ) REPEATABLE (105) limit 5; +SELECT count(*) FROM test tablesample system ( 99.9 ) REPEATABLE (105) where id < 5; +SELECT count(*) FROM test tablesample system ( 99.9 ) REPEATABLE (105) limit 5; + +-- 分区表 +--- 一级分区表 +create table part_list_t1( +id number, +name varchar2(20), +age int) +partition by list(age)( +partition age_10 values(10) , +partition age_20 values(20), +partition age_default values(default)); + +insert into part_list_t1 values (1,'aa',10); +insert into part_list_t1 values (2,'bb',10); +insert into part_list_t1 values (3,'cc',20); +insert into part_list_t1 values (4,'dd',20); +insert into part_list_t1 values (5,'ee',20); +insert into part_list_t1 values (6,'ff',30); +insert into part_list_t1 values (7,'gg',100); +insert into part_list_t1 values (8,'hh',110); + +analyze part_list_t1; + +select count(*) from part_list_t1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +select count(*) from part_list_t1 tablesample bernoulli ( 99.9 ) REPEATABLE (1) where id > 5; +select count(*) from part_list_t1 partition (age_10) tablesample bernoulli ( 99.9 ) REPEATABLE (1); +select count(*) from part_list_t1 partition for (20) tablesample system ( 99.9 ) REPEATABLE (1); + +--- 二级分区表 +create table pt_range_hash_test( + pid number(10), + pname varchar2(30), + sex varchar2(10), + create_date date +) partition by range(create_date) + subpartition by hash(pid) subpartitions 4( + partition p1 values less than(to_date('2020-01-01', 'YYYY-MM-DD')) , + partition p2 values less than(to_date('2021-01-01', 'YYYY-MM-DD')) , + partition p3 values less than(to_date('2022-01-01', 'YYYY-MM-DD')) , + partition p4 values less than(maxvalue) + ); + +insert into pt_range_hash_test(pid, pname, sex, create_date) values(1, '瑶瑶', 'WOMAN', to_date('2018-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(2, '壮壮', 'MAN', to_date('2019-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(3, '晴晴', 'WOMAN', to_date('2020-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(4, '琳琳', 'WOMAN', to_date('2020-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(5, '强强', 'MAN', to_date('2021-01-01', 'YYYY-MM-DD')); +insert into pt_range_hash_test(pid, pname, sex, create_date) values(6, '团团', 'WOMAN', to_date('2022-01-01', 'YYYY-MM-DD')); + +analyze pt_range_hash_test; + +select count(*) from pt_range_hash_test tablesample bernoulli ( 99.9 ) REPEATABLE (1); +select count(*) from pt_range_hash_test tablesample bernoulli ( 99.9 ) REPEATABLE (1) where pid < 4; +select count(*) from pt_range_hash_test partition (P2) tablesample bernoulli ( 99.9 ) REPEATABLE (1); +select count(*) from pt_range_hash_test subpartition for(to_date('2020-01-01', 'YYYY-MM-DD'),3) tablesample system ( 99.9 ) REPEATABLE (1); + +-- 物化视图 +CREATE TABLE base_table +( + base_table_id INTEGER, + base_table_field NUMERIC(10,4) +); + +insert into base_table values(1,2); +insert into base_table values(3,4); +insert into base_table values(5,6); + +CREATE MATERIALIZED VIEW master_view1 AS + SELECT + base_table_id AS id, + base_table_field AS field + FROM base_table; + +analyze base_table; +analyze master_view1; + + +SELECT count(*) FROM master_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT avg(id) FROM master_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT sum(id) FROM master_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); + +SELECT count(*) FROM master_view1 tablesample system (99.9) REPEATABLE (1); +SELECT avg(id) FROM master_view1 tablesample system (99.9) REPEATABLE (1); +SELECT sum(id) FROM master_view1 tablesample system (99.9) REPEATABLE (1); + +-- 普通视图 +CREATE OR REPLACE VIEW master_view2 AS + SELECT + base_table_id AS id, + base_table_field AS field + FROM base_table; + +SELECT count(*) FROM master_view2 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM master_view2 tablesample system (99.9) REPEATABLE (1); + +CREATE OR REPLACE VIEW dependent_view1 AS + SELECT + id AS dependent_id, + field AS dependent_field + FROM master_view2; + +SELECT count(*) FROM dependent_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM dependent_view1 tablesample system (99.9) REPEATABLE (1); + +-- 连接视图 +CREATE OR REPLACE VIEW join_view1 AS + SELECT + a.id AS join_id, + base_table_field AS join_field + FROM test a join base_table b on a.id = b.base_table_id; + +explain (costs off) SELECT count(*) FROM join_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view1 tablesample system (99.9); + +CREATE OR REPLACE VIEW join_view1 AS + SELECT + a.id AS join_id, + base_table_field AS join_field + FROM base_table b join test a on b.base_table_id = a.id; + +explain (costs off) SELECT count(*) FROM join_view1 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view1 tablesample system (99.9); + +CREATE OR REPLACE VIEW join_view2 AS + SELECT + b.base_table_id AS nest_join_id, + join_field AS nest_join_field + FROM join_view1 a join base_table b on a.join_id = b.base_table_id; + +explain (costs off) SELECT count(*) FROM join_view2 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view2 tablesample system (99.9); + +CREATE OR REPLACE VIEW join_view2 AS + SELECT + b.id AS nest_join_id, + join_field AS nest_join_field + FROM join_view1 a join test b on a.join_id = b.id; + +explain (costs off) SELECT count(*) FROM join_view2 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view2 tablesample system (99.9) REPEATABLE (1); + +CREATE TABLE base_table2 +( + base_table_id INTEGER, + base_table_field NUMERIC(10,4) +); + +insert into base_table2 values(1,1); +insert into base_table2 values(2,2); +insert into base_table2 values(3,3); + +analyze base_table2; + +CREATE OR REPLACE VIEW join_view3 AS + SELECT + a.base_table_id AS id, + b.some_text AS some_text, + c.base_table_field AS field + FROM base_table a join test b on a.base_table_id = b.id + join base_table2 c on a.base_table_id = c.base_table_id; + +explain (costs off) SELECT count(*) FROM join_view3 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view3 tablesample system (99.9) REPEATABLE (1); + +ALTER TABLE base_table ADD CONSTRAINT xx PRIMARY KEY (base_table_id); +explain (costs off) SELECT count(*) FROM join_view3 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view3 tablesample system (99.9) REPEATABLE (1); + +ALTER TABLE base_table DROP CONSTRAINT xx; +ALTER TABLE base_table2 ADD CONSTRAINT yy PRIMARY KEY(base_table_id); +explain (costs off) SELECT count(*) FROM join_view3 tablesample bernoulli ( 99.9 ) REPEATABLE (1); +SELECT count(*) FROM join_view3 tablesample system (99.9) REPEATABLE (1); + +reset search_path; +drop schema tablesample_schema5 cascade; +