Compare commits

...

6 Commits

Author SHA1 Message Date
Thomas Munro
0013ba290b Add wait events for checkpoint delay mechanism.
When MyProc->delayChkptFlags is set to temporarily block phase
transitions in a concurrent checkpoint, the checkpointer enters a
sleep-poll loop to wait for the flag to be cleared.  We should show that
as a wait event in the pg_stat_activity view.

Reviewed-by: Robert Haas <robertmhaas@gmail.com>
Reviewed-by: Michael Paquier <michael@paquier.xyz>
Discussion: https://postgr.es/m/CA%2BhUKGL7Whi8iwKbzkbn_1fixH3Yy8aAPz7mfq6Hpj7FeJrKMg%40mail.gmail.com
2023-10-13 16:43:22 +13:00
Michael Paquier
7e1f544827 doc: Mention timezone(zone, time) in section for AT TIME ZONE
timezone(zone, timestamp) is already mentioned as an equivalent of the
two first patterns in the table describing the AT TIME ZONE variants,
but did not mention the third case about "time" and its equivalent as an
SQL function, so let's be consistent here.

Extracted from a larger patch by the same author.

Author: Vik Fearing
Discussion: https://postgr.es/m/8e25dec4-5667-c1a5-6581-167d710c2182@postgresfriends.org
2023-10-13 10:55:25 +09:00
Robert Haas
df9a3d4e99 Unify two isLogSwitch tests in XLogInsertRecord.
An upcoming patch wants to introduce an additional special case in
this function. To keep that as cheap as possible, minimize the amount
of branching that we do based on whether this is an XLOG_SWITCH
record.

Additionally, and also in the interest of keeping the overhead of
special-case code paths as low as possible, apply likely() to the
non-XLOG_SWITCH case, since only a very tiny fraction of WAL records
will be XLOG_SWITCH records.

Patch by me, reviewed by Dilip Kumar, Amit Kapila, Andres Freund,
and Michael Paquier.

Discussion: http://postgr.es/m/CA+TgmoYy-Vc6G9QKcAKNksCa29cv__czr+N9X_QCxEfQVpp_8w@mail.gmail.com
2023-10-12 13:48:21 -04:00
David Rowley
d9e46dfb78 Fix runtime partition pruning for HASH partitioned tables
This could only affect HASH partitioned tables with at least 2 partition
key columns.

If partition pruning was delayed until execution and the query contained
an IS NULL qual on one of the partitioned keys, and some subsequent
partitioned key was being compared to a non-Const, then this could result
in a crash due to the incorrect keyno being used to calculate the
stateidx for the expression evaluation code.

Here we fix this by properly skipping partitioned keys which have a
nullkey set.  Effectively, this must be the same as what's going on
inside perform_pruning_base_step().

Sergei Glukhov also provided a patch, but that's not what's being used
here.

Reported-by: Sergei Glukhov
Reviewed-by: tender wang, Sergei Glukhov
Discussion: https://postgr.es/m/d05b26fa-af54-27e1-f693-6c31590802fa@postgrespro.ru
Backpatch-through: 11, where runtime partition pruning was added.
2023-10-13 01:12:31 +13:00
David Rowley
dab5538f0b Doc: fix grammatical errors for enable_partitionwise_aggregate
Author: Andrew Atkinson
Reviewed-by: Ashutosh Bapat
Discussion: https://postgr.es/m/CAG6XLEnC%3DEgq0YHRic2kWWDs4xwQnQ_kBA6qhhzAq1-pO_9Tfw%40mail.gmail.com
Backpatch-through: 11, where enable_partitionwise_aggregate was added
2023-10-12 21:15:28 +13:00
David Rowley
f0c409d9c7 Fix incorrect step generation in HASH partition pruning
get_steps_using_prefix_recurse() incorrectly assumed that it could stop
recursive processing of the 'prefix' list when cur_keyno was one before
the step_lastkeyno.  Since hash partition pruning can prune using IS
NULL quals, and these IS NULL quals are not present in the 'prefix'
list, then that logic could cause more levels of recursion than what is
needed and lead to there being no more items in the 'prefix' list to
process.  This would manifest itself as a crash in some code that
expected the 'start' ListCell not to be NULL.

Here we adjust the logic so that instead of stopping recursion at 1 key
before the step_lastkeyno, we just look at the llast(prefix) item and
ensure we only recursively process up until just before whichever the last
key is.  This effectively allows keys to be missing in the 'prefix' list.

This change does mean that step_lastkeyno is no longer needed, so we
remove that from the static functions.  I also spent quite some time
reading this code and testing it to try to convince myself that there
are no other issues.  That resulted in the irresistible temptation of
rewriting some comments, many of which were just not true or inconcise.

