diff -urN ../postgresql-9.2.0.orig/contrib/plantuner\COPYRIGHT ./contrib/plantuner/COPYRIGHT --- ../postgresql-9.2.0.orig/contrib/plantuner/COPYRIGHT Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/COPYRIGHT Mon Sep 17 20:00:32 2012 @@ -0,0 +1,29 @@ +/* + * Copyright (c) 2009 Teodor Sigaev + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions + * are met: + * 1. Redistributions of source code must retain the above copyright + * notice, this list of conditions and the following disclaimer. + * 2. Redistributions in binary form must reproduce the above copyright + * notice, this list of conditions and the following disclaimer in the + * documentation and/or other materials provided with the distribution. + * 3. Neither the name of the author nor the names of any co-contributors + * may be used to endorse or promote products derived from this software + * without specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY CONTRIBUTORS ``AS IS'' AND ANY EXPRESS + * OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE + * ARE DISCLAIMED. IN NO EVENT SHALL CONTRIBUTORS BE LIABLE FOR ANY + * DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL + * DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE + * GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS + * INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER + * IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR + * OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN + * IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ + diff -urN ../postgresql-9.2.0.orig/contrib/plantuner/expected/plantuner.out ./contrib/plantuner/expected/plantuner.out --- ../postgresql-9.2.0.orig/contrib/plantuner/expected/plantuner.out Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/expected/plantuner.out Mon Sep 17 20:00:32 2012 @@ -0,0 +1,49 @@ +LOAD 'plantuner'; +SHOW plantuner.disable_index; + plantuner.disable_index +------------------------- + +(1 row) + +CREATE TABLE wow (i int, j int); +CREATE INDEX i_idx ON wow (i); +CREATE INDEX j_idx ON wow (j); +SET enable_seqscan=off; +SELECT * FROM wow; + i | j +---+--- +(0 rows) + +SET plantuner.disable_index="i_idx, j_idx"; +SELECT * FROM wow; + i | j +---+--- +(0 rows) + +SHOW plantuner.disable_index; + plantuner.disable_index +---------------------------- + public.i_idx, public.j_idx +(1 row) + +SET plantuner.disable_index="i_idx, nonexistent, public.j_idx, wow"; +WARNING: 'nonexistent' does not exist +WARNING: 'wow' is not an index +SHOW plantuner.disable_index; + plantuner.disable_index +---------------------------- + public.i_idx, public.j_idx +(1 row) + +SET plantuner.enable_index="i_idx"; +SHOW plantuner.enable_index; + plantuner.enable_index +------------------------ + public.i_idx +(1 row) + +SELECT * FROM wow; + i | j +---+--- +(0 rows) + diff -urN ../postgresql-9.2.0.orig/contrib/plantuner/Makefile ./contrib/plantuner/Makefile --- ../postgresql-9.2.0.orig/contrib/plantuner/Makefile Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/Makefile Mon Sep 17 20:00:32 2012 @@ -0,0 +1,15 @@ +MODULE_big = plantuner +DOCS = README.plantuner +REGRESS = plantuner +OBJS=plantuner.o + +ifdef USE_PGXS +PGXS = $(shell pg_config --pgxs) +include $(PGXS) +else +subdir = contrib/plantuner +top_builddir = ../.. +include $(top_builddir)/src/Makefile.global + +include $(top_srcdir)/contrib/contrib-global.mk +endif diff -urN ../postgresql-9.2.0.orig/contrib/plantuner/plantuner.c ./contrib/plantuner/plantuner.c --- ../postgresql-9.2.0.orig/contrib/plantuner/plantuner.c Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/plantuner.c Mon Sep 17 20:00:32 2012 @@ -0,0 +1,378 @@ +/* + * Copyright (c) 2009 Teodor Sigaev + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions + * are met: + * 1. Redistributions of source code must retain the above copyright + * notice, this list of conditions and the following disclaimer. + * 2. Redistributions in binary form must reproduce the above copyright + * notice, this list of conditions and the following disclaimer in the + * documentation and/or other materials provided with the distribution. + * 3. Neither the name of the author nor the names of any co-contributors + * may be used to endorse or promote products derived from this software + * without specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY CONTRIBUTORS ``AS IS'' AND ANY EXPRESS + * OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE + * ARE DISCLAIMED. IN NO EVENT SHALL CONTRIBUTORS BE LIABLE FOR ANY + * DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL + * DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE + * GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS + * INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER + * IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR + * OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN + * IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ + +#include + +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include + +PG_MODULE_MAGIC; + +static int nDisabledIndexes = 0; +static Oid *disabledIndexes = NULL; +static char *disableIndexesOutStr = ""; + +static int nEnabledIndexes = 0; +static Oid *enabledIndexes = NULL; +static char *enableIndexesOutStr = ""; + +get_relation_info_hook_type prevHook = NULL; +static bool fix_empty_table = false; + + +static const char * +indexesAssign(const char * newval, bool doit, GucSource source, bool isDisable) +{ + char *rawname; + List *namelist; + ListCell *l; + Oid *newOids = NULL; + int nOids = 0, + i = 0; + + rawname = pstrdup(newval); + + if (!SplitIdentifierString(rawname, ',', &namelist)) + goto cleanup; + + if (doit) + { + nOids = list_length(namelist); + newOids = malloc(sizeof(Oid) * (nOids+1)); + if (!newOids) + elog(ERROR,"could not allocate %d bytes", (int)(sizeof(Oid) * (nOids+1))); + } + + foreach(l, namelist) + { + char *curname = (char *) lfirst(l); +#if PG_VERSION_NUM >= 90200 + Oid indexOid = RangeVarGetRelid(makeRangeVarFromNameList(stringToQualifiedNameList(curname)), + NoLock, true); +#else + Oid indexOid = RangeVarGetRelid(makeRangeVarFromNameList(stringToQualifiedNameList(curname)), + true); +#endif + + if (indexOid == InvalidOid) + { +#if PG_VERSION_NUM >= 90100 + if (doit == false) +#endif + elog(WARNING,"'%s' does not exist", curname); + continue; + } + else if ( get_rel_relkind(indexOid) != RELKIND_INDEX ) + { +#if PG_VERSION_NUM >= 90100 + if (doit == false) +#endif + elog(WARNING,"'%s' is not an index", curname); + continue; + } + else if (doit) + { + newOids[i++] = indexOid; + } + } + + if (doit) + { + if (isDisable) + { + nDisabledIndexes = nOids; + disabledIndexes = newOids; + } + else + { + nEnabledIndexes = nOids; + enabledIndexes = newOids; + } + } + + pfree(rawname); + list_free(namelist); + + return newval; + +cleanup: + if (newOids) + free(newOids); + pfree(rawname); + list_free(namelist); + return NULL; +} + +static const char * +assignDisabledIndexes(const char * newval, bool doit, GucSource source) +{ + return indexesAssign(newval, doit, source, true); +} + +static const char * +assignEnabledIndexes(const char * newval, bool doit, GucSource source) +{ + return indexesAssign(newval, doit, source, false); +} + +#if PG_VERSION_NUM >= 90100 + +static bool +checkDisabledIndexes(char **newval, void **extra, GucSource source) +{ + char *val; + + val = (char*)indexesAssign(*newval, false, source, true); + + if (val) + { + *newval = val; + return true; + } + + return false; +} + +static bool +checkEnabledIndexes(char **newval, void **extra, GucSource source) +{ + char *val; + + val = (char*)indexesAssign(*newval, false, source, false); + + if (val) + { + *newval = val; + return true; + } + + return false; +} + +static void +assignDisabledIndexesNew(const char *newval, void *extra) +{ + assignDisabledIndexes(newval, true, PGC_S_USER /* doesn't matter */); +} + +static void +assignEnabledIndexesNew(const char *newval, void *extra) +{ + assignEnabledIndexes(newval, true, PGC_S_USER /* doesn't matter */); +} + +#endif + +static void +indexFilter(PlannerInfo *root, Oid relationObjectId, bool inhparent, RelOptInfo *rel) { + int i; + + for(i=0;iindexlist) + { + IndexOptInfo *info = (IndexOptInfo*)lfirst(l); + + if (disabledIndexes[i] == info->indexoid) + { + int j; + + for(j=0; jindexoid) + break; + + if (j >= nEnabledIndexes) + rel->indexlist = list_delete_ptr(rel->indexlist, info); + + break; + } + } + } +} + +static void +execPlantuner(PlannerInfo *root, Oid relationObjectId, bool inhparent, RelOptInfo *rel) { + Relation relation; + + relation = heap_open(relationObjectId, NoLock); + if (relation->rd_rel->relkind == RELKIND_RELATION) + { + if (fix_empty_table && RelationGetNumberOfBlocks(relation) == 0) + { + /* + * estimate_rel_size() could be too pessimistic for particular + * workload + */ + rel->pages = 0.0; + rel->tuples = 0.0; + } + + indexFilter(root, relationObjectId, inhparent, rel); + } + heap_close(relation, NoLock); + + /* + * Call next hook if it exists + */ + if (prevHook) + prevHook(root, relationObjectId, inhparent, rel); +} + +static const char* +IndexFilterShow(Oid* indexes, int nIndexes) +{ + char *val, *ptr; + int i, + len; + + len = 1 /* \0 */ + nIndexes * (2 * NAMEDATALEN + 2 /* ', ' */ + 1 /* . */); + ptr = val = palloc(len); + + *ptr =(char)'\0'; + for(i=0; i= 90100 + checkDisabledIndexes, + assignDisabledIndexesNew, +#else + assignDisabledIndexes, +#endif + disabledIndexFilterShow + ); + + DefineCustomStringVariable( + "plantuner.disable_index", + "List of disabled indexes", + "Listed indexes will not be used in queries", + &disableIndexesOutStr, + "", + PGC_USERSET, + 0, +#if PG_VERSION_NUM >= 90100 + checkDisabledIndexes, + assignDisabledIndexesNew, +#else + assignDisabledIndexes, +#endif + disabledIndexFilterShow + ); + + DefineCustomStringVariable( + "plantuner.enable_index", + "List of enabled indexes (overload plantuner.disable_index)", + "Listed indexes which could be used in queries even they are listed in plantuner.disable_index", + &enableIndexesOutStr, + "", + PGC_USERSET, + 0, +#if PG_VERSION_NUM >= 90100 + checkEnabledIndexes, + assignEnabledIndexesNew, +#else + assignEnabledIndexes, +#endif + enabledIndexFilterShow + ); + + DefineCustomBoolVariable( + "plantuner.fix_empty_table", + "Sets to zero estimations for empty tables", + "Sets to zero estimations for empty or newly created tables", + &fix_empty_table, +#if PG_VERSION_NUM >= 80400 + fix_empty_table, +#endif + PGC_USERSET, +#if PG_VERSION_NUM >= 80400 + GUC_NOT_IN_SAMPLE, +#if PG_VERSION_NUM >= 90100 + NULL, +#endif +#endif + NULL, + NULL + ); + + if (get_relation_info_hook != execPlantuner ) + { + prevHook = get_relation_info_hook; + get_relation_info_hook = execPlantuner; + } +} diff -urN ../postgresql-9.2.0.orig/contrib/plantuner/README.plantuner ./contrib/plantuner/README.plantuner --- ../postgresql-9.2.0.orig/contrib/plantuner/README.plantuner Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/README.plantuner Mon Sep 17 20:00:32 2012 @@ -0,0 +1,96 @@ +Plantuner - enable planner hints + + contrib/plantuner is a contribution module for PostgreSQL 8.4+, which + enable planner hints. + + All work was done by Teodor Sigaev (teodor@sigaev.ru) and Oleg Bartunov + (oleg@sai.msu.su). + + Sponsor: Nomao project (http://www.nomao.com) + +Motivation + + Whether somebody think it's bad or not, but sometime it's very + interesting to be able to control planner (provide hints, which tells + optimizer to ignore its algorithm in part), which is currently + impossible in POstgreSQL. Oracle, for example, has over 120 hints, SQL + Server also provides hints. + + This first version of plantuner provides a possibility to hide + specified indexes from PostgreSQL planner, so it will not use them. + + There are many situation, when developer want to temporarily disable + specific index(es), without dropping them, or to instruct planner to + use specific index. + + Next, for some workload PostgreSQL could be too pessimistic for + newly created tables and assumes much more rows in table than + it actually has. If plantuner.fix_empty_table GUC variable is set + to true then module will set to zero number of pages/tuples of + table which hasn't blocks in file. + +Installation + + * Get latest source of plantuner from CVS Repository + * gmake && gmake install && gmake installcheck + +Syntax + plantuner.forbid_index (deprecated) + plantuner.disable_index + List of indexes invisible to planner + plantuner.enable_index + List of indexes visible to planner even they are hided + by plantuner.disable_index. + +Usage + + To enable the module you can either load shared library 'plantuner' in + psql session or specify 'shared_preload_libraries' option in + postgresql.conf. +=# LOAD 'plantuner'; +=# create table test(id int); +=# create index id_idx on test(id); +=# create index id_idx2 on test(id); +=# \d test + Table "public.test" + Column | Type | Modifiers +--------+---------+----------- + id | integer | +Indexes: + "id_idx" btree (id) + "id_idx2" btree (id) +=# explain select id from test where id=1; + QUERY PLAN +----------------------------------------------------------------------- + Bitmap Heap Scan on test (cost=4.34..15.03 rows=12 width=4) + Recheck Cond: (id = 1) + -> Bitmap Index Scan on id_idx2 (cost=0.00..4.34 rows=12 width=0) + Index Cond: (id = 1) +(4 rows) +=# set enable_seqscan=off; +=# set plantuner.disable_index='id_idx2'; +=# explain select id from test where id=1; + QUERY PLAN +---------------------------------------------------------------------- + Bitmap Heap Scan on test (cost=4.34..15.03 rows=12 width=4) + Recheck Cond: (id = 1) + -> Bitmap Index Scan on id_idx (cost=0.00..4.34 rows=12 width=0) + Index Cond: (id = 1) +(4 rows) +=# set plantuner.disable_index='id_idx2,id_idx'; +=# explain select id from test where id=1; + QUERY PLAN +------------------------------------------------------------------------- + Seq Scan on test (cost=10000000000.00..10000000040.00 rows=12 width=4) + Filter: (id = 1) +(2 rows) +=# set plantuner.enable_index='id_idx'; +=# explain select id from test where id=1; + QUERY PLAN +----------------------------------------------------------------------- + Bitmap Heap Scan on test (cost=4.34..15.03 rows=12 width=4) + Recheck Cond: (id = 1) + -> Bitmap Index Scan on id_idx (cost=0.00..4.34 rows=12 width=0) + Index Cond: (id = 1) +(4 rows) + diff -urN ../postgresql-9.2.0.orig/contrib/plantuner/results/plantuner.out ./contrib/plantuner/results/plantuner.out --- ../postgresql-9.2.0.orig/contrib/plantuner/results/plantuner.out Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/results/plantuner.out Tue Sep 18 11:59:30 2012 @@ -0,0 +1,49 @@ +LOAD 'plantuner'; +SHOW plantuner.disable_index; + plantuner.disable_index +------------------------- + +(1 row) + +CREATE TABLE wow (i int, j int); +CREATE INDEX i_idx ON wow (i); +CREATE INDEX j_idx ON wow (j); +SET enable_seqscan=off; +SELECT * FROM wow; + i | j +---+--- +(0 rows) + +SET plantuner.disable_index="i_idx, j_idx"; +SELECT * FROM wow; + i | j +---+--- +(0 rows) + +SHOW plantuner.disable_index; + plantuner.disable_index +---------------------------- + public.i_idx, public.j_idx +(1 row) + +SET plantuner.disable_index="i_idx, nonexistent, public.j_idx, wow"; +WARNING: 'nonexistent' does not exist +WARNING: 'wow' is not an index +SHOW plantuner.disable_index; + plantuner.disable_index +---------------------------- + public.i_idx, public.j_idx +(1 row) + +SET plantuner.enable_index="i_idx"; +SHOW plantuner.enable_index; + plantuner.enable_index +------------------------ + public.i_idx +(1 row) + +SELECT * FROM wow; + i | j +---+--- +(0 rows) + diff -urN ../postgresql-9.2.0.orig/contrib/plantuner/sql/plantuner.sql ./contrib/plantuner/sql/plantuner.sql --- ../postgresql-9.2.0.orig/contrib/plantuner/sql/plantuner.sql Thu Jan 01 04:00:00 1970 +++ ./contrib/plantuner/sql/plantuner.sql Mon Sep 17 20:00:32 2012 @@ -0,0 +1,27 @@ +LOAD 'plantuner'; + +SHOW plantuner.disable_index; + +CREATE TABLE wow (i int, j int); +CREATE INDEX i_idx ON wow (i); +CREATE INDEX j_idx ON wow (j); + +SET enable_seqscan=off; + +SELECT * FROM wow; + +SET plantuner.disable_index="i_idx, j_idx"; + +SELECT * FROM wow; + +SHOW plantuner.disable_index; + +SET plantuner.disable_index="i_idx, nonexistent, public.j_idx, wow"; + +SHOW plantuner.disable_index; + +SET plantuner.enable_index="i_idx"; + +SHOW plantuner.enable_index; + +SELECT * FROM wow;