├── Makefile ├── README.md ├── license ├── pg_plan_guarantee.c ├── pg_plan_guarantee.conf └── pg_plan_guarantee.control /Makefile: -------------------------------------------------------------------------------- 1 | # contrib/pg_plan_guarantee/Makefile 2 | 3 | MODULE_big = pg_plan_guarantee 4 | OBJS = \ 5 | $(WIN32RES) \ 6 | pg_plan_guarantee.o 7 | 8 | EXTENSION = pg_plan_guarantee 9 | DATA = 10 | PGFILEDESC = "pg_plan_guarantee - Guarantee that your plans will never change" 11 | 12 | LDFLAGS_SL += $(filter -lm, $(LIBS)) 13 | 14 | REGRESS_OPTS = --temp-config $(top_srcdir)/contrib/pg_plan_guarantee/pg_plan_guarantee.conf 15 | REGRESS = pg_plan_guarantee oldextversions 16 | # Disabled because these tests require "shared_preload_libraries=pg_plan_guarantee", 17 | # which typical installcheck users do not have (e.g. buildfarm clients). 18 | NO_INSTALLCHECK = 1 19 | 20 | ifdef USE_PGXS 21 | PG_CONFIG = pg_config 22 | PGXS := $(shell $(PG_CONFIG) --pgxs) 23 | include $(PGXS) 24 | else 25 | subdir = contrib/pg_plan_guarantee 26 | top_builddir = ../.. 27 | include $(top_builddir)/src/Makefile.global 28 | include $(top_srcdir)/contrib/contrib-global.mk 29 | endif 30 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | pg_plan_guarantee 2 | ================= 3 | 4 | Guarantee that your plans will never change. 5 | 6 | Overview 7 | -------- 8 | 9 | You work very hard to tune your queries; to get the exact query execution plan 10 | that satisfies your performance needs. 11 | 12 | But some time later, after either the data has changed suffiently, or the 13 | statistics have changed sufficiently, Postgres planner chooses to suddenly pick 14 | a query execution plan that makes your application look unresponsive. This shows 15 | up on your dashboard as an outage. Now you find yourself running against the 16 | clock, to rewrite the query, test it, change the application/ORM, and deploy the 17 | changes, and still just hoping that the production database accepts your 18 | offerings, and executes your query just acceptably enough, so you can go back to 19 | bed. 20 | 21 | But if you use the `pg_plan_guarantee` extension, you will never face such a 22 | situation; we can **guarantee** that. This extension provides a mechanism, using 23 | which you can set your execution plan in stone; that is, Postgres will execute 24 | the plan you give it, or it will throw an error, but it will never try to guess 25 | a plan for you. 26 | 27 | Because the data and/or statistics change gradually over time, you can be fairly 28 | confident that the guaraneed-plan will continue to serve your needs in a 29 | graceful manner. That is, your guaranted-plan will degrade gracefully, as 30 | opposed to suddenly, at the most inopportune time. 31 | 32 | Note: the term `pgpg` in the text below, and in the code, stands for/is an 33 | acronym of the extension's name, `PG_Plan_Guarantee`. 34 | 35 | Installation 36 | ------------ 37 | 38 | Place the extension in the `extensions` directory under the Postgres 39 | installation directory. Then add the name of the extension, `pg_plan_guarantee`, 40 | to the `share_preload_libraries` variable in the `postgresql.conf` file. 41 | 42 | #### Disabling the Extension 43 | 44 | If you ever wish to disable the extension, you can do so by adding the parameter 45 | `pg_plan_guarantee.enabled`, and setting its value to `false`. This way you 46 | don't really have to remove the extension from the filesystem, or from the 47 | `shared_preload_libraries` parameter. 48 | 49 | How to Use 50 | ---------- 51 | 52 | The `pg_plan_guarantee` extension is designed to be used in two steps. In the 53 | first step, you ask the extension to generate the guaranteed-plan. In the second 54 | step, you use ask the extension to use the guaranteed-plan. Please see the 55 | `Demo` section, below, to see these steps in action. 56 | 57 | To generate the guaranteed-plan, embed your query in the first string of the 58 | following SQL command: 59 | 60 | select $pgpg$ your query $pgpg$ 61 | as query, 62 | '' as plan; 63 | 64 | The output of the above command will produce the guaranteed-plan in the second 65 | column of the result-set. 66 | 67 | To use the guaranteed-plan produded by the first step, you embed the 68 | guaranteed-plan in the second string of the same SQL command, like so: 69 | 70 | select $pgpg$ your query $pgpg$ 71 | as query, 72 | $pgpg$ guaranteed-plan $pgpg$ 73 | as plan; 74 | 75 | Demo 76 | ---- 77 | 78 | Generate the guaranteed-plan. 79 | 80 | =# select $pgpg$select relkind from pg_class where relname = 'pg_class'$pgpg$ 81 | as query, 82 | '' 83 | as plan; 84 | -[ RECORD 1 ]----- 85 | query | select relkind from pg_class where relname = 'pg_class' 86 | plan | {PLANNEDSTMT :commandType 1 :queryId 0 :hasReturning false :hasModifyingCTE false :canSetTag true :transientPlan false :dependsOnRole false :parallelModeNeeded false :jitFlags 0 :planTree {INDEXSCAN :startup_cost 0.27 :total_cost 8.29 :plan_rows 1 :plan_width 1 :parallel_aware false :parallel_safe true :async_capable false :plan_node_id 0 :targetlist ({TARGETENTRY :expr {VAR :varno 1 :varattno 17 :vartype 18 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnosyn 1 :varattnosyn 17 :location 7} :resno 1 :resname relkind :ressortgroupref 0 :resorigtbl 1259 :resorigcol 17 :resjunk false}) :qual <> :lefttree <> :righttree <> :initPlan <> :extParam (b) :allParam (b) :scanrelid 1 :indexid 2663 :indexqual ({OPEXPR :opno 93 :opfuncid 62 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 950 :args ({VAR :varno -3 :varattno 1 :vartype 19 :vartypmod -1 :varcollid 950 :varlevelsup 0 :varnosyn 1 :varattnosyn 2 :location 35} {CONST :consttype 19 :consttypmod -1 :constcollid 950 :constlen 64 :constbyval false :constisnull false :location 45 :constvalue 64 [ 112 103 95 99 108 97 115 115 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 ]}) :location 43}) :indexqualorig ({OPEXPR :opno 93 :opfuncid 62 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 950 :args ({VAR :varno 1 :varattno 2 :vartype 19 :vartypmod -1 :varcollid 950 :varlevelsup 0 :varnosyn 1 :varattnosyn 2 :location 35} {CONST :consttype 19 :consttypmod -1 :constcollid 950 :constlen 64 :constbyval false :constisnull false :location 45 :constvalue 64 [ 112 103 95 99 108 97 115 115 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 ]}) :location 43}) :indexorderby <> :indexorderbyorig <> :indexorderbyops <> :indexorderdir 1} :rtable ({RANGETBLENTRY :alias <> :eref {ALIAS :aliasname pg_class :colnames ("oid" "relname" "relnamespace" "reltype" "reloftype" "relowner" "relam" "relfilenode" "reltablespace" "relpages" "reltuples" "relallvisible" "reltoastrelid" "relhasindex" "relisshared" "relpersistence" "relkind" "relnatts" "relchecks" "relhasrules" "relhastriggers" "relhassubclass" "relrowsecurity" "relforcerowsecurity" "relispopulated" "relreplident" "relispartition" "relrewrite" "relfrozenxid" "relminmxid" "relacl" "reloptions" "relpartbound")} :rtekind 0 :relid 1259 :relkind r :rellockmode 1 :tablesample <> :lateral false :inh false :inFromCl true :requiredPerms 2 :checkAsUser 0 :selectedCols (b 9 24) :insertedCols (b) :updatedCols (b) :extraUpdatedCols (b) :securityQuals <>}) :resultRelations <> :appendRelations <> :subplans <> :rewindPlanIDs (b) :rowMarks <> :relationOids (o 1259) :invalItems <> :paramExecTypes <> :utilityStmt <> :stmt_location 0 :stmt_len 0} 87 | 88 | Use the guaranteed plan. 89 | 90 | =# select $pgpg$select relkind from pg_class where relname = 'pg_class'$pgpg$ 91 | as query, 92 | $pgpg${PLANNEDSTMT :commandType 1 :queryId 0 :hasReturning false :hasModifyingCTE false :canSetTag true :transientPlan false :dependsOnRole false :parallelModeNeeded false :jitFlags 0 :planTree {INDEXSCAN :startup_cost 0.27 :total_cost 8.29 :plan_rows 1 :plan_width 1 :parallel_aware false :parallel_safe true :async_capable false :plan_node_id 0 :targetlist ({TARGETENTRY :expr {VAR :varno 1 :varattno 17 :vartype 18 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnosyn 1 :varattnosyn 17 :location 7} :resno 1 :resname relkind :ressortgroupref 0 :resorigtbl 1259 :resorigcol 17 :resjunk false}) :qual <> :lefttree <> :righttree <> :initPlan <> :extParam (b) :allParam (b) :scanrelid 1 :indexid 2663 :indexqual ({OPEXPR :opno 93 :opfuncid 62 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 950 :args ({VAR :varno -3 :varattno 1 :vartype 19 :vartypmod -1 :varcollid 950 :varlevelsup 0 :varnosyn 1 :varattnosyn 2 :location 35} {CONST :consttype 19 :consttypmod -1 :constcollid 950 :constlen 64 :constbyval false :constisnull false :location 45 :constvalue 64 [ 112 103 95 99 108 97 115 115 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 ]}) :location 43}) :indexqualorig ({OPEXPR :opno 93 :opfuncid 62 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 950 :args ({VAR :varno 1 :varattno 2 :vartype 19 :vartypmod -1 :varcollid 950 :varlevelsup 0 :varnosyn 1 :varattnosyn 2 :location 35} {CONST :consttype 19 :consttypmod -1 :constcollid 950 :constlen 64 :constbyval false :constisnull false :location 45 :constvalue 64 [ 112 103 95 99 108 97 115 115 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 ]}) :location 43}) :indexorderby <> :indexorderbyorig <> :indexorderbyops <> :indexorderdir 1} :rtable ({RANGETBLENTRY :alias <> :eref {ALIAS :aliasname pg_class :colnames ("oid" "relname" "relnamespace" "reltype" "reloftype" "relowner" "relam" "relfilenode" "reltablespace" "relpages" "reltuples" "relallvisible" "reltoastrelid" "relhasindex" "relisshared" "relpersistence" "relkind" "relnatts" "relchecks" "relhasrules" "relhastriggers" "relhassubclass" "relrowsecurity" "relforcerowsecurity" "relispopulated" "relreplident" "relispartition" "relrewrite" "relfrozenxid" "relminmxid" "relacl" "reloptions" "relpartbound")} :rtekind 0 :relid 1259 :relkind r :rellockmode 1 :tablesample <> :lateral false :inh false :inFromCl true :requiredPerms 2 :checkAsUser 0 :selectedCols (b 9 24) :insertedCols (b) :updatedCols (b) :extraUpdatedCols (b) :securityQuals <>}) :resultRelations <> :appendRelations <> :subplans <> :rewindPlanIDs (b) :rowMarks <> :relationOids (o 1259) :invalItems <> :paramExecTypes <> :utilityStmt <> :stmt_location 0 :stmt_len 0}$pgpg$ 93 | as plan; 94 | relkind 95 | --------- 96 | r 97 | (1 row) 98 | 99 | To see what's going on in the background, add the `auto_explain` extension to `shared_preload_libraries`, and set `client_min_messages` to `log`. 100 | 101 | =# load 'auto_explain'; 102 | LOAD 103 | =# set auto_explain.log_min_duration = 0; 104 | SET 105 | =# set client_min_messages = log; 106 | SET 107 | 108 | By default, our query uses Index Scan. 109 | 110 | =# select relkind from pg_class where relname = 'pg_class'; 111 | LOG: 112 | Query Text: 113 | Index Scan using pg_class_relname_nsp_index on pg_class (cost=0.27..8.29 rows=1 width=1) 114 | Index Cond: (relname = 'pg_class'::name) 115 | relkind 116 | --------- 117 | r 118 | (1 row) 119 | 120 | Let's perform tuning to make it use a plan we want it to, say, sequential scan. 121 | 122 | =# set enable_indexscan = off; 123 | SET 124 | =# set enable_bitmapscan = off; 125 | SET 126 | =# select relkind from pg_class where relname = 'pg_class'; 127 | LOG: 128 | Query Text: 129 | Seq Scan on pg_class (cost=0.00..19.05 rows=1 width=1) 130 | Filter: (relname = 'pg_class'::name) 131 | relkind 132 | --------- 133 | r 134 | (1 row) 135 | 136 | Now that we have our desired plan being generated by the Query Planner, let's generate a guaranteed-plan. 137 | 138 | =# select $pgpg$select relkind from pg_class where relname = 'pg_class'$pgpg$ 139 | as query, 140 | '' 141 | as plan; 142 | LOG: 143 | Query Text: 144 | Result (cost=0.00..0.01 rows=1 width=64) 145 | -[ RECORD 1 ]----------- 146 | query | select relkind from pg_class where relname = 'pg_class' 147 | plan | {PLANNEDSTMT :commandType 1 :queryId 0 :hasReturning false :hasModifyingCTE false :canSetTag true :transientPlan false :dependsOnRole false :parallelModeNeeded false :jitFlags 0 :planTree {SEQSCAN :startup_cost 0.00 :total_cost 19.05 :plan_rows 1 :plan_width 1 :parallel_aware false :parallel_safe true :async_capable false :plan_node_id 0 :targetlist ({TARGETENTRY :expr {VAR :varno 1 :varattno 17 :vartype 18 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnosyn 1 :varattnosyn 17 :location 7} :resno 1 :resname relkind :ressortgroupref 0 :resorigtbl 1259 :resorigcol 17 :resjunk false}) :qual ({OPEXPR :opno 93 :opfuncid 62 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 950 :args ({VAR :varno 1 :varattno 2 :vartype 19 :vartypmod -1 :varcollid 950 :varlevelsup 0 :varnosyn 1 :varattnosyn 2 :location 35} {CONST :consttype 19 :consttypmod -1 :constcollid 950 :constlen 64 :constbyval false :constisnull false :location 45 :constvalue 64 [ 112 103 95 99 108 97 115 115 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 ]}) :location 43}) :lefttree <> :righttree <> :initPlan <> :extParam (b) :allParam (b) :scanrelid 1} :rtable ({RANGETBLENTRY :alias <> :eref {ALIAS :aliasname pg_class :colnames ("oid" "relname" "relnamespace" "reltype" "reloftype" "relowner" "relam" "relfilenode" "reltablespace" "relpages" "reltuples" "relallvisible" "reltoastrelid" "relhasindex" "relisshared" "relpersistence" "relkind" "relnatts" "relchecks" "relhasrules" "relhastriggers" "relhassubclass" "relrowsecurity" "relforcerowsecurity" "relispopulated" "relreplident" "relispartition" "relrewrite" "relfrozenxid" "relminmxid" "relacl" "reloptions" "relpartbound")} :rtekind 0 :relid 1259 :relkind r :rellockmode 1 :tablesample <> :lateral false :inh false :inFromCl true :requiredPerms 2 :checkAsUser 0 :selectedCols (b 9 24) :insertedCols (b) :updatedCols (b) :extraUpdatedCols (b) :securityQuals <>}) :resultRelations <> :appendRelations <> :subplans <> :rewindPlanIDs (b) :rowMarks <> :relationOids (o 1259) :invalItems <> :paramExecTypes <> :utilityStmt <> :stmt_location 0 :stmt_len 0} 148 | 149 | Now let's revert the configuration changes, and then show that despite changes in the tuning/configuration, the guranteed-plan is guaranteed to be used. 150 | 151 | =# reset enable_indexscan; 152 | RESET 153 | =# reset enable_bitmapscan; 154 | RESET 155 | 156 | Show that the query now reverts to Index Scan. 157 | 158 | =# select relkind from pg_class where relname = 'pg_class'; 159 | LOG: 160 | Query Text: 161 | Index Scan using pg_class_relname_nsp_index on pg_class (cost=0.27..8.29 rows=1 width=1) 162 | Index Cond: (relname = 'pg_class'::name) 163 | relkind 164 | --------- 165 | r 166 | (1 row) 167 | 168 | Now use the guaranteed-plan, and see how, despite all the changes in configuration, the `pg_plan_guarantee` extenstion forces the use of the guaranteed-plan. 169 | 170 | =# select $pgpg$ select relkind from pg_class where relname = 'pg_class' $pgpg$ 171 | as query, 172 | $pgpg$ {PLANNEDSTMT :commandType 1 :queryId 0 :hasReturning false :hasModifyingCTE false :canSetTag true :transientPlan false :dependsOnRole false :parallelModeNeeded false :jitFlags 0 :planTree {SEQSCAN :startup_cost 0.00 :total_cost 19.05 :plan_rows 1 :plan_width 1 :parallel_aware false :parallel_safe true :async_capable false :plan_node_id 0 :targetlist ({TARGETENTRY :expr {VAR :varno 1 :varattno 17 :vartype 18 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnosyn 1 :varattnosyn 17 :location 7} :resno 1 :resname relkind :ressortgroupref 0 :resorigtbl 1259 :resorigcol 17 :resjunk false}) :qual ({OPEXPR :opno 93 :opfuncid 62 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 950 :args ({VAR :varno 1 :varattno 2 :vartype 19 :vartypmod -1 :varcollid 950 :varlevelsup 0 :varnosyn 1 :varattnosyn 2 :location 35} {CONST :consttype 19 :consttypmod -1 :constcollid 950 :constlen 64 :constbyval false :constisnull false :location 45 :constvalue 64 [ 112 103 95 99 108 97 115 115 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 ]}) :location 43}) :lefttree <> :righttree <> :initPlan <> :extParam (b) :allParam (b) :scanrelid 1} :rtable ({RANGETBLENTRY :alias <> :eref {ALIAS :aliasname pg_class :colnames ("oid" "relname" "relnamespace" "reltype" "reloftype" "relowner" "relam" "relfilenode" "reltablespace" "relpages" "reltuples" "relallvisible" "reltoastrelid" "relhasindex" "relisshared" "relpersistence" "relkind" "relnatts" "relchecks" "relhasrules" "relhastriggers" "relhassubclass" "relrowsecurity" "relforcerowsecurity" "relispopulated" "relreplident" "relispartition" "relrewrite" "relfrozenxid" "relminmxid" "relacl" "reloptions" "relpartbound")} :rtekind 0 :relid 1259 :relkind r :rellockmode 1 :tablesample <> :lateral false :inh false :inFromCl true :requiredPerms 2 :checkAsUser 0 :selectedCols (b 9 24) :insertedCols (b) :updatedCols (b) :extraUpdatedCols (b) :securityQuals <>}) :resultRelations <> :appendRelations <> :subplans <> :rewindPlanIDs (b) :rowMarks <> :relationOids (o 1259) :invalItems <> :paramExecTypes <> :utilityStmt <> :stmt_location 0 :stmt_len 0} $pgpg$ 173 | as plan; 174 | LOG: 175 | Query Text: 176 | Seq Scan on pg_class (cost=0.00..19.05 rows=1 width=1) 177 | Filter: (relname = 'pg_class'::name) 178 | relkind 179 | --------- 180 | r 181 | (1 row) 182 | 183 | Project Status 184 | -------------- 185 | 186 | Alpha. The extension is under active development. All constructive feedback is welcome. 187 | 188 | WARNING 189 | ------- 190 | 191 | The `pg_plan_guarantee` extension exposes internal data-structures of Postgres to the user. And the user has the ability to change the data-structure before feeding it back to the extension. 192 | 193 | The extension code takes many measures to prevent malicious/accidental misuse of its capabilities. But this extension may be used, accidentally or otherwise, to create security holes in your applications. So please exercise caution when using this extension. 194 | 195 | Development 196 | ----------- 197 | 198 | Provided that you have Git, VirtualBox, and Vagrant installed, you can get started like so. 199 | 200 | git clone git://git.postgresql.org/git/postgresql.git ~/dev/POSTGRES 201 | cd ~/dev/POSTGRES 202 | ln -s ../Postgres_Development_Vagrantfile ./Vagrantfile 203 | # ^^ See https://github.com/gurjeet/home/blob/wip/dev/Postgres_Development_Vagrantfile 204 | vagrant up 205 | vagrant ssh 206 | # Now we're inside Vagrant/Virtualbox VM 207 | cd ~/dev/POSTGRES 208 | git clone git@github.com:gurjeet/pg_plan_guarantee.git contrib/pg_plan_guarantee 209 | pgconfigure 210 | pgmake -j4 all check install 211 | pgmake -C contrib/pg_plan_guarantee all install 212 | pgmake -C contrib/auto_explain all install 213 | pgstart 214 | pgsql #starts psql utility 215 | --- do testing etc. 216 | pgstop 217 | 218 | The above instructions use my custom develoment environment; they include the shell functions from my [pgd][] project, Vagrantfile for setting up Postgres development environment, and miscellaneous artifacts from my $[HOME][] directory versioned in Git. 219 | 220 | [pgd]: https://github.com/gurjeet/pgd 221 | [HOME]: https://github.com/gurjeet/home 222 | 223 | Controversial Idea 224 | ------------------ 225 | 226 | TODO: Show how/why the Postgres developer/hacker community is against such an idea. 227 | -------------------------------------------------------------------------------- /license: -------------------------------------------------------------------------------- 1 | Copyright (c) 2022, http://Gurje.et 2 | 3 | Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies. 4 | 5 | IN NO EVENT SHALL RIGHTS-HOLDER BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF RIGHTS-HOLDER HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 6 | 7 | RIGHTS-HOLDER SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND RIGHTS-HOLDER HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 8 | 9 | -------------------------------------------------------------------------------- /pg_plan_guarantee.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * Copyright (c) 2022, Gurjeet Singh 4 | * 5 | * IDENTIFICATION 6 | * contrib/pg_plan_guarantee/pg_plan_guarantee.c 7 | * 8 | *------------------------------------------------------------------------- 9 | */ 10 | #include "postgres.h" 11 | 12 | #include "optimizer/planner.h" 13 | #include "storage/lmgr.h" 14 | #include "tcop/utility.h" 15 | #include "utils/builtins.h" 16 | 17 | PG_MODULE_MAGIC; 18 | 19 | /* Saved hooks */ 20 | static planner_hook_type prev_planner_hook = NULL; 21 | 22 | /* GUC variables */ 23 | static bool pgpg_enabled; /* Is the extension enabled? */ 24 | 25 | /* Function declarations */ 26 | void _PG_init(void); 27 | void _PG_fini(void); 28 | 29 | static PlannedStmt *pgpg_planner(Query *parse, 30 | const char *query_string, 31 | int cursorOptions, 32 | ParamListInfo boundParams); 33 | 34 | static void AcquireExecutorLocks(List *stmt_list, bool acquire); 35 | 36 | /* 37 | * Module load callback 38 | */ 39 | void 40 | _PG_init(void) 41 | { 42 | 43 | DefineCustomBoolVariable("pg_plan_guarantee.enabled", 44 | "Enable or disable the pg_plan_guarantee extension", 45 | NULL, 46 | &pgpg_enabled, 47 | true, 48 | PGC_USERSET, 49 | 0, 50 | NULL, 51 | NULL, 52 | NULL); 53 | 54 | MarkGUCPrefixReserved("pg_plan_guarantee"); 55 | 56 | /* 57 | * Install hooks. 58 | */ 59 | prev_planner_hook = planner_hook; 60 | planner_hook = pgpg_planner; 61 | } 62 | 63 | /* 64 | * Module unload callback 65 | */ 66 | void 67 | _PG_fini(void) 68 | { 69 | /* Uninstall hooks. */ 70 | planner_hook = prev_planner_hook; 71 | } 72 | 73 | /* 74 | * pgpg_planner: The workhorse. 75 | */ 76 | static PlannedStmt * 77 | pgpg_planner(Query *parse, 78 | const char *query_string, 79 | int cursorOptions, 80 | ParamListInfo boundParams) 81 | { 82 | PlannedStmt *result; 83 | 84 | if (pgpg_enabled 85 | && parse->commandType == CMD_SELECT 86 | && parse->jointree->fromlist == NULL 87 | && list_length(parse->targetList) == 2) 88 | { 89 | List *targetList = parse->targetList; 90 | char *res1_name = (char* )((TargetEntry*)list_nth(targetList,0))->resname; 91 | char *res2_name = (char* )((TargetEntry*)list_nth(targetList,1))->resname; 92 | int expr1_type = ((Expr*)((TargetEntry*)list_nth(targetList,0))->expr)->type; 93 | int expr2_type = ((Expr*)((TargetEntry*)list_nth(targetList,1))->expr)->type; 94 | Const *const1 = (Const*)((TargetEntry*)list_nth(targetList,0))->expr; 95 | Const *const2 = (Const*)((TargetEntry*)list_nth(targetList,1))->expr; 96 | Oid const1_type = const1->consttype; 97 | Oid const2_type = const2->consttype; 98 | bool const1_is_null = const1->constisnull; 99 | bool const2_is_null = const2->constisnull; 100 | 101 | if (strcmp(res1_name, "query") == 0 102 | && strcmp(res2_name, "plan") == 0 103 | && expr1_type == T_Const 104 | && expr2_type == T_Const 105 | && const1_type == TEXTOID 106 | && const2_type == TEXTOID 107 | && !const1_is_null 108 | && !const2_is_null) 109 | { 110 | /* The command matches the shape we expect */ 111 | 112 | char *query_text = TextDatumGetCString(const1->constvalue); 113 | char *plan_text = TextDatumGetCString(const2->constvalue); 114 | 115 | elog(DEBUG1, "query: %s", query_text); 116 | elog(DEBUG1, "plan: %s", plan_text); 117 | 118 | if (strlen(plan_text) == 0) 119 | { 120 | /* 121 | * User wants us to generate the plan and return it as 122 | * result. 123 | */ 124 | 125 | Datum plan_text_datum; 126 | List *parsetree_list; 127 | List *querytree_list; 128 | RawStmt*raw_parsetree; 129 | 130 | elog(DEBUG1, "plan text length is 0"); 131 | 132 | parsetree_list = pg_parse_query(query_text); 133 | if (list_length(parsetree_list) > 1) 134 | elog(ERROR, "pg_plan_guarantee: cannot use multiple commands in query text"); 135 | 136 | raw_parsetree = linitial_node(RawStmt, parsetree_list); 137 | 138 | querytree_list = pg_analyze_and_rewrite_fixedparams(raw_parsetree, query_text, 139 | NULL, 0, NULL); 140 | 141 | if (list_length(querytree_list) > 1) 142 | elog(ERROR, "pg_plan_guarantee: cannot use multiple queries in query text"); 143 | 144 | elog(DEBUG1, "querytree_list: %s", nodeToString(querytree_list)); 145 | 146 | if (prev_planner_hook) 147 | result = prev_planner_hook(linitial_node(Query, querytree_list), 148 | query_text, cursorOptions, 149 | boundParams); 150 | else 151 | result = standard_planner(linitial_node(Query, querytree_list), 152 | query_text, cursorOptions, 153 | boundParams); 154 | 155 | plan_text = nodeToString(result); 156 | plan_text_datum = CStringGetTextDatum(plan_text); 157 | 158 | elog(DEBUG1, "new plan text: %s", plan_text); 159 | 160 | /* Replace the zero-length string in second column with the guranteed-plan */ 161 | const2->constvalue = plan_text_datum; 162 | 163 | /* Perform the planning, as usual */ 164 | if (prev_planner_hook) 165 | result = prev_planner_hook(parse, query_string, cursorOptions, 166 | boundParams); 167 | else 168 | result = standard_planner(parse, query_string, cursorOptions, 169 | boundParams); 170 | 171 | return result; 172 | } 173 | else 174 | { 175 | /* 176 | * User wants us to use the guaranteed- plan, and send that to 177 | * the executor. 178 | */ 179 | 180 | Node *planned_node; 181 | List *dummy_list = NIL; 182 | PlannedStmt *planned_stmt; 183 | 184 | elog(DEBUG1, "plan text length is NOT 0"); 185 | 186 | planned_node = stringToNode(plan_text); 187 | 188 | if (!IsA(planned_node, PlannedStmt)) 189 | elog(ERROR, "pg_plan_guarantee: the provided plan-text is not a PlannedStmt"); 190 | 191 | planned_stmt = (PlannedStmt*)planned_node; 192 | 193 | dummy_list = lcons(planned_stmt, dummy_list); 194 | 195 | /* 196 | * Acquire locks that the Executor assumes are already taken 197 | * by the parse -> analyze -> plan steps. 198 | */ 199 | AcquireExecutorLocks(dummy_list, true); 200 | 201 | return planned_stmt; 202 | } 203 | } 204 | } 205 | 206 | /* 207 | * If any of the conditions we stipulate did not match, process the Query* 208 | * as if the extension was disabled. 209 | */ 210 | if (prev_planner_hook) 211 | result = prev_planner_hook(parse, query_string, cursorOptions, 212 | boundParams); 213 | else 214 | result = standard_planner(parse, query_string, cursorOptions, 215 | boundParams); 216 | 217 | return result; 218 | } 219 | 220 | /* 221 | * AcquireExecutorLocks: acquire locks needed for execution of a cached plan; 222 | * or release them if acquire is false. 223 | * 224 | * Copied verbatim (except for the '#if 0' and the corresponding '#endif') from 225 | * src/backend/utils/cache/plancache.c. We could use this function from there, 226 | * instead of duplicating it, if it were exported. Some code was '#if 0'd out, 227 | * because it contains call to another function (ScanQueryForLocks) which I 228 | * don't want/need to copy here. 229 | * 230 | * TODO: 231 | * Once this extension is in a useful state, consider asking the community 232 | * to export the function AcquireExecutorLocks, so we can use it here. Yesterday 233 | * (2022/06/24) I created a patch that marked the function extern, and did some 234 | * analysis before contributing it upstream; the analysis showed that the 235 | * function is marked private/static becuase it's not supposed to be part of the 236 | * API of the component it is in. Hence it will be very difficult to convince 237 | * the community to make it public/extern, when the sole user of the change 238 | * (this extension) is not even in a useful state. See branch Postgres 239 | * extern_AcquireExecutorLocks. 240 | */ 241 | static void 242 | AcquireExecutorLocks(List *stmt_list, bool acquire) 243 | { 244 | ListCell *lc1; 245 | 246 | foreach(lc1, stmt_list) 247 | { 248 | PlannedStmt *plannedstmt = lfirst_node(PlannedStmt, lc1); 249 | ListCell *lc2; 250 | #if 0 // We know for sure we'll not get Utility statments here 251 | if (plannedstmt->commandType == CMD_UTILITY) 252 | { 253 | /* 254 | * Ignore utility statements, except those (such as EXPLAIN) that 255 | * contain a parsed-but-not-planned query. Note: it's okay to use 256 | * ScanQueryForLocks, even though the query hasn't been through 257 | * rule rewriting, because rewriting doesn't change the query 258 | * representation. 259 | */ 260 | Query *query = UtilityContainsQuery(plannedstmt->utilityStmt); 261 | 262 | if (query) 263 | ScanQueryForLocks(query, acquire); 264 | continue; 265 | } 266 | #endif 267 | foreach(lc2, plannedstmt->rtable) 268 | { 269 | RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc2); 270 | 271 | if (rte->rtekind != RTE_RELATION) 272 | continue; 273 | 274 | /* 275 | * Acquire the appropriate type of lock on each relation OID. Note 276 | * that we don't actually try to open the rel, and hence will not 277 | * fail if it's been dropped entirely --- we'll just transiently 278 | * acquire a non-conflicting lock. 279 | */ 280 | if (acquire) 281 | LockRelationOid(rte->relid, rte->rellockmode); 282 | else 283 | UnlockRelationOid(rte->relid, rte->rellockmode); 284 | } 285 | } 286 | } 287 | 288 | -------------------------------------------------------------------------------- /pg_plan_guarantee.conf: -------------------------------------------------------------------------------- 1 | shared_preload_libraries = 'pg_plan_guarantee' 2 | -------------------------------------------------------------------------------- /pg_plan_guarantee.control: -------------------------------------------------------------------------------- 1 | # pg_plan_guarantee extension 2 | comment = 'guarantee that your plans will never change' 3 | default_version = '1.0' 4 | module_pathname = '$libdir/pg_plan_guarantee' 5 | relocatable = true 6 | --------------------------------------------------------------------------------