Reported-by: Sergei Glukhov
Reviewed-by: Sergei Glukhov, tender wang
Discussion: https://postgr.es/m/2f09ce72-315e-2a33-589a-8519ada8df61@postgrespro.ru
Backpatch-through: 11, where partition pruning was introduced.
2023-10-12 19:50:38 +13:00
8 changed files with 461 additions and 137 deletions

View File

@ -5271,13 +5271,14 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
<listitem>
<para>
Enables or disables the query planner's use of partitionwise grouping
or aggregation, which allows grouping or aggregation on a partitioned
tables performed separately for each partition. If the <literal>GROUP
BY</literal> clause does not include the partition keys, only partial
aggregation can be performed on a per-partition basis, and
finalization must be performed later. Because partitionwise grouping
or aggregation can use significantly more CPU time and memory during
planning, the default is <literal>off</literal>.
or aggregation, which allows grouping or aggregation on partitioned
tables to be performed separately for each partition. If the
<literal>GROUP BY</literal> clause does not include the partition
keys, only partial aggregation can be performed on a per-partition
basis, and finalization must be performed later. Because
partitionwise grouping or aggregation can use significantly more CPU
time and memory during planning, the default is
<literal>off</literal>.
</para>
</listitem>
</varlistentry>

View File

@ -10738,6 +10738,13 @@ SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'A
<literal><replaceable>timestamp</replaceable> AT TIME ZONE
<replaceable>zone</replaceable></literal>.
</para>
<para>
The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
<replaceable>time</replaceable>)</literal> is equivalent to the SQL-conforming construct
<literal><replaceable>time</replaceable> AT TIME ZONE
<replaceable>zone</replaceable></literal>.
</para>
</sect2>
<sect2 id="functions-datetime-current">

View File

