Commit 368df304 authored by Tom Lane's avatar Tom Lane

Support hashing for duplicate-elimination in INTERSECT and EXCEPT queries.

This completes my project of improving usage of hashing for duplicate
elimination (aggregate functions with DISTINCT remain undone, but that's
for some other day).

As with the previous patches, this means we can INTERSECT/EXCEPT on datatypes
that can hash but not sort, and it means that INTERSECT/EXCEPT without ORDER
BY are no longer certain to produce sorted output.
parent 2d1d96b1
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1994-5, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/commands/explain.c,v 1.175 2008/05/14 19:10:29 tgl Exp $
* $PostgreSQL: pgsql/src/backend/commands/explain.c,v 1.176 2008/08/07 03:04:03 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -558,19 +558,47 @@ explain_outNode(StringInfo str,
pname = "Unique";
break;
case T_SetOp:
switch (((SetOp *) plan)->cmd)
switch (((SetOp *) plan)->strategy)
{
case SETOPCMD_INTERSECT:
pname = "SetOp Intersect";
case SETOP_SORTED:
switch (((SetOp *) plan)->cmd)
{
case SETOPCMD_INTERSECT:
pname = "SetOp Intersect";
break;
case SETOPCMD_INTERSECT_ALL:
pname = "SetOp Intersect All";
break;
case SETOPCMD_EXCEPT:
pname = "SetOp Except";
break;
case SETOPCMD_EXCEPT_ALL:
pname = "SetOp Except All";
break;
default:
pname = "SetOp ???";
break;
}
break;
case SETOPCMD_INTERSECT_ALL:
pname = "SetOp Intersect All";
break;
case SETOPCMD_EXCEPT:
pname = "SetOp Except";
break;
case SETOPCMD_EXCEPT_ALL:
pname = "SetOp Except All";
case SETOP_HASHED:
switch (((SetOp *) plan)->cmd)
{
case SETOPCMD_INTERSECT:
pname = "HashSetOp Intersect";
break;
case SETOPCMD_INTERSECT_ALL:
pname = "HashSetOp Intersect All";
break;
case SETOPCMD_EXCEPT:
pname = "HashSetOp Except";
break;
case SETOPCMD_EXCEPT_ALL:
pname = "HashSetOp Except All";
break;
default:
pname = "HashSetOp ???";
break;
}
break;
default:
pname = "SetOp ???";
......
This diff is collapsed.
......@@ -15,7 +15,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.397 2008/08/07 01:11:46 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.398 2008/08/07 03:04:03 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -652,10 +652,12 @@ _copySetOp(SetOp *from)
* copy remainder of node
*/
COPY_SCALAR_FIELD(cmd);
COPY_SCALAR_FIELD(strategy);
COPY_SCALAR_FIELD(numCols);
COPY_POINTER_FIELD(dupColIdx, from->numCols * sizeof(AttrNumber));
COPY_POINTER_FIELD(dupOperators, from->numCols * sizeof(Oid));
COPY_SCALAR_FIELD(flagColIdx);
COPY_SCALAR_FIELD(numGroups);
return newnode;
}
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/outfuncs.c,v 1.331 2008/08/07 01:11:48 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/outfuncs.c,v 1.332 2008/08/07 03:04:03 tgl Exp $
*
* NOTES
* Every node type that can appear in stored rules' parsetrees *must*
......@@ -599,6 +599,7 @@ _outSetOp(StringInfo str, SetOp *node)
_outPlanInfo(str, (Plan *) node);
WRITE_ENUM_FIELD(cmd, SetOpCmd);
WRITE_ENUM_FIELD(strategy, SetOpStrategy);
WRITE_INT_FIELD(numCols);
appendStringInfo(str, " :dupColIdx");
......@@ -610,6 +611,7 @@ _outSetOp(StringInfo str, SetOp *node)
appendStringInfo(str, " %u", node->dupOperators[i]);
WRITE_INT_FIELD(flagColIdx);
WRITE_LONG_FIELD(numGroups);
}
static void
......
......@@ -10,7 +10,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/optimizer/plan/createplan.c,v 1.242 2008/08/02 21:32:00 tgl Exp $
* $PostgreSQL: pgsql/src/backend/optimizer/plan/createplan.c,v 1.243 2008/08/07 03:04:03 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -3108,8 +3108,9 @@ make_unique(Plan *lefttree, List *distinctList)
* already be sorted accordingly.
*/
SetOp *
make_setop(SetOpCmd cmd, Plan *lefttree,
List *distinctList, AttrNumber flagColIdx)
make_setop(SetOpCmd cmd, SetOpStrategy strategy, Plan *lefttree,
List *distinctList, AttrNumber flagColIdx, long numGroups,
double outputRows)
{
SetOp *node = makeNode(SetOp);
Plan *plan = &node->plan;
......@@ -3120,20 +3121,13 @@ make_setop(SetOpCmd cmd, Plan *lefttree,
ListCell *slitem;
copy_plan_costsize(plan, lefttree);
plan->plan_rows = outputRows;
/*
* Charge one cpu_operator_cost per comparison per input tuple. We assume
* all columns get compared at most of the tuples.
*/
plan->total_cost += cpu_operator_cost * plan->plan_rows * numCols;
/*
* We make the unsupported assumption that there will be 10% as many
* tuples out as in. Any way to do better?
*/
plan->plan_rows *= 0.1;
if (plan->plan_rows < 1)
plan->plan_rows = 1;
plan->total_cost += cpu_operator_cost * lefttree->plan_rows * numCols;
plan->targetlist = lefttree->targetlist;
plan->qual = NIL;
......@@ -3160,10 +3154,12 @@ make_setop(SetOpCmd cmd, Plan *lefttree,
}
node->cmd = cmd;
node->strategy = strategy;
node->numCols = numCols;
node->dupColIdx = dupColIdx;
node->dupOperators = dupOperators;
node->flagColIdx = flagColIdx;
node->numGroups = numGroups;
return node;
}
......
......@@ -22,7 +22,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/optimizer/prep/prepunion.c,v 1.150 2008/08/07 01:11:50 tgl Exp $
* $PostgreSQL: pgsql/src/backend/optimizer/prep/prepunion.c,v 1.151 2008/08/07 03:04:03 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -60,6 +60,7 @@ static Plan *generate_union_plan(SetOperationStmt *op, PlannerInfo *root,
double tuple_fraction,
List *refnames_tlist, List **sortClauses);
static Plan *generate_nonunion_plan(SetOperationStmt *op, PlannerInfo *root,
double tuple_fraction,
List *refnames_tlist, List **sortClauses);
static List *recurse_union_children(Node *setOp, PlannerInfo *root,
double tuple_fraction,
......@@ -229,7 +230,7 @@ recurse_set_operations(Node *setOp, PlannerInfo *root,
refnames_tlist,
sortClauses);
else
plan = generate_nonunion_plan(op, root,
plan = generate_nonunion_plan(op, root, tuple_fraction,
refnames_tlist,
sortClauses);
......@@ -341,6 +342,7 @@ generate_union_plan(SetOperationStmt *op, PlannerInfo *root,
*/
static Plan *
generate_nonunion_plan(SetOperationStmt *op, PlannerInfo *root,
double tuple_fraction,
List *refnames_tlist,
List **sortClauses)
{
......@@ -351,6 +353,10 @@ generate_nonunion_plan(SetOperationStmt *op, PlannerInfo *root,
*groupList,
*planlist,
*child_sortclauses;
double dNumDistinctRows;
double dNumOutputRows;
long numDistinctRows;
bool use_hash;
SetOpCmd cmd;
/* Recurse on children, ensuring their outputs are marked */
......@@ -393,10 +399,32 @@ generate_nonunion_plan(SetOperationStmt *op, PlannerInfo *root,
return plan;
}
/*
* XXX for the moment, take the number of distinct groups as being the
* total input size, ie, the worst case. This is too conservative, but
* we don't want to risk having the hashtable overrun memory; also,
* it's not clear how to get a decent estimate of the true size.
*/
dNumDistinctRows = plan->plan_rows;
/* Also convert to long int --- but 'ware overflow! */
numDistinctRows = (long) Min(dNumDistinctRows, (double) LONG_MAX);
/*
* The output size is taken as 10% of that, which is a completely bogus
* guess, but it's what we've used historically.
*/
dNumOutputRows = ceil(dNumDistinctRows * 0.1);
/*
* Decide whether to hash or sort, and add a sort node if needed.
*/
plan = (Plan *) make_sort_from_sortclauses(root, groupList, plan);
use_hash = choose_hashed_setop(root, groupList, plan,
tuple_fraction, dNumDistinctRows,
(op->op == SETOP_INTERSECT) ? "INTERSECT" : "EXCEPT");
if (!use_hash)
plan = (Plan *) make_sort_from_sortclauses(root, groupList, plan);
/*
* Finally, add a SetOp plan node to generate the correct output.
......@@ -414,9 +442,12 @@ generate_nonunion_plan(SetOperationStmt *op, PlannerInfo *root,
cmd = SETOPCMD_INTERSECT; /* keep compiler quiet */
break;
}
plan = (Plan *) make_setop(cmd, plan, groupList, list_length(op->colTypes) + 1);
plan = (Plan *) make_setop(cmd, use_hash ? SETOP_HASHED : SETOP_SORTED,
plan, groupList, list_length(op->colTypes) + 1,
numDistinctRows, dNumOutputRows);
*sortClauses = groupList;
/* Result is sorted only if we're not hashing */
*sortClauses = use_hash ? NIL : groupList;
return plan;
}
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.185 2008/07/26 19:15:35 tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.186 2008/08/07 03:04:03 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1414,21 +1414,31 @@ typedef struct HashState
/* ----------------
* SetOpState information
*
* SetOp nodes are used "on top of" sort nodes to discard
* duplicate tuples returned from the sort phase. These are
* more complex than a simple Unique since we have to count
* how many duplicates to return.
* Even in "sorted" mode, SetOp nodes are more complex than a simple
* Unique, since we have to count how many duplicates to return. But
* we also support hashing, so this is really more like a cut-down
* form of Agg.
* ----------------
*/
/* this struct is private in nodeSetOp.c: */
typedef struct SetOpStatePerGroupData *SetOpStatePerGroup;
typedef struct SetOpState
{
PlanState ps; /* its first field is NodeTag */
FmgrInfo *eqfunctions; /* per-field lookup data for equality fns */
bool subplan_done; /* has subplan returned EOF? */
long numLeft; /* number of left-input dups of cur group */
long numRight; /* number of right-input dups of cur group */
FmgrInfo *eqfunctions; /* per-grouping-field equality fns */
FmgrInfo *hashfunctions; /* per-grouping-field hash fns */
bool setop_done; /* indicates completion of output scan */
long numOutput; /* number of dups left to output */
MemoryContext tempContext; /* short-term context for comparisons */
/* these fields are used in SETOP_SORTED mode: */
SetOpStatePerGroup pergroup; /* per-group working state */
HeapTuple grp_firstTuple; /* copy of first tuple of current group */
/* these fields are used in SETOP_HASHED mode: */
TupleHashTable hashtable; /* hash table with one entry per group */
MemoryContext tableContext; /* memory context containing hash table */
bool table_filled; /* hash table filled yet? */
TupleHashIterator hashiter; /* for iterating through hash table */
} SetOpState;
/* ----------------
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/plannodes.h,v 1.100 2008/04/13 20:51:21 tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/plannodes.h,v 1.101 2008/08/07 03:04:04 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -525,15 +525,23 @@ typedef enum SetOpCmd
SETOPCMD_EXCEPT_ALL
} SetOpCmd;
typedef enum SetOpStrategy
{
SETOP_SORTED, /* input must be sorted */
SETOP_HASHED /* use internal hashtable */
} SetOpStrategy;
typedef struct SetOp
{
Plan plan;
SetOpCmd cmd; /* what to do */
SetOpStrategy strategy; /* how to do it */
int numCols; /* number of columns to check for
* duplicate-ness */
AttrNumber *dupColIdx; /* their indexes in the target list */
Oid *dupOperators; /* equality operators to compare with */
AttrNumber flagColIdx; /* where is the flag column, if any */
long numGroups; /* estimated number of groups in input */
} SetOp;
/* ----------------
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/optimizer/planmain.h,v 1.108 2008/05/02 21:26:10 tgl Exp $
* $PostgreSQL: pgsql/src/include/optimizer/planmain.h,v 1.109 2008/08/07 03:04:04 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -61,8 +61,9 @@ extern Plan *materialize_finished_plan(Plan *subplan);
extern Unique *make_unique(Plan *lefttree, List *distinctList);
extern Limit *make_limit(Plan *lefttree, Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
extern SetOp *make_setop(SetOpCmd cmd, Plan *lefttree,
List *distinctList, AttrNumber flagColIdx);
extern SetOp *make_setop(SetOpCmd cmd, SetOpStrategy strategy, Plan *lefttree,
List *distinctList, AttrNumber flagColIdx, long numGroups,
double outputRows);
extern Result *make_result(PlannerInfo *root, List *tlist,
Node *resconstantqual, Plan *subplan);
extern bool is_projection_capable_plan(Plan *plan);
......
......@@ -275,21 +275,21 @@ SELECT q2 FROM int8_tbl INTERSECT ALL SELECT q1 FROM int8_tbl;
4567890123456789
(3 rows)
SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1;
q2
-------------------
-4567890123456789
456
(2 rows)
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT q1 FROM int8_tbl ORDER BY 1;
q2
-------------------
-4567890123456789
456
(2 rows)
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT DISTINCT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT DISTINCT q1 FROM int8_tbl ORDER BY 1;
q2
-------------------
-4567890123456789
......@@ -326,7 +326,7 @@ SELECT f1 FROM float8_tbl INTERSECT SELECT f1 FROM int4_tbl;
0
(1 row)
SELECT f1 FROM float8_tbl EXCEPT SELECT f1 FROM int4_tbl;
SELECT f1 FROM float8_tbl EXCEPT SELECT f1 FROM int4_tbl ORDER BY 1;
f1
-----------------------
-1.2345678901234e+200
......@@ -369,14 +369,14 @@ SELECT q1 FROM int8_tbl INTERSECT (((SELECT q2 FROM int8_tbl UNION ALL SELECT q2
-4567890123456789
(7 rows)
SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl;
SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1;
q1
-------------------
-4567890123456789
456
(2 rows)
SELECT q1 FROM int8_tbl UNION ALL (((SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl)));
SELECT q1 FROM int8_tbl UNION ALL (((SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1)));
q1
-------------------
123
......@@ -388,7 +388,7 @@ SELECT q1 FROM int8_tbl UNION ALL (((SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FR
456
(7 rows)
(((SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl))) EXCEPT SELECT q1 FROM int8_tbl;
(((SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl))) EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1;
q1
-------------------
-4567890123456789
......
......@@ -97,11 +97,11 @@ SELECT q2 FROM int8_tbl INTERSECT SELECT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl INTERSECT ALL SELECT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1;
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT q1 FROM int8_tbl ORDER BY 1;
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT DISTINCT q1 FROM int8_tbl;
SELECT q2 FROM int8_tbl EXCEPT ALL SELECT DISTINCT q1 FROM int8_tbl ORDER BY 1;
SELECT q1 FROM int8_tbl EXCEPT SELECT q2 FROM int8_tbl;
......@@ -115,7 +115,7 @@ SELECT q1 FROM int8_tbl EXCEPT ALL SELECT DISTINCT q2 FROM int8_tbl;
SELECT f1 FROM float8_tbl INTERSECT SELECT f1 FROM int4_tbl;
SELECT f1 FROM float8_tbl EXCEPT SELECT f1 FROM int4_tbl;
SELECT f1 FROM float8_tbl EXCEPT SELECT f1 FROM int4_tbl ORDER BY 1;
--
-- Operator precedence and (((((extra))))) parentheses
......@@ -127,11 +127,11 @@ SELECT q1 FROM int8_tbl INTERSECT (((SELECT q2 FROM int8_tbl UNION ALL SELECT q2
(((SELECT q1 FROM int8_tbl INTERSECT SELECT q2 FROM int8_tbl))) UNION ALL SELECT q2 FROM int8_tbl;
SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl;
SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1;
SELECT q1 FROM int8_tbl UNION ALL (((SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl)));
SELECT q1 FROM int8_tbl UNION ALL (((SELECT q2 FROM int8_tbl EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1)));
(((SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl))) EXCEPT SELECT q1 FROM int8_tbl;
(((SELECT q1 FROM int8_tbl UNION ALL SELECT q2 FROM int8_tbl))) EXCEPT SELECT q1 FROM int8_tbl ORDER BY 1;
--
-- Subqueries with ORDER BY & LIMIT clauses
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment