Disk-based Hash Aggregation.

While performing hash aggregation, track memory usage when adding new
groups to a hash table. If the memory usage exceeds work_mem, enter
"spill mode".

In spill mode, new groups are not created in the hash table(s), but
existing groups continue to be advanced if input tuples match. Tuples
that would cause a new group to be created are instead spilled to a
logical tape to be processed later.

The tuples are spilled in a partitioned fashion. When all tuples from
the outer plan are processed (either by advancing the group or
spilling the tuple), finalize and emit the groups from the hash
table. Then, create new batches of work from the spilled partitions,
and select one of the saved batches and process it (possibly spilling
recursively).

Author: Jeff Davis
Reviewed-by: Tomas Vondra, Adam Lee, Justin Pryzby, Taylor Vesely, Melanie Plageman
Discussion: https://postgr.es/m/507ac540ec7c20136364b5272acbcd4574aa76ef.camel@j-davis.com
This commit is contained in:
Jeff Davis 2020-03-18 15:42:02 -07:00
parent e00912e11a
commit 1f39bce021
18 changed files with 1950 additions and 38 deletions

View File

@ -4482,6 +4482,23 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
</listitem>
</varlistentry>
<varlistentry id="guc-enable-groupingsets-hash-disk" xreflabel="enable_groupingsets_hash_disk">
<term><varname>enable_groupingsets_hash_disk</varname> (<type>boolean</type>)
<indexterm>
<primary><varname>enable_groupingsets_hash_disk</varname> configuration parameter</primary>
</indexterm>
</term>
<listitem>
<para>
Enables or disables the query planner's use of hashed aggregation plan
types for grouping sets when the total size of the hash tables is
expected to exceed <varname>work_mem</varname>. See <xref
linkend="queries-grouping-sets"/>. The default is
<literal>off</literal>.
</para>
</listitem>
</varlistentry>
<varlistentry id="guc-enable-hashagg" xreflabel="enable_hashagg">
<term><varname>enable_hashagg</varname> (<type>boolean</type>)
<indexterm>
@ -4496,6 +4513,21 @@ ANY <replaceable class="parameter">num_sync</replaceable> ( <replaceable class="
</listitem>
</varlistentry>
<varlistentry id="guc-enable-hashagg-disk" xreflabel="enable_hashagg_disk">
<term><varname>enable_hashagg_disk</varname> (<type>boolean</type>)
<indexterm>
<primary><varname>enable_hashagg_disk</varname> configuration parameter</primary>
</indexterm>
</term>
<listitem>
<para>
Enables or disables the query planner's use of hashed aggregation plan
types when the memory usage is expected to exceed
<varname>work_mem</varname>. The default is <literal>on</literal>.
</para>
</listitem>
</varlistentry>
<varlistentry id="guc-enable-hashjoin" xreflabel="enable_hashjoin">
<term><varname>enable_hashjoin</varname> (<type>boolean</type>)
<indexterm>

View File

@ -104,6 +104,7 @@ static void show_tablesample(TableSampleClause *tsc, PlanState *planstate,
List *ancestors, ExplainState *es);
static void show_sort_info(SortState *sortstate, ExplainState *es);
static void show_hash_info(HashState *hashstate, ExplainState *es);
static void show_hashagg_info(AggState *hashstate, ExplainState *es);
static void show_tidbitmap_info(BitmapHeapScanState *planstate,
ExplainState *es);
static void show_instrumentation_count(const char *qlabel, int which,
@ -1882,6 +1883,7 @@ ExplainNode(PlanState *planstate, List *ancestors,
case T_Agg:
show_agg_keys(castNode(AggState, planstate), ancestors, es);
show_upper_qual(plan->qual, "Filter", planstate, ancestors, es);
show_hashagg_info((AggState *) planstate, es);
if (plan->qual)
show_instrumentation_count("Rows Removed by Filter", 1,
planstate, es);
@ -2769,6 +2771,41 @@ show_hash_info(HashState *hashstate, ExplainState *es)
}
}
/*
* Show information on hash aggregate memory usage and batches.
*/
static void
show_hashagg_info(AggState *aggstate, ExplainState *es)
{
Agg *agg = (Agg *)aggstate->ss.ps.plan;
long memPeakKb = (aggstate->hash_mem_peak + 1023) / 1024;
Assert(IsA(aggstate, AggState));
if (agg->aggstrategy != AGG_HASHED &&
agg->aggstrategy != AGG_MIXED)
return;
if (es->costs && aggstate->hash_planned_partitions > 0)
{
ExplainPropertyInteger("Planned Partitions", NULL,
aggstate->hash_planned_partitions, es);
}
if (!es->analyze)
return;
/* EXPLAIN ANALYZE */
ExplainPropertyInteger("Peak Memory Usage", "kB", memPeakKb, es);
if (aggstate->hash_batches_used > 0)
{
ExplainPropertyInteger("Disk Usage", "kB",
aggstate->hash_disk_used, es);
ExplainPropertyInteger("HashAgg Batches", NULL,
aggstate->hash_batches_used, es);
}
}
/*
* If it's EXPLAIN ANALYZE, show exact/lossy pages for a BitmapHeapScan node
*/

File diff suppressed because it is too large Load Diff

View File

@ -77,6 +77,7 @@
#include "access/htup_details.h"
#include "access/tsmapi.h"
#include "executor/executor.h"
#include "executor/nodeAgg.h"
#include "executor/nodeHash.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@ -128,6 +129,8 @@ bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_hashagg_disk = true;
bool enable_groupingsets_hash_disk = false;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
@ -2153,7 +2156,7 @@ cost_agg(Path *path, PlannerInfo *root,
int numGroupCols, double numGroups,
List *quals,
Cost input_startup_cost, Cost input_total_cost,
double input_tuples)
double input_tuples, double input_width)
{
double output_tuples;
Cost startup_cost;
@ -2228,14 +2231,79 @@ cost_agg(Path *path, PlannerInfo *root,
startup_cost += disable_cost;
startup_cost += aggcosts->transCost.startup;
startup_cost += aggcosts->transCost.per_tuple * input_tuples;
/* cost of computing hash value */
startup_cost += (cpu_operator_cost * numGroupCols) * input_tuples;
startup_cost += aggcosts->finalCost.startup;
total_cost = startup_cost;
total_cost += aggcosts->finalCost.per_tuple * numGroups;
/* cost of retrieving from hash table */
total_cost += cpu_tuple_cost * numGroups;
output_tuples = numGroups;
}
/*
* Add the disk costs of hash aggregation that spills to disk.
*
* Groups that go into the hash table stay in memory until finalized,
* so spilling and reprocessing tuples doesn't incur additional
* invocations of transCost or finalCost. Furthermore, the computed
* hash value is stored with the spilled tuples, so we don't incur
* extra invocations of the hash function.
*
* Hash Agg begins returning tuples after the first batch is
* complete. Accrue writes (spilled tuples) to startup_cost and to
* total_cost; accrue reads only to total_cost.
*/
if (aggstrategy == AGG_HASHED || aggstrategy == AGG_MIXED)
{
double pages_written = 0.0;
double pages_read = 0.0;
double hashentrysize;
double nbatches;
Size mem_limit;
uint64 ngroups_limit;
int num_partitions;
/*
* Estimate number of batches based on the computed limits. If less
* than or equal to one, all groups are expected to fit in memory;
* otherwise we expect to spill.
*/
hashentrysize = hash_agg_entry_size(
aggcosts->numAggs, input_width, aggcosts->transitionSpace);
hash_agg_set_limits(hashentrysize, numGroups, 0, &mem_limit,
&ngroups_limit, &num_partitions);
nbatches = Max( (numGroups * hashentrysize) / mem_limit,
numGroups / ngroups_limit );
/*
* Estimate number of pages read and written. For each level of
* recursion, a tuple must be written and then later read.
*/
if (nbatches > 1.0)
{
double depth;
double pages;
pages = relation_byte_size(input_tuples, input_width) / BLCKSZ;
/*
* The number of partitions can change at different levels of
* recursion; but for the purposes of this calculation assume it
* stays constant.
*/
depth = ceil( log(nbatches - 1) / log(num_partitions) );
pages_written = pages_read = pages * depth;
}
startup_cost += pages_written * random_page_cost;
total_cost += pages_written * random_page_cost;
total_cost += pages_read * seq_page_cost;
}
/*
* If there are quals (HAVING quals), account for their cost and
* selectivity.

View File

@ -4258,11 +4258,12 @@ consider_groupingsets_paths(PlannerInfo *root,
dNumGroups - exclude_groups);
/*
* gd->rollups is empty if we have only unsortable columns to work
* with. Override work_mem in that case; otherwise, we'll rely on the
* sorted-input case to generate usable mixed paths.
* If we have sortable columns to work with (gd->rollups is non-empty)
* and enable_groupingsets_hash_disk is disabled, don't generate
* hash-based paths that will exceed work_mem.
*/
if (hashsize > work_mem * 1024L && gd->rollups)
if (!enable_groupingsets_hash_disk &&
hashsize > work_mem * 1024L && gd->rollups)
return; /* nope, won't fit */
/*
@ -6528,7 +6529,8 @@ add_paths_to_grouping_rel(PlannerInfo *root, RelOptInfo *input_rel,
* were unable to sort above, then we'd better generate a Path, so
* that we at least have one.
*/
if (hashaggtablesize < work_mem * 1024L ||
if (enable_hashagg_disk ||
hashaggtablesize < work_mem * 1024L ||
grouped_rel->pathlist == NIL)
{
/*
@ -6561,7 +6563,8 @@ add_paths_to_grouping_rel(PlannerInfo *root, RelOptInfo *input_rel,
agg_final_costs,
dNumGroups);
if (hashaggtablesize < work_mem * 1024L)
if (enable_hashagg_disk ||
hashaggtablesize < work_mem * 1024L)
add_path(grouped_rel, (Path *)
create_agg_path(root,
grouped_rel,
@ -6830,7 +6833,7 @@ create_partial_grouping_paths(PlannerInfo *root,
* Tentatively produce a partial HashAgg Path, depending on if it
* looks as if the hash table will fit in work_mem.
*/
if (hashaggtablesize < work_mem * 1024L &&
if ((enable_hashagg_disk || hashaggtablesize < work_mem * 1024L) &&
cheapest_total_path != NULL)
{
add_path(partially_grouped_rel, (Path *)
@ -6857,7 +6860,7 @@ create_partial_grouping_paths(PlannerInfo *root,
dNumPartialPartialGroups);
/* Do the same for partial paths. */
if (hashaggtablesize < work_mem * 1024L &&
if ((enable_hashagg_disk || hashaggtablesize < work_mem * 1024L) &&
cheapest_partial_path != NULL)
{
add_partial_path(partially_grouped_rel, (Path *)

View File

@ -1072,7 +1072,7 @@ choose_hashed_setop(PlannerInfo *root, List *groupClauses,
numGroupCols, dNumGroups,
NIL,
input_path->startup_cost, input_path->total_cost,
input_path->rows);
input_path->rows, input_path->pathtarget->width);
/*
* Now for the sorted case. Note that the input is *always* unsorted,

View File

@ -1704,7 +1704,8 @@ create_unique_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
NIL,
subpath->startup_cost,
subpath->total_cost,
rel->rows);
rel->rows,
subpath->pathtarget->width);
}
if (sjinfo->semi_can_btree && sjinfo->semi_can_hash)
@ -2958,7 +2959,7 @@ create_agg_path(PlannerInfo *root,
list_length(groupClause), numGroups,
qual,
subpath->startup_cost, subpath->total_cost,
subpath->rows);
subpath->rows, subpath->pathtarget->width);
/* add tlist eval cost for each output row */
pathnode->path.startup_cost += target->cost.startup;
@ -3069,7 +3070,8 @@ create_groupingsets_path(PlannerInfo *root,
having_qual,
subpath->startup_cost,
subpath->total_cost,
subpath->rows);
subpath->rows,
subpath->pathtarget->width);
is_first = false;
if (!rollup->is_hashed)
is_first_sort = false;
@ -3092,7 +3094,8 @@ create_groupingsets_path(PlannerInfo *root,
rollup->numGroups,
having_qual,
0.0, 0.0,
subpath->rows);
subpath->rows,
subpath->pathtarget->width);
if (!rollup->is_hashed)
is_first_sort = false;
}
@ -3117,7 +3120,8 @@ create_groupingsets_path(PlannerInfo *root,
having_qual,
sort_path.startup_cost,
sort_path.total_cost,
sort_path.rows);
sort_path.rows,
subpath->pathtarget->width);
}
pathnode->path.total_cost += agg_path.total_cost;

View File

@ -999,6 +999,26 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
{
{"enable_hashagg_disk", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hashed aggregation plans that are expected to exceed work_mem."),
NULL,
GUC_EXPLAIN
},
&enable_hashagg_disk,
true,
NULL, NULL, NULL
},
{
{"enable_groupingsets_hash_disk", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hashed aggregation plans for groupingsets when the total size of the hash tables is expected to exceed work_mem."),
NULL,
GUC_EXPLAIN
},
&enable_groupingsets_hash_disk,
false,
NULL, NULL, NULL
},
{
{"enable_material", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of materialization."),

View File

@ -280,6 +280,11 @@ typedef struct AggStatePerPhaseData
Sort *sortnode; /* Sort node for input ordering for phase */
ExprState *evaltrans; /* evaluation of transition functions */
/* cached variants of the compiled expression */
ExprState *evaltrans_cache
[2] /* 0: outerops; 1: TTSOpsMinimalTuple */
[2]; /* 0: no NULL check; 1: with NULL check */
} AggStatePerPhaseData;
/*
@ -311,5 +316,8 @@ extern void ExecReScanAgg(AggState *node);
extern Size hash_agg_entry_size(int numAggs, Size tupleWidth,
Size transitionSpace);
extern void hash_agg_set_limits(double hashentrysize, uint64 input_groups,
int used_bits, Size *mem_limit,
uint64 *ngroups_limit, int *num_partitions);
#endif /* NODEAGG_H */

View File

@ -2079,12 +2079,32 @@ typedef struct AggState
/* these fields are used in AGG_HASHED and AGG_MIXED modes: */
bool table_filled; /* hash table filled yet? */
int num_hashes;
MemoryContext hash_metacxt; /* memory for hash table itself */
struct HashTapeInfo *hash_tapeinfo; /* metadata for spill tapes */
struct HashAggSpill *hash_spills; /* HashAggSpill for each grouping set,
exists only during first pass */
TupleTableSlot *hash_spill_slot; /* slot for reading from spill files */
List *hash_batches; /* hash batches remaining to be processed */
bool hash_ever_spilled; /* ever spilled during this execution? */
bool hash_spill_mode; /* we hit a limit during the current batch
and we must not create new groups */
Size hash_mem_limit; /* limit before spilling hash table */
uint64 hash_ngroups_limit; /* limit before spilling hash table */
int hash_planned_partitions; /* number of partitions planned
for first pass */
double hashentrysize; /* estimate revised during execution */
Size hash_mem_peak; /* peak hash table memory usage */
uint64 hash_ngroups_current; /* number of groups currently in
memory in all hash tables */
uint64 hash_disk_used; /* kB of disk space used */
int hash_batches_used; /* batches used during entire execution */
AggStatePerHash perhash; /* array of per-hashtable data */
AggStatePerGroup *hash_pergroup; /* grouping set indexed array of
* per-group pointers */
/* support for evaluation of agg input expressions: */
#define FIELDNO_AGGSTATE_ALL_PERGROUPS 34
#define FIELDNO_AGGSTATE_ALL_PERGROUPS 49
AggStatePerGroup *all_pergroups; /* array of first ->pergroups, than
* ->hash_pergroup */
ProjectionInfo *combinedproj; /* projection machinery */

View File

@ -54,6 +54,8 @@ extern PGDLLIMPORT bool enable_bitmapscan;
extern PGDLLIMPORT bool enable_tidscan;
extern PGDLLIMPORT bool enable_sort;
extern PGDLLIMPORT bool enable_hashagg;
extern PGDLLIMPORT bool enable_hashagg_disk;
extern PGDLLIMPORT bool enable_groupingsets_hash_disk;
extern PGDLLIMPORT bool enable_nestloop;
extern PGDLLIMPORT bool enable_material;
extern PGDLLIMPORT bool enable_mergejoin;
@ -114,7 +116,7 @@ extern void cost_agg(Path *path, PlannerInfo *root,
int numGroupCols, double numGroups,
List *quals,
Cost input_startup_cost, Cost input_total_cost,
double input_tuples);
double input_tuples, double input_width);
extern void cost_windowagg(Path *path, PlannerInfo *root,
List *windowFuncs, int numPartCols, int numOrderCols,
Cost input_startup_cost, Cost input_total_cost,

View File

@ -2357,3 +2357,187 @@ explain (costs off)
-> Seq Scan on onek
(8 rows)
--
-- Hash Aggregation Spill tests
--
set enable_sort=false;
set work_mem='64kB';
select unique1, count(*), sum(twothousand) from tenk1
group by unique1
having sum(fivethous) > 4975
order by sum(twothousand);
unique1 | count | sum
---------+-------+------
4976 | 1 | 976
4977 | 1 | 977
4978 | 1 | 978
4979 | 1 | 979
4980 | 1 | 980
4981 | 1 | 981
4982 | 1 | 982
4983 | 1 | 983
4984 | 1 | 984
4985 | 1 | 985
4986 | 1 | 986
4987 | 1 | 987
4988 | 1 | 988
4989 | 1 | 989
4990 | 1 | 990
4991 | 1 | 991
4992 | 1 | 992
4993 | 1 | 993
4994 | 1 | 994
4995 | 1 | 995
4996 | 1 | 996
4997 | 1 | 997
4998 | 1 | 998
4999 | 1 | 999
9976 | 1 | 1976
9977 | 1 | 1977
9978 | 1 | 1978
9979 | 1 | 1979
9980 | 1 | 1980
9981 | 1 | 1981
9982 | 1 | 1982
9983 | 1 | 1983
9984 | 1 | 1984
9985 | 1 | 1985
9986 | 1 | 1986
9987 | 1 | 1987
9988 | 1 | 1988
9989 | 1 | 1989
9990 | 1 | 1990
9991 | 1 | 1991
9992 | 1 | 1992
9993 | 1 | 1993
9994 | 1 | 1994
9995 | 1 | 1995
9996 | 1 | 1996
9997 | 1 | 1997
9998 | 1 | 1998
9999 | 1 | 1999
(48 rows)
set work_mem to default;
set enable_sort to default;
--
-- Compare results between plans using sorting and plans using hash
-- aggregation. Force spilling in both cases by setting work_mem low.
--
set work_mem='64kB';
-- Produce results with sorting.
set enable_hashagg = false;
set jit_above_cost = 0;
explain (costs off)
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
QUERY PLAN
------------------------------------------------
GroupAggregate
Group Key: ((g % 100000))
-> Sort
Sort Key: ((g % 100000))
-> Function Scan on generate_series g
(5 rows)
create table agg_group_1 as
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
create table agg_group_2 as
select * from
(values (100), (300), (500)) as r(a),
lateral (
select (g/2)::numeric as c1,
array_agg(g::numeric) as c2,
count(*) as c3
from generate_series(0, 1999) g
where g < r.a
group by g/2) as s;
set jit_above_cost to default;
create table agg_group_3 as
select (g/2)::numeric as c1, sum(7::int4) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
create table agg_group_4 as
select (g/2)::numeric as c1, array_agg(g::numeric) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
-- Produce results with hash aggregation
set enable_hashagg = true;
set enable_sort = false;
set jit_above_cost = 0;
explain (costs off)
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
QUERY PLAN
------------------------------------------
HashAggregate
Group Key: (g % 100000)
-> Function Scan on generate_series g
(3 rows)
create table agg_hash_1 as
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
create table agg_hash_2 as
select * from
(values (100), (300), (500)) as r(a),
lateral (
select (g/2)::numeric as c1,
array_agg(g::numeric) as c2,
count(*) as c3
from generate_series(0, 1999) g
where g < r.a
group by g/2) as s;
set jit_above_cost to default;
create table agg_hash_3 as
select (g/2)::numeric as c1, sum(7::int4) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
create table agg_hash_4 as
select (g/2)::numeric as c1, array_agg(g::numeric) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
set enable_sort = true;
set work_mem to default;
-- Compare group aggregation results to hash aggregation results
(select * from agg_hash_1 except select * from agg_group_1)
union all
(select * from agg_group_1 except select * from agg_hash_1);
c1 | c2 | c3
----+----+----
(0 rows)
(select * from agg_hash_2 except select * from agg_group_2)
union all
(select * from agg_group_2 except select * from agg_hash_2);
a | c1 | c2 | c3
---+----+----+----
(0 rows)
(select * from agg_hash_3 except select * from agg_group_3)
union all
(select * from agg_group_3 except select * from agg_hash_3);
c1 | c2 | c3
----+----+----
(0 rows)
(select * from agg_hash_4 except select * from agg_group_4)
union all
(select * from agg_group_4 except select * from agg_hash_4);
c1 | c2 | c3
----+----+----
(0 rows)
drop table agg_group_1;
drop table agg_group_2;
drop table agg_group_3;
drop table agg_group_4;
drop table agg_hash_1;
drop table agg_hash_2;
drop table agg_hash_3;
drop table agg_hash_4;

View File

@ -1633,4 +1633,126 @@ select v||'a', case when grouping(v||'a') = 1 then 1 else 0 end, count(*)
| 1 | 2
(4 rows)
--
-- Compare results between plans using sorting and plans using hash
-- aggregation. Force spilling in both cases by setting work_mem low
-- and turning on enable_groupingsets_hash_disk.
--
SET enable_groupingsets_hash_disk = true;
SET work_mem='64kB';
-- Produce results with sorting.
set enable_hashagg = false;
set jit_above_cost = 0;
explain (costs off)
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
QUERY PLAN
---------------------------------------------------------------
GroupAggregate
Group Key: ((g.g % 1000)), ((g.g % 100)), ((g.g % 10))
Group Key: ((g.g % 1000)), ((g.g % 100))
Group Key: ((g.g % 1000))
Group Key: ()
Sort Key: ((g.g % 100)), ((g.g % 10))
Group Key: ((g.g % 100)), ((g.g % 10))
Group Key: ((g.g % 100))
Sort Key: ((g.g % 10)), ((g.g % 1000))
Group Key: ((g.g % 10)), ((g.g % 1000))
Group Key: ((g.g % 10))
-> Sort
Sort Key: ((g.g % 1000)), ((g.g % 100)), ((g.g % 10))
-> Function Scan on generate_series g
(14 rows)
create table gs_group_1 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
set jit_above_cost to default;
create table gs_group_2 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g/20 as g1000, g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by cube (g1000,g100,g10);
create table gs_group_3 as
select g100, g10, array_agg(g) as a, count(*) as c, max(g::text) as m from
(select g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by grouping sets (g100,g10);
-- Produce results with hash aggregation.
set enable_hashagg = true;
set enable_sort = false;
set work_mem='64kB';
set jit_above_cost = 0;
explain (costs off)
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
QUERY PLAN
---------------------------------------------------
MixedAggregate
Hash Key: (g.g % 1000), (g.g % 100), (g.g % 10)
Hash Key: (g.g % 1000), (g.g % 100)
Hash Key: (g.g % 1000)
Hash Key: (g.g % 100), (g.g % 10)
Hash Key: (g.g % 100)
Hash Key: (g.g % 10), (g.g % 1000)
Hash Key: (g.g % 10)
Group Key: ()
-> Function Scan on generate_series g
(10 rows)
create table gs_hash_1 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
set jit_above_cost to default;
create table gs_hash_2 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g/20 as g1000, g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by cube (g1000,g100,g10);
create table gs_hash_3 as
select g100, g10, array_agg(g) as a, count(*) as c, max(g::text) as m from
(select g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by grouping sets (g100,g10);
set enable_sort = true;
set work_mem to default;
-- Compare results
(select * from gs_hash_1 except select * from gs_group_1)
union all
(select * from gs_group_1 except select * from gs_hash_1);
g1000 | g100 | g10 | sum | count | max
-------+------+-----+-----+-------+-----
(0 rows)
(select * from gs_hash_2 except select * from gs_group_2)
union all
(select * from gs_group_2 except select * from gs_hash_2);
g1000 | g100 | g10 | sum | count | max
-------+------+-----+-----+-------+-----
(0 rows)
(select g100,g10,unnest(a),c,m from gs_hash_3 except
select g100,g10,unnest(a),c,m from gs_group_3)
union all
(select g100,g10,unnest(a),c,m from gs_group_3 except
select g100,g10,unnest(a),c,m from gs_hash_3);
g100 | g10 | unnest | c | m
------+-----+--------+---+---
(0 rows)
drop table gs_group_1;
drop table gs_group_2;
drop table gs_group_3;
drop table gs_hash_1;
drop table gs_hash_2;
drop table gs_hash_3;
SET enable_groupingsets_hash_disk TO DEFAULT;
-- end

View File

@ -148,6 +148,68 @@ SELECT count(*) FROM
4
(1 row)
--
-- Compare results between plans using sorting and plans using hash
-- aggregation. Force spilling in both cases by setting work_mem low.
--
SET work_mem='64kB';
-- Produce results with sorting.
SET enable_hashagg=FALSE;
SET jit_above_cost=0;
EXPLAIN (costs off)
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
QUERY PLAN
------------------------------------------------
Unique
-> Sort
Sort Key: ((g % 1000))
-> Function Scan on generate_series g
(4 rows)
CREATE TABLE distinct_group_1 AS
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
SET jit_above_cost TO DEFAULT;
CREATE TABLE distinct_group_2 AS
SELECT DISTINCT (g%1000)::text FROM generate_series(0,9999) g;
SET enable_hashagg=TRUE;
-- Produce results with hash aggregation.
SET enable_sort=FALSE;
SET jit_above_cost=0;
EXPLAIN (costs off)
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
QUERY PLAN
------------------------------------------
HashAggregate
Group Key: (g % 1000)
-> Function Scan on generate_series g
(3 rows)
CREATE TABLE distinct_hash_1 AS
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
SET jit_above_cost TO DEFAULT;
CREATE TABLE distinct_hash_2 AS
SELECT DISTINCT (g%1000)::text FROM generate_series(0,9999) g;
SET enable_sort=TRUE;
SET work_mem TO DEFAULT;
-- Compare results
(SELECT * FROM distinct_hash_1 EXCEPT SELECT * FROM distinct_group_1)
UNION ALL
(SELECT * FROM distinct_group_1 EXCEPT SELECT * FROM distinct_hash_1);
?column?
----------
(0 rows)
(SELECT * FROM distinct_hash_1 EXCEPT SELECT * FROM distinct_group_1)
UNION ALL
(SELECT * FROM distinct_group_1 EXCEPT SELECT * FROM distinct_hash_1);
?column?
----------
(0 rows)
DROP TABLE distinct_hash_1;
DROP TABLE distinct_hash_2;
DROP TABLE distinct_group_1;
DROP TABLE distinct_group_2;
--
-- Also, some tests of IS DISTINCT FROM, which doesn't quite deserve its
-- very own regression file.

View File

@ -74,7 +74,9 @@ select name, setting from pg_settings where name like 'enable%';
--------------------------------+---------
enable_bitmapscan | on
enable_gathermerge | on
enable_groupingsets_hash_disk | off
enable_hashagg | on
enable_hashagg_disk | on
enable_hashjoin | on
enable_indexonlyscan | on
enable_indexscan | on
@ -89,7 +91,7 @@ select name, setting from pg_settings where name like 'enable%';
enable_seqscan | on
enable_sort | on
enable_tidscan | on
(17 rows)
(19 rows)
-- Test that the pg_timezone_names and pg_timezone_abbrevs views are
-- more-or-less working. We can't test their contents in any great detail

View File

@ -1032,3 +1032,134 @@ select v||'a', case when v||'a' = 'aa' then 1 else 0 end, count(*)
explain (costs off)
select 1 from tenk1
where (hundred, thousand) in (select twothousand, twothousand from onek);
--
-- Hash Aggregation Spill tests
--
set enable_sort=false;
set work_mem='64kB';
select unique1, count(*), sum(twothousand) from tenk1
group by unique1
having sum(fivethous) > 4975
order by sum(twothousand);
set work_mem to default;
set enable_sort to default;
--
-- Compare results between plans using sorting and plans using hash
-- aggregation. Force spilling in both cases by setting work_mem low.
--
set work_mem='64kB';
-- Produce results with sorting.
set enable_hashagg = false;
set jit_above_cost = 0;
explain (costs off)
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
create table agg_group_1 as
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
create table agg_group_2 as
select * from
(values (100), (300), (500)) as r(a),
lateral (
select (g/2)::numeric as c1,
array_agg(g::numeric) as c2,
count(*) as c3
from generate_series(0, 1999) g
where g < r.a
group by g/2) as s;
set jit_above_cost to default;
create table agg_group_3 as
select (g/2)::numeric as c1, sum(7::int4) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
create table agg_group_4 as
select (g/2)::numeric as c1, array_agg(g::numeric) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
-- Produce results with hash aggregation
set enable_hashagg = true;
set enable_sort = false;
set jit_above_cost = 0;
explain (costs off)
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
create table agg_hash_1 as
select g%100000 as c1, sum(g::numeric) as c2, count(*) as c3
from generate_series(0, 199999) g
group by g%100000;
create table agg_hash_2 as
select * from
(values (100), (300), (500)) as r(a),
lateral (
select (g/2)::numeric as c1,
array_agg(g::numeric) as c2,
count(*) as c3
from generate_series(0, 1999) g
where g < r.a
group by g/2) as s;
set jit_above_cost to default;
create table agg_hash_3 as
select (g/2)::numeric as c1, sum(7::int4) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
create table agg_hash_4 as
select (g/2)::numeric as c1, array_agg(g::numeric) as c2, count(*) as c3
from generate_series(0, 1999) g
group by g/2;
set enable_sort = true;
set work_mem to default;
-- Compare group aggregation results to hash aggregation results
(select * from agg_hash_1 except select * from agg_group_1)
union all
(select * from agg_group_1 except select * from agg_hash_1);
(select * from agg_hash_2 except select * from agg_group_2)
union all
(select * from agg_group_2 except select * from agg_hash_2);
(select * from agg_hash_3 except select * from agg_group_3)
union all
(select * from agg_group_3 except select * from agg_hash_3);
(select * from agg_hash_4 except select * from agg_group_4)
union all
(select * from agg_group_4 except select * from agg_hash_4);
drop table agg_group_1;
drop table agg_group_2;
drop table agg_group_3;
drop table agg_group_4;
drop table agg_hash_1;
drop table agg_hash_2;
drop table agg_hash_3;
drop table agg_hash_4;

View File

@ -441,4 +441,107 @@ select v||'a', case when grouping(v||'a') = 1 then 1 else 0 end, count(*)
from unnest(array[1,1], array['a','b']) u(i,v)
group by rollup(i, v||'a') order by 1,3;
--
-- Compare results between plans using sorting and plans using hash
-- aggregation. Force spilling in both cases by setting work_mem low
-- and turning on enable_groupingsets_hash_disk.
--
SET enable_groupingsets_hash_disk = true;
SET work_mem='64kB';
-- Produce results with sorting.
set enable_hashagg = false;
set jit_above_cost = 0;
explain (costs off)
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
create table gs_group_1 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
set jit_above_cost to default;
create table gs_group_2 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g/20 as g1000, g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by cube (g1000,g100,g10);
create table gs_group_3 as
select g100, g10, array_agg(g) as a, count(*) as c, max(g::text) as m from
(select g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by grouping sets (g100,g10);
-- Produce results with hash aggregation.
set enable_hashagg = true;
set enable_sort = false;
set work_mem='64kB';
set jit_above_cost = 0;
explain (costs off)
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
create table gs_hash_1 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g%1000 as g1000, g%100 as g100, g%10 as g10, g
from generate_series(0,199999) g) s
group by cube (g1000,g100,g10);
set jit_above_cost to default;
create table gs_hash_2 as
select g1000, g100, g10, sum(g::numeric), count(*), max(g::text) from
(select g/20 as g1000, g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by cube (g1000,g100,g10);
create table gs_hash_3 as
select g100, g10, array_agg(g) as a, count(*) as c, max(g::text) as m from
(select g/200 as g100, g/2000 as g10, g
from generate_series(0,19999) g) s
group by grouping sets (g100,g10);
set enable_sort = true;
set work_mem to default;
-- Compare results
(select * from gs_hash_1 except select * from gs_group_1)
union all
(select * from gs_group_1 except select * from gs_hash_1);
(select * from gs_hash_2 except select * from gs_group_2)
union all
(select * from gs_group_2 except select * from gs_hash_2);
(select g100,g10,unnest(a),c,m from gs_hash_3 except
select g100,g10,unnest(a),c,m from gs_group_3)
union all
(select g100,g10,unnest(a),c,m from gs_group_3 except
select g100,g10,unnest(a),c,m from gs_hash_3);
drop table gs_group_1;
drop table gs_group_2;
drop table gs_group_3;
drop table gs_hash_1;
drop table gs_hash_2;
drop table gs_hash_3;
SET enable_groupingsets_hash_disk TO DEFAULT;
-- end

View File

@ -45,6 +45,68 @@ SELECT count(*) FROM
SELECT count(*) FROM
(SELECT DISTINCT two, four, two FROM tenk1) ss;
--
-- Compare results between plans using sorting and plans using hash
-- aggregation. Force spilling in both cases by setting work_mem low.
--
SET work_mem='64kB';
-- Produce results with sorting.
SET enable_hashagg=FALSE;
SET jit_above_cost=0;
EXPLAIN (costs off)
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
CREATE TABLE distinct_group_1 AS
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
SET jit_above_cost TO DEFAULT;
CREATE TABLE distinct_group_2 AS
SELECT DISTINCT (g%1000)::text FROM generate_series(0,9999) g;
SET enable_hashagg=TRUE;
-- Produce results with hash aggregation.
SET enable_sort=FALSE;
SET jit_above_cost=0;
EXPLAIN (costs off)
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
CREATE TABLE distinct_hash_1 AS
SELECT DISTINCT g%1000 FROM generate_series(0,9999) g;
SET jit_above_cost TO DEFAULT;
CREATE TABLE distinct_hash_2 AS
SELECT DISTINCT (g%1000)::text FROM generate_series(0,9999) g;
SET enable_sort=TRUE;
SET work_mem TO DEFAULT;
-- Compare results
(SELECT * FROM distinct_hash_1 EXCEPT SELECT * FROM distinct_group_1)
UNION ALL
(SELECT * FROM distinct_group_1 EXCEPT SELECT * FROM distinct_hash_1);
(SELECT * FROM distinct_hash_1 EXCEPT SELECT * FROM distinct_group_1)
UNION ALL
(SELECT * FROM distinct_group_1 EXCEPT SELECT * FROM distinct_hash_1);
DROP TABLE distinct_hash_1;
DROP TABLE distinct_hash_2;
DROP TABLE distinct_group_1;
DROP TABLE distinct_group_2;
--
-- Also, some tests of IS DISTINCT FROM, which doesn't quite deserve its
-- very own regression file.