@ -792,26 +792,26 @@ XLogInsertRecord(XLogRecData *rdata,
*----------
*/
START_CRIT_SECTION();
if (isLogSwitch)
WALInsertLockAcquireExclusive();
else
if (likely(!isLogSwitch))
{
WALInsertLockAcquire();
/*
* Check to see if my copy of RedoRecPtr is out of date. If so, may have
* to go back and have the caller recompute everything. This can only
* happen just after a checkpoint, so it's better to be slow in this case
* and fast otherwise.
* Check to see if my copy of RedoRecPtr is out of date. If so, may
* have to go back and have the caller recompute everything. This can
* only happen just after a checkpoint, so it's better to be slow in
* this case and fast otherwise.
*
* Also check to see if fullPageWrites was just turned on or there's a
* running backup (which forces full-page writes); if we weren't already
* doing full-page writes then go back and recompute.
* running backup (which forces full-page writes); if we weren't
* already doing full-page writes then go back and recompute.
*
* If we aren't doing full-page writes then RedoRecPtr doesn't actually
* affect the contents of the XLOG record, so we'll update our local copy
* but not force a recomputation. (If doPageWrites was just turned off,
* we could recompute the record without full pages, but we choose not to
* bother.)
* If we aren't doing full-page writes then RedoRecPtr doesn't
* actually affect the contents of the XLOG record, so we'll update
* our local copy but not force a recomputation. (If doPageWrites was
* just turned off, we could recompute the record without full pages,
* but we choose not to bother.)
*/
if (RedoRecPtr != Insert->RedoRecPtr)
{
@ -825,8 +825,8 @@ XLogInsertRecord(XLogRecData *rdata,
(fpw_lsn != InvalidXLogRecPtr && fpw_lsn <= RedoRecPtr)))
{
/*
* Oops, some buffer now needs to be backed up that the caller didn't
* back up. Start over.
* Oops, some buffer now needs to be backed up that the caller
* didn't back up. Start over.
*/
WALInsertLockRelease();
END_CRIT_SECTION();
@ -837,14 +837,29 @@ XLogInsertRecord(XLogRecData *rdata,
* Reserve space for the record in the WAL. This also sets the xl_prev
* pointer.
*/
if (isLogSwitch)
inserted = ReserveXLogSwitch(&StartPos, &EndPos, &rechdr->xl_prev);
else
{
ReserveXLogInsertLocation(rechdr->xl_tot_len, &StartPos, &EndPos,
&rechdr->xl_prev);
/* Normal records are always inserted. */
inserted = true;
}
else
{
/*
* In order to insert an XLOG_SWITCH record, we need to hold all of
* the WAL insertion locks, not just one, so that no one else can
* begin inserting a record until we've figured out how much space
* remains in the current WAL segment and claimed all of it.
*
* Nonetheless, this case is simpler than the normal cases handled
* above, which must check for changes in doPageWrites and RedoRecPtr.
* Those checks are only needed for records that can contain
* full-pages images, and an XLOG_SWITCH record never does.
*/
Assert(fpw_lsn == InvalidXLogRecPtr);
WALInsertLockAcquireExclusive();
inserted = ReserveXLogSwitch(&StartPos, &EndPos, &rechdr->xl_prev);
}
if (inserted)
{
@ -6722,7 +6737,9 @@ CreateCheckPoint(int flags)
{
do
{
pgstat_report_wait_start(WAIT_EVENT_CHECKPOINT_DELAY_START);
pg_usleep(10000L); /* wait for 10 msec */
pgstat_report_wait_end();
} while (HaveVirtualXIDsDelayingChkpt(vxids, nvxids,
DELAY_CHKPT_START));
}
@ -6735,7 +6752,9 @@ CreateCheckPoint(int flags)
{
do
{
pgstat_report_wait_start(WAIT_EVENT_CHECKPOINT_DELAY_COMPLETE);
pg_usleep(10000L); /* wait for 10 msec */
pgstat_report_wait_end();
} while (HaveVirtualXIDsDelayingChkpt(vxids, nvxids,
DELAY_CHKPT_COMPLETE));
}

View File

@ -2108,7 +2108,7 @@ InitPartitionPruneContext(PartitionPruneContext *context,
foreach(lc, pruning_steps)
{
PartitionPruneStepOp *step = (PartitionPruneStepOp *) lfirst(lc);
ListCell *lc2;
ListCell *lc2 = list_head(step->exprs);
int keyno;
/* not needed for other step kinds */
@ -2117,10 +2117,14 @@ InitPartitionPruneContext(PartitionPruneContext *context,
Assert(list_length(step->exprs) <= partnatts);
keyno = 0;
foreach(lc2, step->exprs)
for (keyno = 0; keyno < partnatts; keyno++)
{
Expr *expr = (Expr *) lfirst(lc2);
if (bms_is_member(keyno, step->nullkeys))
continue;
if (lc2 != NULL)
{
Expr *expr = lfirst(lc2);
/* not needed for Consts */
if (!IsA(expr, Const))
@ -2133,8 +2137,8 @@ InitPartitionPruneContext(PartitionPruneContext *context,
* When planstate is NULL, pruning_steps is known not to
* contain any expressions that depend on the parent plan.
* Information of any available EXTERN parameters must be
* passed explicitly in that case, which the caller must have
* made available via econtext.
* passed explicitly in that case, which the caller must
* have made available via econtext.
*/
if (planstate == NULL)
context->exprstates[stateidx] =
@ -2144,7 +2148,8 @@ InitPartitionPruneContext(PartitionPruneContext *context,
context->exprstates[stateidx] =
ExecInitExpr(expr, context->planstate);
}
keyno++;
lc2 = lnext(step->exprs, lc2);
}
}
}
}

View File

@ -167,7 +167,6 @@ static List *get_steps_using_prefix(GeneratePruningStepsContext *context,
bool step_op_is_ne,
Expr *step_lastexpr,
Oid step_lastcmpfn,
int step_lastkeyno,
Bitmapset *step_nullkeys,
List *prefix);
static List *get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
@ -175,7 +174,6 @@ static List *get_steps_using_prefix_recurse(GeneratePruningStepsContext *context
bool step_op_is_ne,
Expr *step_lastexpr,
Oid step_lastcmpfn,
int step_lastkeyno,
Bitmapset *step_nullkeys,
List *prefix,
ListCell *start,
@ -1531,7 +1529,6 @@ gen_prune_steps_from_opexps(GeneratePruningStepsContext *context,
pc->op_is_ne,
pc->expr,
pc->cmpfn,
0,
NULL,
NIL);
opsteps = list_concat(opsteps, pc_steps);
@ -1657,7 +1654,6 @@ gen_prune_steps_from_opexps(GeneratePruningStepsContext *context,
pc->op_is_ne,
pc->expr,
pc->cmpfn,
pc->keyno,
NULL,
prefix);
opsteps = list_concat(opsteps, pc_steps);
@ -1731,7 +1727,6 @@ gen_prune_steps_from_opexps(GeneratePruningStepsContext *context,
false,
pc->expr,
pc->cmpfn,
pc->keyno,
nullkeys,
prefix);
opsteps = list_concat(opsteps, pc_steps);
@ -2350,25 +2345,31 @@ match_clause_to_partition_key(GeneratePruningStepsContext *context,
/*
* get_steps_using_prefix
* Generate list of PartitionPruneStepOp steps each consisting of given
* opstrategy
* Generate a list of PartitionPruneStepOps based on the given input.
*
* To generate steps, step_lastexpr and step_lastcmpfn are appended to
* expressions and cmpfns, respectively, extracted from the clauses in
* 'prefix'. Actually, since 'prefix' may contain multiple clauses for the
* same partition key column, we must generate steps for various combinations
* of the clauses of different keys.
* 'step_lastexpr' and 'step_lastcmpfn' are the Expr and comparison function
* belonging to the final partition key that we have a clause for. 'prefix'
* is a list of PartClauseInfos for partition key numbers prior to the given
* 'step_lastexpr' and 'step_lastcmpfn'. 'prefix' may contain multiple
* PartClauseInfos belonging to a single partition key. We will generate a
* PartitionPruneStepOp for each combination of the given PartClauseInfos
* using, at most, one PartClauseInfo per partition key.
*
* For list/range partitioning, callers must ensure that step_nullkeys is
* NULL, and that prefix contains at least one clause for each of the
* partition keys earlier than one specified in step_lastkeyno if it's
* greater than zero. For hash partitioning, step_nullkeys is allowed to be
* non-NULL, but they must ensure that prefix contains at least one clause
* for each of the partition keys other than those specified in step_nullkeys
* and step_lastkeyno.
* For LIST and RANGE partitioned tables, callers must ensure that
* step_nullkeys is NULL, and that prefix contains at least one clause for
* each of the partition keys prior to the key that 'step_lastexpr' and
* 'step_lastcmpfn'belong to.
*
* For both cases, callers must also ensure that clauses in prefix are sorted
* in ascending order of their partition key numbers.
* For HASH partitioned tables, callers must ensure that 'prefix' contains at
* least one clause for each of the partition keys apart from the final key
* (the expr and comparison function for the final key are in 'step_lastexpr'
* and 'step_lastcmpfn'). A bit set in step_nullkeys can substitute clauses
* in the 'prefix' list for any given key. If a bit is set in 'step_nullkeys'
* for a given key, then there must be no PartClauseInfo for that key in the
* 'prefix' list.
*
* For each of the above cases, callers must ensure that PartClauseInfos in
* 'prefix' are sorted in ascending order of keyno.
*/
static List *
get_steps_using_prefix(GeneratePruningStepsContext *context,
@ -2376,14 +2377,17 @@ get_steps_using_prefix(GeneratePruningStepsContext *context,
bool step_op_is_ne,
Expr *step_lastexpr,
Oid step_lastcmpfn,
int step_lastkeyno,
Bitmapset *step_nullkeys,
List *prefix)
{
/* step_nullkeys must be empty for RANGE and LIST partitioned tables */
Assert(step_nullkeys == NULL ||
context->rel->part_scheme->strategy == PARTITION_STRATEGY_HASH);
/* Quick exit if there are no values to prefix with. */
/*
* No recursive processing is required when 'prefix' is an empty list.
* This occurs when there is only 1 partition key column.
*/
if (prefix == NIL)
{
PartitionPruneStep *step;
@ -2397,13 +2401,12 @@ get_steps_using_prefix(GeneratePruningStepsContext *context,
return list_make1(step);
}
/* Recurse to generate steps for various combinations. */
/* Recurse to generate steps for every combination of clauses. */
return get_steps_using_prefix_recurse(context,
step_opstrategy,
step_op_is_ne,
step_lastexpr,
step_lastcmpfn,
step_lastkeyno,
step_nullkeys,
prefix,
list_head(prefix),
@ -2412,13 +2415,17 @@ get_steps_using_prefix(GeneratePruningStepsContext *context,
/*
* get_steps_using_prefix_recurse
* Recursively generate combinations of clauses for different partition
* keys and start generating steps upon reaching clauses for the greatest
* column that is less than the one for which we're currently generating
* steps (that is, step_lastkeyno)
* Generate and return a list of PartitionPruneStepOps using the 'prefix'
* list of PartClauseInfos starting at the 'start' cell.
*
* 'prefix' is the list of PartClauseInfos.
* 'start' is where we should start iterating for the current invocation.
* When 'prefix' contains multiple PartClauseInfos for a single partition key
* we create a PartitionPruneStepOp for each combination of duplicated
* PartClauseInfos. The returned list will contain a PartitionPruneStepOp
* for each unique combination of input PartClauseInfos containing at most one
* PartClauseInfo per partition key.
*
* 'prefix' is the input list of PartClauseInfos sorted by keyno.
* 'start' marks the cell that searching the 'prefix' list should start from.
* 'step_exprs' and 'step_cmpfns' each contains the expressions and cmpfns
* we've generated so far from the clauses for the previous part keys.
*/
@ -2428,7 +2435,6 @@ get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
bool step_op_is_ne,
Expr *step_lastexpr,
Oid step_lastcmpfn,
int step_lastkeyno,
Bitmapset *step_nullkeys,
List *prefix,
ListCell *start,
@ -2438,23 +2444,25 @@ get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
List *result = NIL;
ListCell *lc;
int cur_keyno;
int final_keyno;
/* Actually, recursion would be limited by PARTITION_MAX_KEYS. */
check_stack_depth();
/* Check if we need to recurse. */
Assert(start != NULL);
cur_keyno = ((PartClauseInfo *) lfirst(start))->keyno;
if (cur_keyno < step_lastkeyno - 1)
final_keyno = ((PartClauseInfo *) llast(prefix))->keyno;
/* Check if we need to recurse. */
if (cur_keyno < final_keyno)
{
PartClauseInfo *pc;
ListCell *next_start;
/*
* For each clause with cur_keyno, add its expr and cmpfn to
* step_exprs and step_cmpfns, respectively, and recurse after setting
* next_start to the ListCell of the first clause for the next
* partition key.
* Find the first PartClauseInfo belonging to the next partition key,
* the next recursive call must start iteration of the prefix list
* from that point.
*/
for_each_cell(lc, prefix, start)
{
@ -2463,8 +2471,15 @@ get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
if (pc->keyno > cur_keyno)
break;
}
/* record where to start iterating in the next recursive call */
next_start = lc;
/*
* For each PartClauseInfo with keyno set to cur_keyno, add its expr
* and cmpfn to step_exprs and step_cmpfns, respectively, and recurse
* using 'next_start' as the starting point in the 'prefix' list.
*/
for_each_cell(lc, prefix, start)
{
List *moresteps;
@ -2484,6 +2499,7 @@ get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
}
else
{
/* check the 'prefix' list is sorted correctly */
Assert(pc->keyno > cur_keyno);
break;
}
@ -2493,7 +2509,6 @@ get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
step_op_is_ne,
step_lastexpr,
step_lastcmpfn,
step_lastkeyno,
step_nullkeys,
prefix,
next_start,
@ -2512,8 +2527,8 @@ get_steps_using_prefix_recurse(GeneratePruningStepsContext *context,
* each clause with cur_keyno, which is all clauses from here onward
* till the end of the list. Note that for hash partitioning,
* step_nullkeys is allowed to be non-empty, in which case step_exprs
* would only contain expressions for the earlier partition keys that
* are not specified in step_nullkeys.
* would only contain expressions for the partition keys that are not
* specified in step_nullkeys.
*/
Assert(list_length(step_exprs) == cur_keyno ||
!bms_is_empty(step_nullkeys));

View File

@ -97,6 +97,8 @@ BGWORKER_SHUTDOWN "Waiting for background worker to shut down."
BGWORKER_STARTUP "Waiting for background worker to start up."
BTREE_PAGE "Waiting for the page number needed to continue a parallel B-tree scan to become available."
BUFFER_IO "Waiting for buffer I/O to complete."
CHECKPOINT_DELAY_COMPLETE "Waiting for a backend that blocks a checkpoint from completing."
CHECKPOINT_DELAY_START "Waiting for a backend that blocks a checkpoint from starting."
CHECKPOINT_DONE "Waiting for a checkpoint to complete."
CHECKPOINT_START "Waiting for a checkpoint to start."
EXECUTE_GATHER "Waiting for activity from a child process while executing a <literal>Gather</literal> plan node."

View File

@ -1948,7 +1948,6 @@ explain (costs off) select * from hp where a = 1 and b = 'abcde' and
One-Time Filter: false
(2 rows)
drop table hp;
--
-- Test runtime partition pruning
--
@ -2070,6 +2069,27 @@ explain (analyze, costs off, summary off, timing off) execute ab_q3 (2, 2);
Filter: ((b >= $1) AND (b <= $2) AND (a < $0))
(10 rows)
--
-- Test runtime pruning with hash partitioned tables
--
-- recreate partitions dropped above
create table hp1 partition of hp for values with (modulus 4, remainder 1);
create table hp2 partition of hp for values with (modulus 4, remainder 2);
create table hp3 partition of hp for values with (modulus 4, remainder 3);
-- Ensure we correctly prune unneeded partitions when there is an IS NULL qual
prepare hp_q1 (text) as
select * from hp where a is null and b = $1;
explain (costs off) execute hp_q1('xxx');
QUERY PLAN
--------------------------------------------
Append
Subplans Removed: 3
-> Seq Scan on hp2 hp_1
Filter: ((a IS NULL) AND (b = $1))
(4 rows)
deallocate hp_q1;
drop table hp;
-- Test a backwards Append scan
create table list_part (a int) partition by list (a);
create table list_part1 partition of list_part for values in (1);
@ -4011,20 +4031,217 @@ explain (costs off) select * from rp_prefix_test3 where a >= 1 and b >= 1 and b
Filter: ((a >= 1) AND (b >= 1) AND (d >= 0) AND (b = 2) AND (c = 2))
(2 rows)
create table hp_prefix_test (a int, b int, c int, d int) partition by hash (a part_test_int4_ops, b part_test_int4_ops, c part_test_int4_ops, d part_test_int4_ops);
create table hp_prefix_test_p1 partition of hp_prefix_test for values with (modulus 2, remainder 0);
create table hp_prefix_test_p2 partition of hp_prefix_test for values with (modulus 2, remainder 1);
-- Test that get_steps_using_prefix() handles non-NULL step_nullkeys
explain (costs off) select * from hp_prefix_test where a = 1 and b is null and c = 1 and d = 1;
QUERY PLAN
-------------------------------------------------------------
Seq Scan on hp_prefix_test_p1 hp_prefix_test
Filter: ((b IS NULL) AND (a = 1) AND (c = 1) AND (d = 1))
(2 rows)
drop table rp_prefix_test1;
drop table rp_prefix_test2;
drop table rp_prefix_test3;
--
-- Test that get_steps_using_prefix() handles IS NULL clauses correctly
--
create table hp_prefix_test (a int, b int, c int, d int)
partition by hash (a part_test_int4_ops, b part_test_int4_ops, c part_test_int4_ops, d part_test_int4_ops);
-- create 8 partitions
select 'create table hp_prefix_test_p' || x::text || ' partition of hp_prefix_test for values with (modulus 8, remainder ' || x::text || ');'
from generate_Series(0,7) x;
?column?
------------------------------------------------------------------------------------------------------
create table hp_prefix_test_p0 partition of hp_prefix_test for values with (modulus 8, remainder 0);
create table hp_prefix_test_p1 partition of hp_prefix_test for values with (modulus 8, remainder 1);
create table hp_prefix_test_p2 partition of hp_prefix_test for values with (modulus 8, remainder 2);
create table hp_prefix_test_p3 partition of hp_prefix_test for values with (modulus 8, remainder 3);
create table hp_prefix_test_p4 partition of hp_prefix_test for values with (modulus 8, remainder 4);
create table hp_prefix_test_p5 partition of hp_prefix_test for values with (modulus 8, remainder 5);
create table hp_prefix_test_p6 partition of hp_prefix_test for values with (modulus 8, remainder 6);
create table hp_prefix_test_p7 partition of hp_prefix_test for values with (modulus 8, remainder 7);
(8 rows)
\gexec
create table hp_prefix_test_p0 partition of hp_prefix_test for values with (modulus 8, remainder 0);
create table hp_prefix_test_p1 partition of hp_prefix_test for values with (modulus 8, remainder 1);
create table hp_prefix_test_p2 partition of hp_prefix_test for values with (modulus 8, remainder 2);
create table hp_prefix_test_p3 partition of hp_prefix_test for values with (modulus 8, remainder 3);
create table hp_prefix_test_p4 partition of hp_prefix_test for values with (modulus 8, remainder 4);
create table hp_prefix_test_p5 partition of hp_prefix_test for values with (modulus 8, remainder 5);
create table hp_prefix_test_p6 partition of hp_prefix_test for values with (modulus 8, remainder 6);
create table hp_prefix_test_p7 partition of hp_prefix_test for values with (modulus 8, remainder 7);
-- insert 16 rows, one row for each test to perform.
insert into hp_prefix_test
select
case a when 0 then null else 1 end,
case b when 0 then null else 2 end,
case c when 0 then null else 3 end,
case d when 0 then null else 4 end
from
generate_series(0,1) a,
generate_series(0,1) b,
generate_Series(0,1) c,
generate_Series(0,1) d;
-- Ensure partition pruning works correctly for each combination of IS NULL
-- and equality quals. This may seem a little excessive, but there have been
-- a number of bugs in this area over the years. We make use of row only
-- output to reduce the size of the expected results.
\t on
select
'explain (costs off) select tableoid::regclass,* from hp_prefix_test where ' ||
string_agg(c.colname || case when g.s & (1 << c.colpos) = 0 then ' is null' else ' = ' || (colpos+1)::text end, ' and ' order by c.colpos)
from (values('a',0),('b',1),('c',2),('d',3)) c(colname, colpos), generate_Series(0,15) g(s)
group by g.s
order by g.s;
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d is null
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d = 4
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d = 4
\gexec
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d is null
Seq Scan on hp_prefix_test_p0 hp_prefix_test
Filter: ((a IS NULL) AND (b IS NULL) AND (c IS NULL) AND (d IS NULL))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d is null
Seq Scan on hp_prefix_test_p1 hp_prefix_test
Filter: ((b IS NULL) AND (c IS NULL) AND (d IS NULL) AND (a = 1))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d is null
Seq Scan on hp_prefix_test_p2 hp_prefix_test
Filter: ((a IS NULL) AND (c IS NULL) AND (d IS NULL) AND (b = 2))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d is null
Seq Scan on hp_prefix_test_p4 hp_prefix_test
Filter: ((c IS NULL) AND (d IS NULL) AND (a = 1) AND (b = 2))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d is null
Seq Scan on hp_prefix_test_p3 hp_prefix_test
Filter: ((a IS NULL) AND (b IS NULL) AND (d IS NULL) AND (c = 3))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d is null
Seq Scan on hp_prefix_test_p7 hp_prefix_test
Filter: ((b IS NULL) AND (d IS NULL) AND (a = 1) AND (c = 3))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d is null
Seq Scan on hp_prefix_test_p4 hp_prefix_test
Filter: ((a IS NULL) AND (d IS NULL) AND (b = 2) AND (c = 3))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d is null
Seq Scan on hp_prefix_test_p5 hp_prefix_test
Filter: ((d IS NULL) AND (a = 1) AND (b = 2) AND (c = 3))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d = 4
Seq Scan on hp_prefix_test_p4 hp_prefix_test
Filter: ((a IS NULL) AND (b IS NULL) AND (c IS NULL) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d = 4
Seq Scan on hp_prefix_test_p6 hp_prefix_test
Filter: ((b IS NULL) AND (c IS NULL) AND (a = 1) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d = 4
Seq Scan on hp_prefix_test_p5 hp_prefix_test
Filter: ((a IS NULL) AND (c IS NULL) AND (b = 2) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d = 4
Seq Scan on hp_prefix_test_p6 hp_prefix_test
Filter: ((c IS NULL) AND (a = 1) AND (b = 2) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d = 4
Seq Scan on hp_prefix_test_p4 hp_prefix_test
Filter: ((a IS NULL) AND (b IS NULL) AND (c = 3) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d = 4
Seq Scan on hp_prefix_test_p5 hp_prefix_test
Filter: ((b IS NULL) AND (a = 1) AND (c = 3) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d = 4
Seq Scan on hp_prefix_test_p6 hp_prefix_test
Filter: ((a IS NULL) AND (b = 2) AND (c = 3) AND (d = 4))
explain (costs off) select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d = 4
Seq Scan on hp_prefix_test_p4 hp_prefix_test
Filter: ((a = 1) AND (b = 2) AND (c = 3) AND (d = 4))
-- And ensure we get exactly 1 row from each. Again, all 16 possible combinations.
select
'select tableoid::regclass,* from hp_prefix_test where ' ||
string_agg(c.colname || case when g.s & (1 << c.colpos) = 0 then ' is null' else ' = ' || (colpos+1)::text end, ' and ' order by c.colpos)
from (values('a',0),('b',1),('c',2),('d',3)) c(colname, colpos), generate_Series(0,15) g(s)
group by g.s
order by g.s;
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d is null
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d is null
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d is null
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d is null
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d is null
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d is null
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d is null
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d is null
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d = 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d = 4
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d = 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d = 4
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d = 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d = 4
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d = 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d = 4
\gexec
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d is null
hp_prefix_test_p0 | | | |
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d is null
hp_prefix_test_p1 | 1 | | |
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d is null
hp_prefix_test_p2 | | 2 | |
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d is null
hp_prefix_test_p4 | 1 | 2 | |
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d is null
hp_prefix_test_p3 | | | 3 |
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d is null
hp_prefix_test_p7 | 1 | | 3 |
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d is null
hp_prefix_test_p4 | | 2 | 3 |
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d is null
hp_prefix_test_p5 | 1 | 2 | 3 |
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c is null and d = 4
hp_prefix_test_p4 | | | | 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c is null and d = 4
hp_prefix_test_p6 | 1 | | | 4
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c is null and d = 4
hp_prefix_test_p5 | | 2 | | 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c is null and d = 4
hp_prefix_test_p6 | 1 | 2 | | 4
select tableoid::regclass,* from hp_prefix_test where a is null and b is null and c = 3 and d = 4
hp_prefix_test_p4 | | | 3 | 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b is null and c = 3 and d = 4
hp_prefix_test_p5 | 1 | | 3 | 4
select tableoid::regclass,* from hp_prefix_test where a is null and b = 2 and c = 3 and d = 4
hp_prefix_test_p6 | | 2 | 3 | 4
select tableoid::regclass,* from hp_prefix_test where a = 1 and b = 2 and c = 3 and d = 4
hp_prefix_test_p4 | 1 | 2 | 3 | 4
\t off
drop table hp_prefix_test;
--
-- Check that gen_partprune_steps() detects self-contradiction from clauses

View File

@ -384,8 +384,6 @@ drop table hp2;
explain (costs off) select * from hp where a = 1 and b = 'abcde' and
(c = 2 or c = 3);
drop table hp;
--
-- Test runtime partition pruning
--
@ -436,6 +434,25 @@ select a from ab where b between $1 and $2 and a < (select 3);
explain (analyze, costs off, summary off, timing off) execute ab_q3 (2, 2);
--
-- Test runtime pruning with hash partitioned tables
--
-- recreate partitions dropped above
create table hp1 partition of hp for values with (modulus 4, remainder 1);
create table hp2 partition of hp for values with (modulus 4, remainder 2);
create table hp3 partition of hp for values with (modulus 4, remainder 3);
-- Ensure we correctly prune unneeded partitions when there is an IS NULL qual
prepare hp_q1 (text) as
select * from hp where a is null and b = $1;
explain (costs off) execute hp_q1('xxx');
deallocate hp_q1;
drop table hp;
-- Test a backwards Append scan
create table list_part (a int) partition by list (a);
create table list_part1 partition of list_part for values in (1);
@ -1182,16 +1199,57 @@ explain (costs off) select * from rp_prefix_test3 where a >= 1 and b >= 1 and b
-- that the caller arranges clauses in that prefix in the required order)
explain (costs off) select * from rp_prefix_test3 where a >= 1 and b >= 1 and b = 2 and c = 2 and d >= 0;
create table hp_prefix_test (a int, b int, c int, d int) partition by hash (a part_test_int4_ops, b part_test_int4_ops, c part_test_int4_ops, d part_test_int4_ops);
create table hp_prefix_test_p1 partition of hp_prefix_test for values with (modulus 2, remainder 0);
create table hp_prefix_test_p2 partition of hp_prefix_test for values with (modulus 2, remainder 1);
-- Test that get_steps_using_prefix() handles non-NULL step_nullkeys
explain (costs off) select * from hp_prefix_test where a = 1 and b is null and c = 1 and d = 1;
drop table rp_prefix_test1;
drop table rp_prefix_test2;
drop table rp_prefix_test3;
--
-- Test that get_steps_using_prefix() handles IS NULL clauses correctly
--
create table hp_prefix_test (a int, b int, c int, d int)
partition by hash (a part_test_int4_ops, b part_test_int4_ops, c part_test_int4_ops, d part_test_int4_ops);
-- create 8 partitions
select 'create table hp_prefix_test_p' || x::text || ' partition of hp_prefix_test for values with (modulus 8, remainder ' || x::text || ');'
from generate_Series(0,7) x;
\gexec
-- insert 16 rows, one row for each test to perform.
insert into hp_prefix_test
select
case a when 0 then null else 1 end,
case b when 0 then null else 2 end,
case c when 0 then null else 3 end,
case d when 0 then null else 4 end
from
generate_series(0,1) a,
generate_series(0,1) b,
generate_Series(0,1) c,
generate_Series(0,1) d;
-- Ensure partition pruning works correctly for each combination of IS NULL
-- and equality quals. This may seem a little excessive, but there have been
-- a number of bugs in this area over the years. We make use of row only
-- output to reduce the size of the expected results.
\t on
select
'explain (costs off) select tableoid::regclass,* from hp_prefix_test where ' ||
string_agg(c.colname || case when g.s & (1 << c.colpos) = 0 then ' is null' else ' = ' || (colpos+1)::text end, ' and ' order by c.colpos)
from (values('a',0),('b',1),('c',2),('d',3)) c(colname, colpos), generate_Series(0,15) g(s)
group by g.s
order by g.s;
\gexec
-- And ensure we get exactly 1 row from each. Again, all 16 possible combinations.
select
'select tableoid::regclass,* from hp_prefix_test where ' ||
string_agg(c.colname || case when g.s & (1 << c.colpos) = 0 then ' is null' else ' = ' || (colpos+1)::text end, ' and ' order by c.colpos)
from (values('a',0),('b',1),('c',2),('d',3)) c(colname, colpos), generate_Series(0,15) g(s)
group by g.s
order by g.s;
\gexec
\t off
drop table hp_prefix_test;
--