From: Tom Lane Date: Thu, 24 Mar 2005 19:14:49 +0000 (+0000) Subject: Tweak planner to use a minimum size estimate of 10 pages for a X-Git-Tag: REL8_1_0BETA1~1125 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=208ec47ba33289d4c18b2ad2feb6a9e7b88c58c5;p=postgresql Tweak planner to use a minimum size estimate of 10 pages for a never-yet-vacuumed relation. This restores the pre-8.0 behavior of avoiding seqscans during initial data loading, while still allowing reasonable optimization after a table has been vacuumed. Several regression test cases revert to 7.4-like behavior, which is probably a good sign. Per gripes from Keith Browne and others. --- diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c index 48d7493351..c9679a19e2 100644 --- a/src/backend/optimizer/util/plancat.c +++ b/src/backend/optimizer/util/plancat.c @@ -9,7 +9,7 @@ * * * IDENTIFICATION - * $PostgreSQL: pgsql/src/backend/optimizer/util/plancat.c,v 1.100 2004/12/31 22:00:23 pgsql Exp $ + * $PostgreSQL: pgsql/src/backend/optimizer/util/plancat.c,v 1.101 2005/03/24 19:14:49 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -234,7 +234,32 @@ estimate_rel_size(Relation rel, int32 *attr_widths, case RELKIND_INDEX: case RELKIND_TOASTVALUE: /* it has storage, ok to call the smgr */ - *pages = curpages = RelationGetNumberOfBlocks(rel); + curpages = RelationGetNumberOfBlocks(rel); + + /* + * HACK: if the relation has never yet been vacuumed, use a + * minimum estimate of 10 pages. This emulates a desirable + * aspect of pre-8.0 behavior, which is that we wouldn't assume + * a newly created relation is really small, which saves us from + * making really bad plans during initial data loading. (The + * plans are not wrong when they are made, but if they are cached + * and used again after the table has grown a lot, they are bad.) + * It would be better to force replanning if the table size has + * changed a lot since the plan was made ... but we don't + * currently have any infrastructure for redoing cached plans at + * all, so we have to kluge things here instead. + * + * We approximate "never vacuumed" by "has relpages = 0", which + * means this will also fire on genuinely empty relations. Not + * great, but fortunately that's a seldom-seen case in the real + * world, and it shouldn't degrade the quality of the plan too + * much anyway to err in this direction. + */ + if (curpages < 10 && rel->rd_rel->relpages == 0) + curpages = 10; + + /* report estimated # pages */ + *pages = curpages; /* quick exit if rel is clearly empty */ if (curpages == 0) { diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out index b98288e5c2..83f6939945 100644 --- a/src/test/regress/expected/join.out +++ b/src/test/regress/expected/join.out @@ -214,13 +214,13 @@ SELECT '' AS "xxx", t1.a, t2.e WHERE t1.a = t2.d; xxx | a | e -----+---+---- + | 0 | | 1 | -1 | 2 | 2 - | 3 | -3 | 2 | 4 + | 3 | -3 | 5 | -5 | 5 | -5 - | 0 | (7 rows) -- @@ -1567,13 +1567,13 @@ SELECT '' AS "xxx", * FROM J1_TBL INNER JOIN J2_TBL USING (i); xxx | i | j | t | k -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 - | 2 | 3 | two | 4 | 2 | 3 | two | 2 + | 2 | 3 | two | 4 | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | (7 rows) -- Same as above, slightly different syntax @@ -1581,13 +1581,13 @@ SELECT '' AS "xxx", * FROM J1_TBL JOIN J2_TBL USING (i); xxx | i | j | t | k -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 - | 2 | 3 | two | 4 | 2 | 3 | two | 2 + | 2 | 3 | two | 4 | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | (7 rows) SELECT '' AS "xxx", * @@ -1623,35 +1623,35 @@ SELECT '' AS "xxx", * FROM J1_TBL NATURAL JOIN J2_TBL; xxx | i | j | t | k -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 - | 2 | 3 | two | 4 | 2 | 3 | two | 2 + | 2 | 3 | two | 4 | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | (7 rows) SELECT '' AS "xxx", * FROM J1_TBL t1 (a, b, c) NATURAL JOIN J2_TBL t2 (a, d); xxx | a | b | c | d -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 - | 2 | 3 | two | 4 | 2 | 3 | two | 2 + | 2 | 3 | two | 4 | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | (7 rows) SELECT '' AS "xxx", * FROM J1_TBL t1 (a, b, c) NATURAL JOIN J2_TBL t2 (d, a); xxx | a | b | c | d -----+---+---+------+--- + | 0 | | zero | | 2 | 3 | two | 2 | 4 | 1 | four | 2 - | 0 | | zero | (3 rows) -- mismatch number of columns @@ -1660,13 +1660,13 @@ SELECT '' AS "xxx", * FROM J1_TBL t1 (a, b) NATURAL JOIN J2_TBL t2 (a); xxx | a | b | t | k -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 - | 2 | 3 | two | 4 | 2 | 3 | two | 2 + | 2 | 3 | two | 4 | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | (7 rows) -- @@ -1676,22 +1676,22 @@ SELECT '' AS "xxx", * FROM J1_TBL JOIN J2_TBL ON (J1_TBL.i = J2_TBL.i); xxx | i | j | t | i | k -----+---+---+-------+---+---- + | 0 | | zero | 0 | | 1 | 4 | one | 1 | -1 - | 2 | 3 | two | 2 | 4 | 2 | 3 | two | 2 | 2 + | 2 | 3 | two | 2 | 4 | 3 | 2 | three | 3 | -3 | 5 | 0 | five | 5 | -5 | 5 | 0 | five | 5 | -5 - | 0 | | zero | 0 | (7 rows) SELECT '' AS "xxx", * FROM J1_TBL JOIN J2_TBL ON (J1_TBL.i = J2_TBL.k); xxx | i | j | t | i | k -----+---+---+------+---+--- + | 0 | | zero | | 0 | 2 | 3 | two | 2 | 2 | 4 | 1 | four | 2 | 4 - | 0 | | zero | | 0 (3 rows) -- @@ -1760,13 +1760,13 @@ SELECT '' AS "xxx", * FROM J1_TBL RIGHT OUTER JOIN J2_TBL USING (i); xxx | i | j | t | k -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 | 2 | 3 | two | 2 - | 3 | 2 | three | -3 | 2 | 3 | two | 4 + | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | | | | | | | | | 0 (9 rows) @@ -1775,13 +1775,13 @@ SELECT '' AS "xxx", * FROM J1_TBL RIGHT JOIN J2_TBL USING (i); xxx | i | j | t | k -----+---+---+-------+---- + | 0 | | zero | | 1 | 4 | one | -1 | 2 | 3 | two | 2 - | 3 | 2 | three | -3 | 2 | 3 | two | 4 + | 3 | 2 | three | -3 | 5 | 0 | five | -5 | 5 | 0 | five | -5 - | 0 | | zero | | | | | | | | | 0 (9 rows) diff --git a/src/test/regress/expected/polymorphism.out b/src/test/regress/expected/polymorphism.out index 23ee8b839e..55687467a0 100644 --- a/src/test/regress/expected/polymorphism.out +++ b/src/test/regress/expected/polymorphism.out @@ -349,184 +349,184 @@ insert into t values(3,array[3],'b'); select f3, myaggp01a(*) from t group by f3; f3 | myaggp01a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp03a(*) from t group by f3; f3 | myaggp03a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp03b(*) from t group by f3; f3 | myaggp03b ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp05a(f1) from t group by f3; f3 | myaggp05a ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggp06a(f1) from t group by f3; f3 | myaggp06a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp08a(f1) from t group by f3; f3 | myaggp08a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp09a(f1) from t group by f3; f3 | myaggp09a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp09b(f1) from t group by f3; f3 | myaggp09b ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggp10a(f1) from t group by f3; f3 | myaggp10a ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggp10b(f1) from t group by f3; f3 | myaggp10b ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggp20a(f1) from t group by f3; f3 | myaggp20a ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggp20b(f1) from t group by f3; f3 | myaggp20b ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggn01a(*) from t group by f3; f3 | myaggn01a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn01b(*) from t group by f3; f3 | myaggn01b ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn03a(*) from t group by f3; f3 | myaggn03a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn05a(f1) from t group by f3; f3 | myaggn05a ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggn05b(f1) from t group by f3; f3 | myaggn05b ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) select f3, myaggn06a(f1) from t group by f3; f3 | myaggn06a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn06b(f1) from t group by f3; f3 | myaggn06b ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn08a(f1) from t group by f3; f3 | myaggn08a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn08b(f1) from t group by f3; f3 | myaggn08b ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn09a(f1) from t group by f3; f3 | myaggn09a ----+----------- + b | {} c | {} a | {} - b | {} (3 rows) select f3, myaggn10a(f1) from t group by f3; f3 | myaggn10a ----+----------- + b | {1,2,3} c | {1,2} a | {1,2,3} - b | {1,2,3} (3 rows) diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out index cf3e237e76..837c46b55a 100644 --- a/src/test/regress/expected/rules.out +++ b/src/test/regress/expected/rules.out @@ -1124,8 +1124,8 @@ insert into shoelace values ('sl10', 1000, 'magenta', 40.0, 'inch', 0.0); SELECT * FROM shoelace_obsolete; sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm ------------+----------+------------+--------+----------+----------- - sl10 | 1000 | magenta | 40 | inch | 101.6 sl9 | 0 | pink | 35 | inch | 88.9 + sl10 | 1000 | magenta | 40 | inch | 101.6 (2 rows) SELECT * FROM shoelace_candelete;