├── AUTHORS ├── CONTRIBUTORS ├── COPYING ├── ChangeLog ├── INSTALL ├── META.json ├── Makefile ├── README.md ├── doc ├── README └── oracle-style.txt ├── pgtt_bgw.c ├── pgtt_rsl.c ├── pgtt_rsl.control ├── sql ├── pgtt_rsl--1.2.0.sql ├── pgtt_rsl--1.3.0.sql └── pgtt_rsl--2.0.0.sql ├── test ├── bench │ ├── README │ ├── global_temp.bench │ ├── local_temp1.bench │ └── local_temp2.bench ├── expected │ ├── test_gtt.txt │ └── test_gtt2.txt ├── test_gtt.sql └── test_gtt2.sql └── updates ├── pgtt_rsl--1.2.0--1.3.0.sql └── pgtt_rsl--1.3.0--2.0.0.sql /AUTHORS: -------------------------------------------------------------------------------- 1 | global_temporary_tables is written by: 2 | * Gilles Darold 3 | 4 | -------------------------------------------------------------------------------- /CONTRIBUTORS: -------------------------------------------------------------------------------- 1 | List of contributors 2 | ==================== 3 | 4 | Thanks to all of them! 5 | -------------------------------------------------------------------------------- /COPYING: -------------------------------------------------------------------------------- 1 | Copyright (c) 2018-2022 Gilles Darold 2 | 3 | Permission to use, copy, modify, and distribute this software for any 4 | purpose with or without fee is hereby granted, provided that the above 5 | copyright notice and this permission notice appear in all copies. 6 | 7 | THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES 8 | WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF 9 | MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR 10 | ANY SPECIAL, DIRECT, INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES 11 | WHATSOEVER RESULTING FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN 12 | ACTION OF CONTRACT, NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF 13 | OR IN CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. 14 | -------------------------------------------------------------------------------- /ChangeLog: -------------------------------------------------------------------------------- 1 | Version 2.0 - November 14 2024 2 | 3 | - Add tests for the CREATE GLOBAL TEMPORARY TABLE / DROP TABLE syntax and 4 | update documentation. 5 | - Add support to CREATE GLOBAL TEMPORARY TABLE, CREATE GLOBAL TEMPORARY 6 | TABLE ... AS SELECT, and DROP TABLE. 7 | - Fix ON COMMIT DROP global temporary tables with subtransaction generated 8 | by SAVEPOINT. Thanks to Benjamin Wirth for the report. 9 | - Allow to create the table into any schema. 10 | - Use session_user instead of current_user for the owner of the view. Thanks 11 | to Benjamin Wirth for the report. 12 | - Rename the extension into pgtt_rsl and allow to create global temporary 13 | tables into any existing schema. 14 | 15 | Version 1.3 - June 02 2022 16 | 17 | - Add link to the new efficient implementation at https://github.com/darold/pgtt 18 | - Update copyright year 19 | - Add support to PostgreSQL 15 20 | - Add basic test of the extension to documentation 21 | - Set miminum PG version to 9.5 22 | - Prevent code to be executed in parallel processes 23 | - Add support to PostgreSQL 14 24 | - Port to PostgreSQL v13 and some test improvement. 25 | - Use bold for the warning 26 | 27 | Version 1.2 - April 08 2019 28 | 29 | - Fix some code missing port to v12 30 | - Fix pg_config path in Makefile. 31 | 32 | -------------------------------------------------------------------------------- /INSTALL: -------------------------------------------------------------------------------- 1 | The installation steps are covered in the README file. 2 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pgtt_rsl", 3 | "abstract": "Extension to add Global Temporary Tables feature to PostgreSQL", 4 | "description": "pgtt_rsl is a PostgreSQL extension to add Oracle-style Global Temporary Tables feature. It is based on unlogged table, Row Security Level and views.", 5 | "version": "2.0.0", 6 | "maintainer": "Gilles Darold ", 7 | "license": { 8 | "PostgreSQL": "http://www.postgresql.org/about/licence" 9 | }, 10 | "release_status": "stable", 11 | "prereqs": { 12 | "runtime": { 13 | "requires": { 14 | "PostgreSQL": "9.5.0" 15 | } 16 | } 17 | }, 18 | "provides": { 19 | "pgtt_rsl": { 20 | "file": "sql/pgtt_rsl--2.0.0.sql", 21 | "docfile": "doc/pgtt_rsl.md", 22 | "version": "2.0.0", 23 | "abstract": "Extension to manage Global Temporary Tables using RSL" 24 | }, 25 | "pgtt_bgw": { 26 | "file": "pgtt_bgw.so", 27 | "docfile": "doc/pgtt_bgw.md", 28 | "version": "2.0.0", 29 | "abstract": "Background worker to remove obsolete rows and tables for Global Temporary Tables RSL extension" 30 | } 31 | }, 32 | "meta-spec": { 33 | "version": "1.0", 34 | "url": "http://pgxn.org/meta/spec.txt" 35 | }, 36 | "tags": [ 37 | "global", 38 | "temporary", 39 | "table", 40 | "bgw", 41 | "background worker" 42 | ], 43 | "resources": { 44 | "bugtracker": { 45 | "web": "https://github.com/darold/pgtt-rsl/issues" 46 | }, 47 | "repository": { 48 | "type": "git", 49 | "url": "git://github.com/darold/pgtt-rsl.git", 50 | "web": "https://github.com/darold/pgtt-rsl.git" 51 | } 52 | } 53 | } 54 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = pgtt_rsl 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \ 3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 4 | 5 | PGFILEDESC = "pgtt_rsl - Global Temporary Tables for PostgreSQL with Row Security Level" 6 | 7 | PG_CONFIG = pg_config 8 | 9 | PG_CPPFLAGS = -I$(libpq_srcdir) 10 | PG_LDFLAGS = -L$(libpq_builddir) -lpq 11 | 12 | SHLIB_LINK = $(libpq) 13 | 14 | DOCS = $(wildcard doc/README*) 15 | MODULES = pgtt_rsl 16 | MODULE_big = pgtt_bgw 17 | OBJS = pgtt_bgw.o 18 | 19 | DATA = $(wildcard updates/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 20 | TESTS = $(wildcard test/*.sql) 21 | 22 | PGXS := $(shell $(PG_CONFIG) --pgxs) 23 | include $(PGXS) 24 | 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | * [Description](#description) 2 | * [Installation](#installation) 3 | * [Configuration](#configuration) 4 | * [Use of the extension](#use-of-the-extension) 5 | * [How the extension really works](#how-the-extension-really-works) 6 | * [Authors](#authors) 7 | 8 | ## PostgreSQL Global Temporary Tables - RSL 9 | 10 | ### [Description](#description) 11 | 12 | pgtt_rsl is a PostgreSQL extension to create and manage Oracle or DB2 style 13 | Global Temporary Tables. It is based on unlogged tables, Row Security 14 | Level and views. A background worker is responsible to periodically 15 | remove obsolete rows and tables. This implementation is designed to avoid 16 | catalog bloating when creating a lot of temporary tables. If you are looking 17 | for Oracle style Global Temporary Tables but with high performances 18 | you should look at [pgtt](https://github.com/darold/pgtt) which is 19 | based on temporary tables but will not address the bloat problem. 20 | 21 | PostgreSQL native temporary tables are automatically dropped at the 22 | end of a session, or optionally at the end of the current transaction. 23 | Oracle Global Temporary Tables (GTT) are permanent, they are created 24 | as regular tables visible to all users but their content is relative 25 | to the current session or transaction. Even if the table is persistent 26 | a session or transaction can not see rows written by an other session. 27 | 28 | An other difference is that Oracle or DB2 Global Temporary Table can be 29 | created in any schema while it is not possible with PostgreSQL where 30 | temporary table are stored in the pg_temp namespace. This version of the 31 | extension aallow to create the global temporary table in any schema. 32 | 33 | Usually this is not a problem, you have learn to deal with the 34 | temporary table behavior of PostgreSQL but the problem comes when 35 | you are migrating an Oracle or DB2 database to PostgreSQL. You have to 36 | rewrite the SQL and plpgsql code to follow the application logic and 37 | use PostgreSQL temporary table, that mean recreating the temporary 38 | table everywhere it is used. 39 | 40 | The other advantage of this kind of object when your application 41 | create and delete a lot of temporary tables this will add bloat in 42 | the PostgreSQL catalog and the performances will start to fall. 43 | Using Global Temporary Table will save this catalog bloating. They 44 | are permanent tables and so on permanent indexes, they will be found 45 | by the autovacuum process in contrary of local temporary tables. 46 | The very intensive creation of temporary table can also generate lot 47 | of replication lag. 48 | 49 | Don't expect high performances if you insert huge amount of tuples in 50 | these tables. The use of Row Security Level and cleanup by a background 51 | worker is slower than the use of regular temporary tables. Use it only 52 | if you have the pg_catalog bloating issue. 53 | 54 | ### [Installation](#installation) 55 | 56 | To install the pgtt_rsl extension you need a PostgreSQL version upper than 57 | 9.5. Untar the pgtt_rsl tarball anywhere you want then you'll need to 58 | compile it with pgxs. So the pg_config tool must be in your path. 59 | 60 | Depending on your installation, you may need to install some devel 61 | package and especially the libpq devel package. Once pg_config is in 62 | your path, do "make", and then "make install". 63 | 64 | Once the extension is installed, that shared_preload_library is set and 65 | PostgreSQL restarted you can verify that the extension is working as 66 | expected using: 67 | 68 | - `LANG=C psql -f test/test_gtt.sql > result.log 2>&1 && diff result.log test/expected/test_gtt.txt` 69 | - `LANG=C psql -f test/test_gtt2.sql > result.log 2>&1 && diff result.log test/expected/test_gtt2.txt` 70 | 71 | ### [Configuration](#configuration) 72 | 73 | The background worker used to remove obsolete rows from global 74 | temporary tables must be loaded on database start by adding the 75 | library to shared_preload_libraries in postgresql.conf. You also 76 | need to load the pgtt_rsl library defining C function used by the 77 | extension. 78 | 79 | * shared_preload_libraries='pgtt_bgw,pgtt_rsl' 80 | 81 | You'll be able to set the two following parameters in configuration 82 | file: 83 | 84 | * pgtt_bgw.naptime = 5 85 | 86 | this is the interval used between each cleaning cycle, 5 seconds 87 | per default. 88 | 89 | * pgtt_bgw.analyze = off 90 | 91 | Force the background worker to execute an ANALYZE after each run. 92 | Default is off, it is better to let autoanalyze to the work. 93 | 94 | To avoid too much performances lost when the background worker is 95 | deleting obsolete rows the limit of rows removed at one time is 96 | defined by the following directive: 97 | 98 | * pgtt_bgw.chunk_size = 250000 99 | 100 | Default is to remove rows by chunk of 250000 tuples. 101 | 102 | 103 | Once this configuration is done, restart PostgreSQL. 104 | 105 | The background worker will wake up each naptime interval to scan 106 | all database using the pgtt_rsl extension. It will then remove all rows 107 | that don't belong to an existing session or transaction. 108 | 109 | ### [Use of the extension](#use-of-the-extension) 110 | 111 | In all database where you want to use Global Temporary Tables you 112 | will have to create the extension using: 113 | 114 | * CREATE EXTENSION pgtt_rsl; 115 | 116 | The extension comes with two functions that can be used instead of 117 | the CREATE GLOBAL TEMPORARY TABLE statement. To create a GTT table 118 | named test_table you can use one of the following statements: 119 | 120 | * `CREATE GLOBAL TEMPORARY TABLE test_table (id integer, lbl text) ON COMMIT PRESERVE ROWS;` 121 | * `SELECT pgtt_schema.pgtt_create_table('test_table', 'id integer, lbl text', true);` 122 | 123 | The first argument of the pgtt_create_table() function is the name 124 | of the permanent temporary table. The second is the definition of 125 | the table. The third parameter is a boolean to indicate if the rows 126 | should be preserved at end of the transaction or deleted at commit. 127 | 128 | The CREATE GLOBAL TEMPORARY syntax output a message saying the GLOBAL keyword 129 | is deprecated but this is just a warning. If you don't want to be annoyed by 130 | this messages, comment the GLOBAL keyword like this: 131 | 132 | * `CREATE /*GLOBAL*/ TEMPORARY TABLE test_table (id integer, lbl text) ON COMMIT PRESERVE ROWS;` 133 | 134 | Once the table is created it can be used by the application like any 135 | temporary table. A session will only see its rows for the time of a 136 | session or a transaction following if the temporary table preserves 137 | the rows at end of the transaction or deleted them at commit. 138 | 139 | To drop a Global Temporary Table you can use one of the following statements: 140 | 141 | * `DROP TABLE test_table;` 142 | * `SELECT pgtt_schema.pgtt_drop_table('test_table');` 143 | 144 | ### [How the extension really works](#how-the-extension-really-works) 145 | 146 | When you call the pgtt_create_table() function or CREATE GLOBAL TEMPORARY TABLE 147 | the pgtt_rsl extension act as follow: 148 | 149 | 1) Create an unlogged table in the pgtt_schema schema and renamed it 150 | with 'pgtt_' and the oid of the table newly created. Alter the table 151 | to add an "hidden" column 'pgtt_sessid' of custom type lsid. 152 | The users must not access to this table directly. 153 | The pgtt_sessid column has default to get_session_id(), this 154 | function is part of the pgtt_extension and build a session 155 | local unique id from the backend start time (epoch) and the pid. 156 | The custom type use is a C structure of two integers: 157 | ``` 158 | typedef struct Lsid { 159 | int backend_start_time; 160 | int backend_pid; 161 | } Lsid; 162 | ``` 163 | 2) Create a view with the name and the schema of the origin global 164 | temporary table. All user access to the underlying table will be 165 | done through this view. 166 | 3) Create a btree index on column pgtt_sessid of special type lsid. 167 | 4) Grant SELECT,INSERT,UPDATE,DELETE on the table to PUBLIC. 168 | 5) Activate RLS on the table and create two RLS policies to hide rows 169 | to other sessions or transactions when required. 170 | 6) Force RLS to be active for the owner of the table. 171 | 7) Create an updatable view using the original table name with a 172 | a WHERE clause to hide the "hidden" column of the table. 173 | 8) Set owner of the view to current_user which might be a superuser, 174 | grants to other users are the responsability of the administrator. 175 | 9) Insert the relation between the GTT and the view in the catalog 176 | table pgtt_global_temp. 177 | 178 | The pgtt_drop_table() function is responsible to remove all references 179 | to a GTT table and its corresponding view. When it is called it just 180 | execute a "DROP TABLE IF EXISTS pgtt_schema.pgtt_tbname CASCADE;". 181 | Using CASCADE will also drop the associated view. 182 | 183 | The "DROP TABLE pgtt_table" statement will drop the view instead, the 184 | corresponding table in extension's schema pgtt_schema will be removed 185 | later by the background worker. 186 | 187 | The extension also define four functions to manipulate the 'lsid' type: 188 | 189 | * get_session_id(): generate the local session id and returns an lsid. 190 | * generate_lsid(int, int): generate a local session id based on a backend 191 | start time (number of second since epoch) and a pid of the backend. 192 | Returns an lsid. 193 | * get_session_start_time(lsid): returns the number of second since epoch 194 | part of an lsid. 195 | * get_session_pid(lsid): returns the pid part of an lsid. 196 | 197 | Here is an example of use of these functions: 198 | ``` 199 | test=# SELECT get_session_id(); 200 | get_session_id 201 | -------------------- 202 | {1527703231,11007} 203 | 204 | test=# SELECT generate_lsid(1527703231,11007); 205 | generate_lsid 206 | -------------------- 207 | {1527703231,11007} 208 | 209 | test=# SELECT get_session_start_time(get_session_id()); 210 | get_session_start_time 211 | ------------------------ 212 | 1527703231 213 | 214 | test=# SELECT get_session_pid(get_session_id()); 215 | get_session_pid 216 | ----------------- 217 | 11007 218 | ``` 219 | 220 | The purpose of these functions is for internal and debuging use only. 221 | 222 | Behind the background worker 223 | ============================ 224 | 225 | The pgtt_bgw background worker is responsible of removing all rows 226 | that are no more visible to any running session or transaction. 227 | 228 | To achieve that it wakes up each naptime (default 5 seconds) and 229 | creates dedicated dynamic background workers to connect to each 230 | database. When the pgtt extension is found in the database it calls 231 | the pgtt_schema.pgtt_maintenance() function. 232 | 233 | The first argument of the function is the iteration number, 0 mean 234 | that the background worker was just started so Global Temporary tables 235 | must be truncated. The iteration number is incremented each time 236 | the background worker wakes up. 237 | 238 | To avoid too much performances lost when the background worker is 239 | deleting rows the number of rows removed at one time is defined 240 | by the pgtt_rsl.chunk_size GUC. It is passed to the function as second 241 | parameter, default: 250000. 242 | 243 | The third parameter is use to force an ANALYZE to be perform just 244 | after obsolete rows have been removed. Default is to leave autoanalyze 245 | do the work. 246 | 247 | The pgtt_schema.pgtt_maintenance() has the following actions: 248 | 249 | 1) Look for relation id in table pgtt_schema.pgtt_global_temp. 250 | 2) Remove all references to the relation if it has been dropped. 251 | 3) If the relation exists it truncate the GTT table when the worker 252 | is run at postmaster startup then exit. 253 | 4) For other iteration it delete rows from the Global Temporary table 254 | where the pid stored in pgtt_sessid doesn't appears in view 255 | pg_stat_activity or if the xmim is not fount in the same view, 256 | looking at pid and backend_xid columns. Xmin is verified only if 257 | the Global Temporary table is declared to delete rows on commit, 258 | when preserved is false. 259 | 5) When an analyze is asked the function execute an ANALYZE on 260 | the table after having removed obsolete tuples. THe default is to 261 | let autoanalyze do is work. 262 | 263 | The function returns the total number of rows deleted. It must not be 264 | run manually but only run by pgtt_bgw the background worker. 265 | 266 | ### [Authors](#authors) 267 | 268 | - Gilles Darold 269 | 270 | ### [License](#license) 271 | 272 | This extension is free software distributed under the PostgreSQL 273 | Licence. 274 | 275 | Copyright (c) 2018-2024, Gilles Darold 276 | 277 | -------------------------------------------------------------------------------- /doc/README: -------------------------------------------------------------------------------- 1 | ../README.md -------------------------------------------------------------------------------- /doc/oracle-style.txt: -------------------------------------------------------------------------------- 1 | Oracle-style Global temporary tables. 2 | 3 | To display all Oracle global temporary tables: 4 | 5 | SELECT table_name FROM all_tables WHERE temporary = 'Y'; 6 | 7 | To know if rows are presistent or not: 8 | 9 | SELECT duration FROM all_tables WHERE table_name='MY_TEMP_TABLE' 10 | 11 | DURATION 12 | --------------- 13 | SYS$TRANSACTION 14 | SYS$TRANSACTION 15 | 16 | Type of DURATION: 17 | 18 | SYS$SESSION - Rows are preserved for the duration of the session 19 | SYS$TRANSACTION - Rows are deleted after COMMIT 20 | NULL - Permanent table 21 | 22 | 23 | Example of use: 24 | 25 | CREATE GLOBAL TEMPORARY TABLE my_temp_table(column1 number) ON COMMIT PRESERVE ROWS; 26 | 27 | INSERT INTO my_temp_table (column1) VALUES (1); 28 | SELECT * FROM my_temp_table; 29 | 30 | 31 | REF/ https://oracle-base.com/articles/misc/temporary-tables 32 | 33 | 34 | Create global temporary table with transaction scope: 35 | 36 | CREATE GLOBAL TEMPORARY TABLE TABLE_GTT_TRANSACTION 37 | ( 38 | PKID NUMBER(1,0) NOT NULL 39 | , CODE VARCHAR(2) NOT NULL 40 | ) ON COMMIT DELETE ROWS; 41 | 42 | 43 | Create global temporary table with session scope: 44 | 45 | CREATE GLOBAL TEMPORARY TABLE TABLE_GTT_SESSION 46 | ( 47 | PKID NUMBER(1,0) NOT NULL 48 | , CODE VARCHAR(2) NOT NULL 49 | ) ON COMMIT PRESERVE ROWS; 50 | 51 | 52 | https://www.techonthenet.com/oracle/tables/global_temp.php 53 | 54 | Syntax 55 | 56 | The syntax for Oracle CREATE GLOBAL TEMPORARY TABLE is: 57 | 58 | CREATE GLOBAL TEMPORARY TABLE table_name 59 | ( column1 datatype [ NULL | NOT NULL ], 60 | column2 datatype [ NULL | NOT NULL ], 61 | ... 62 | column_n datatype [ NULL | NOT NULL ] 63 | ); 64 | 65 | Example 66 | 67 | Let's look at an Oracle CREATE GLOBAL TEMPORARY TABLE example: 68 | 69 | CREATE GLOBAL TEMPORARY TABLE suppliers 70 | ( supplier_id numeric(10) NOT NULL, 71 | supplier_name varchar2(50) NOT NULL, 72 | contact_name varchar2(50) 73 | ); 74 | 75 | 76 | 77 | http://www.dba-oracle.com/t_global_temporary_tables.htm 78 | 79 | drop table store_sales; 80 | drop table store_cnt; 81 | drop table store_qty; 82 | 83 | create global temporary table store_qty 84 | on commit preserve rows 85 | as select sum(quantity) all_sales from sales; 86 | 87 | create global temporary table store_cnt 88 | on commit preserve rows 89 | as select count(*) nbr_stores from store; 90 | 91 | create global temporary table store_sales 92 | on commit preserve rows 93 | as select store_name, sum(quantity) store_sales 94 | from store natural join sales group by store_name; 95 | 96 | select 97 | store_name, 98 | store_sales, 99 | all_sales / nbr_stores avg_sales 100 | from 101 | store_qty, 102 | store_cnt, 103 | store_sales 104 | where 105 | store_sales > (all_sales / nbr_stores); 106 | 107 | -------------------------------------------------------------------------------- /pgtt_bgw.c: -------------------------------------------------------------------------------- 1 | /* 2 | * pgtt_bgw.c 3 | * 4 | * A background worker process for the global_temporary_table extension to 5 | * allow maintenance of obsolete rows in pgtt_global_temp_register tables. 6 | * Run in all database with the extension to remove rows in the register 7 | * table that are no more visible by any session or any session+transaction. 8 | * 9 | * This program is open source, licensed under the PostgreSQL license. 10 | * For license terms, see the COPYING file. 11 | * 12 | * Copyright (c) 2018-2022 Gilles Darold 13 | */ 14 | 15 | #include "postgres.h" 16 | #include "libpq-fe.h" 17 | 18 | /* Necessary for a bgworker */ 19 | #include "miscadmin.h" 20 | #include "postmaster/bgworker.h" 21 | #include "storage/ipc.h" 22 | #include "storage/latch.h" 23 | #include "storage/lwlock.h" 24 | #include "storage/proc.h" 25 | #include "storage/shmem.h" 26 | 27 | /* Used by this code */ 28 | #include "access/xact.h" 29 | #include "executor/spi.h" 30 | #include "fmgr.h" 31 | #include "lib/stringinfo.h" 32 | #include "utils/builtins.h" 33 | #include "utils/snapmgr.h" 34 | #include "tcop/utility.h" 35 | #include "pgstat.h" 36 | #include "utils/ps_status.h" 37 | #include "catalog/pg_database.h" 38 | #include "access/htup_details.h" 39 | #include "utils/memutils.h" 40 | 41 | #if (PG_VERSION_NUM >= 120000) 42 | #include "access/tableam.h" 43 | #include "access/heapam.h" 44 | #include "access/table.h" 45 | #endif 46 | 47 | #if (PG_VERSION_NUM >= 100000) 48 | #include "utils/varlena.h" 49 | #endif 50 | 51 | /* Default database/user connection */ 52 | #define PGTT_START_DBNAME "postgres" 53 | #define PGTT_BGW_USER "postgres" 54 | /* PGTT extension schema */ 55 | #define PGTT_SCHEMA "pgtt_schema" 56 | 57 | /* the minimum allowed time between two awakenings of the worker */ 58 | #define MIN_PGTT_SLEEPTIME 1 /* second */ 59 | #define MAX_PGTT_SLEEPTIME 60 /* seconds */ 60 | 61 | #define BGW_RESTART_TIME 600 /* Restart after 10min in case of crash */ 62 | 63 | #define PGTT_FUNCTION_INFO_V1(fn) \ 64 | PGDLLEXPORT Datum fn(PG_FUNCTION_ARGS); \ 65 | PG_FUNCTION_INFO_V1(fn) 66 | 67 | PG_MODULE_MAGIC; 68 | 69 | void _PG_init(void); 70 | //void pgtt_bgw_main(Datum main_arg) ; 71 | //void pgtt_bgw_maintenance(Datum main_arg); 72 | extern PGDLLEXPORT void pgtt_bgw_main(Datum main_arg); 73 | extern PGDLLEXPORT void pgtt_bgw_maintenance(Datum main_arg); 74 | 75 | static List *get_database_list(void); 76 | 77 | /* flags set by signal handlers */ 78 | static volatile sig_atomic_t got_sighup = false; 79 | static volatile sig_atomic_t got_sigterm = false; 80 | 81 | /* GUC variables */ 82 | static int pgtt_naptime = 5; // Default 5 seconds 83 | static char *pgtt_analyze = "off"; 84 | static int pgtt_chunk_size = 250000; // Default delete by 250000 rows at a timeœ 85 | 86 | /* Counter of iteration */ 87 | static int iteration = 0; 88 | /* 89 | * Signal handler for SIGTERM 90 | * Set a flag to let the main loop to terminate, and set our latch to wake 91 | * it up. 92 | */ 93 | static void 94 | pgtt_bgw_sigterm(SIGNAL_ARGS) 95 | { 96 | int save_errno = errno; 97 | 98 | got_sigterm = true; 99 | 100 | if (MyProc) 101 | SetLatch(&MyProc->procLatch); 102 | 103 | errno = save_errno; 104 | } 105 | 106 | /* 107 | * Signal handler for SIGHUP 108 | * Set a flag to tell the main loop to reread the config file, and set 109 | * our latch to wake it up. 110 | */ 111 | static void 112 | pgtt_bgw_sighup(SIGNAL_ARGS) 113 | { 114 | int save_errno = errno; 115 | 116 | got_sighup = true; 117 | 118 | if (MyProc) 119 | SetLatch(&MyProc->procLatch); 120 | 121 | errno = save_errno; 122 | } 123 | 124 | /* 125 | * Entrypoint of this module. 126 | */ 127 | void 128 | _PG_init(void) 129 | { 130 | BackgroundWorker worker; 131 | 132 | DefineCustomIntVariable("pgtt_bgw.naptime", 133 | "How often maintenance of Global Temporary Tables is called (in seconds).", 134 | NULL, 135 | &pgtt_naptime, 136 | 5, 137 | MIN_PGTT_SLEEPTIME, 138 | MAX_PGTT_SLEEPTIME, 139 | PGC_SIGHUP, 140 | 0, 141 | NULL, 142 | NULL, 143 | NULL); 144 | 145 | DefineCustomStringVariable("pgtt_bgw.analyze", 146 | "Whether to force an analyze after a maintenance on a GTT. Possible values: 'off' (default) or 'on'. Default is to let autoanalyze do the job.", 147 | NULL, 148 | &pgtt_analyze, 149 | "off", 150 | PGC_SIGHUP, 151 | 0, 152 | NULL, 153 | NULL, 154 | NULL); 155 | 156 | DefineCustomIntVariable("pgtt_bgw.chunk_size", 157 | "Maximum number of rows to delete in Global Temporary Tables.", 158 | NULL, 159 | &pgtt_chunk_size, 160 | 250000, 161 | 1000, 162 | INT_MAX, 163 | PGC_SIGHUP, 164 | 0, 165 | NULL, 166 | NULL, 167 | NULL); 168 | 169 | 170 | if (!process_shared_preload_libraries_in_progress) 171 | return; 172 | 173 | /* Start when database starts */ 174 | memset(&worker, 0, sizeof(worker)); 175 | snprintf(worker.bgw_name, BGW_MAXLEN, "pgtt_rsl master background worker"); 176 | worker.bgw_flags = BGWORKER_SHMEM_ACCESS | BGWORKER_BACKEND_DATABASE_CONNECTION; 177 | worker.bgw_restart_time = BGW_RESTART_TIME; 178 | worker.bgw_start_time = BgWorkerStart_RecoveryFinished; 179 | #if (PG_VERSION_NUM < 100000) 180 | worker.bgw_main = pgtt_bgw_main; 181 | #else 182 | snprintf(worker.bgw_library_name, BGW_MAXLEN, "pgtt_bgw"); 183 | snprintf(worker.bgw_function_name, BGW_MAXLEN, CppAsString(pgtt_bgw_main)); 184 | #endif 185 | worker.bgw_main_arg = (Datum) 0; 186 | #if (PG_VERSION_NUM >= 90400) 187 | worker.bgw_notify_pid = 0; 188 | #endif 189 | RegisterBackgroundWorker(&worker); 190 | 191 | } 192 | 193 | void 194 | pgtt_bgw_main(Datum main_arg) 195 | { 196 | int worker_id = DatumGetInt32(main_arg); /* in case we start mulitple worker at startup */ 197 | StringInfoData buf; 198 | 199 | ereport(DEBUG1, 200 | (errmsg("PGTT background worker started (#%d)", worker_id))); 201 | 202 | /* Establish signal handlers before unblocking signals. */ 203 | pqsignal(SIGHUP, pgtt_bgw_sighup); 204 | pqsignal(SIGTERM, pgtt_bgw_sigterm); 205 | 206 | /* We're now ready to receive signals */ 207 | BackgroundWorkerUnblockSignals(); 208 | 209 | /* 210 | * Connect to the postgres database, will be used to get 211 | * a list of all database at each main loop iteration 212 | */ 213 | ereport(DEBUG1, 214 | (errmsg("Initialize connection to database %s", PGTT_START_DBNAME))); 215 | #if (PG_VERSION_NUM >= 110000) 216 | BackgroundWorkerInitializeConnection(PGTT_START_DBNAME, NULL, 0); 217 | #else 218 | BackgroundWorkerInitializeConnection(PGTT_START_DBNAME, NULL); 219 | #endif 220 | 221 | initStringInfo(&buf); 222 | 223 | /* 224 | * Main loop: do this until the SIGTERM handler tells us to terminate 225 | */ 226 | while (!got_sigterm) 227 | { 228 | List *dblist = NIL; 229 | int rc; 230 | 231 | /* Using Latch loop method suggested in latch.h 232 | * Uses timeout flag in WaitLatch() further below instead of sleep to allow clean shutdown */ 233 | ResetLatch(&MyProc->procLatch); 234 | 235 | CHECK_FOR_INTERRUPTS(); 236 | 237 | /* In case of a SIGHUP, just reload the configuration. */ 238 | if (got_sighup) 239 | { 240 | got_sighup = false; 241 | ProcessConfigFile(PGC_SIGHUP); 242 | } 243 | 244 | /* Get the list of database to scan */ 245 | dblist = get_database_list(); 246 | 247 | /* Now for each database run GTT maintenance in a dedicated dynamic worker */ 248 | if (dblist != NIL) 249 | { 250 | ListCell *item; 251 | BackgroundWorker worker; 252 | BackgroundWorkerHandle *handle; 253 | BgwHandleStatus status; 254 | int full_string_length; 255 | pid_t pid; 256 | int i = 0; 257 | 258 | /* set up common data for all our workers */ 259 | worker.bgw_flags = BGWORKER_SHMEM_ACCESS | BGWORKER_BACKEND_DATABASE_CONNECTION; 260 | worker.bgw_start_time = BgWorkerStart_RecoveryFinished; 261 | worker.bgw_restart_time = BGW_NEVER_RESTART; 262 | #if (PG_VERSION_NUM < 100000) 263 | worker.bgw_main = NULL; 264 | #endif 265 | sprintf(worker.bgw_library_name, "pgtt_bgw"); 266 | sprintf(worker.bgw_function_name, "pgtt_bgw_maintenance"); 267 | 268 | foreach(item, dblist) 269 | { 270 | char *dbname = (char *) lfirst(item); 271 | 272 | i++; 273 | 274 | ereport(DEBUG1, 275 | (errmsg("Dynamic launch of a background worker to clean GTT in database %s", dbname))); 276 | full_string_length = snprintf(worker.bgw_name, sizeof(worker.bgw_name), 277 | "pgtt_bgw dynamic bgworker [%s]", dbname); 278 | if (full_string_length >= sizeof(worker.bgw_name)) { 279 | memcpy(worker.bgw_name + sizeof(worker.bgw_name) - 4, "...)", 4); 280 | } 281 | worker.bgw_main_arg = (Datum) iteration; 282 | worker.bgw_notify_pid = MyProcPid; 283 | /* set the database to scan by the dynamic bgworker */ 284 | memset(worker.bgw_extra, 0, BGW_EXTRALEN); 285 | memcpy(worker.bgw_extra, dbname, strlen(dbname)); 286 | 287 | ereport(DEBUG1, 288 | (errmsg("Registering dynamic background worker..."))); 289 | if (!RegisterDynamicBackgroundWorker(&worker, &handle)) { 290 | ereport(ERROR, 291 | (errmsg("Unable to register dynamic background worker for pgtt. Consider increasing max_worker_processes if you see this frequently. Main background worker process will try restarting in 10 minutes."))); 292 | } 293 | ereport(DEBUG1, 294 | (errmsg("Waiting for dynamic background worker startup..."))); 295 | status = WaitForBackgroundWorkerStartup(handle, &pid); 296 | ereport(DEBUG1, 297 | (errmsg("Dynamic background worker startup status: %d", status))); 298 | if (status == BGWH_STOPPED) { 299 | ereport(ERROR, 300 | (errcode(ERRCODE_INSUFFICIENT_RESOURCES), 301 | errmsg("Could not start dynamic pgtt background process"), 302 | errhint("More details may be available in the server log."))); 303 | } 304 | 305 | if (status == BGWH_POSTMASTER_DIED) { 306 | ereport(ERROR, 307 | (errcode(ERRCODE_INSUFFICIENT_RESOURCES), 308 | errmsg("Cannot start dynamic pgtt background processes without postmaster"), 309 | errhint("Kill all remaining database processes and restart the database."))); 310 | } 311 | Assert(status == BGWH_STARTED); 312 | #if (PG_VERSION_NUM >= 90500) 313 | /* 314 | * Shutdown wait function introduced in 9.5. The latch problems this wait 315 | * fixes are only encountered in 9.6 and later. So this shouldn't be a 316 | * problem for 9.4. 317 | */ 318 | ereport(DEBUG1, 319 | (errmsg("Waiting for dynamic pgtt background shutdown..."))); 320 | status = WaitForBackgroundWorkerShutdown(handle); 321 | ereport(DEBUG1, 322 | (errmsg("Dynamic pgtt background shutdown status: %d", status))); 323 | Assert(status == BGWH_STOPPED); 324 | #endif 325 | } 326 | list_free(dblist); 327 | iteration++; 328 | } 329 | ereport(DEBUG1, 330 | (errmsg("Latch status before waitlatch call: %d", MyProc->procLatch.is_set))); 331 | 332 | #if (PG_VERSION_NUM >= 100000) 333 | rc = WaitLatch(&MyProc->procLatch, 334 | WL_LATCH_SET | WL_TIMEOUT | WL_POSTMASTER_DEATH, 335 | pgtt_naptime * 1000L, 336 | PG_WAIT_EXTENSION); 337 | #else 338 | rc = WaitLatch(&MyProc->procLatch, 339 | WL_LATCH_SET | WL_TIMEOUT | WL_POSTMASTER_DEATH, 340 | pgtt_naptime * 1000L); 341 | #endif 342 | 343 | /* emergency bailout if postmaster has died */ 344 | if (rc & WL_POSTMASTER_DEATH) 345 | proc_exit(1); 346 | 347 | ereport(DEBUG1, 348 | (errmsg("Latch status after waitlatch call: %d", MyProc->procLatch.is_set))); 349 | } /* End of main loop */ 350 | 351 | ereport(LOG, (errmsg("pgtt_rsl background worker shutting down"))); 352 | proc_exit(1); 353 | } 354 | 355 | /* 356 | * Function executed at each loop of the main process. 357 | * Remove obsolete rows from all Global Temporary Tables. 358 | */ 359 | void 360 | pgtt_bgw_maintenance(Datum main_arg) 361 | { 362 | 363 | char *dbname; 364 | char *analyze; 365 | StringInfoData buf; 366 | int worker_iter; 367 | PGconn *dbh; 368 | const char *conninfo; 369 | PGresult *result; 370 | 371 | /* Get the current iteration */ 372 | worker_iter = DatumGetInt32(main_arg); 373 | 374 | /* Get database to scan for this worker_iter */ 375 | dbname = MyBgworkerEntry->bgw_extra; 376 | Assert(dbname != NULL); 377 | 378 | ereport(DEBUG1, 379 | (errmsg("Entering pgtt dynamic bgworker to scan database %s", dbname))); 380 | 381 | pgstat_report_appname(psprintf("pgtt_bgw %s", dbname)); 382 | 383 | /* 384 | * We can not change connection database using SPI 385 | * so we use libpq to connect to each database to 386 | * proceed to obsolete rows cleaning. 387 | */ 388 | conninfo = psprintf("dbname=%s user=%s", dbname, PGTT_BGW_USER); 389 | 390 | ereport(DEBUG1, 391 | (errmsg("Establishing connection to '%s' using libpd", conninfo))); 392 | 393 | if (( dbh = PQconnectdb( conninfo )) == NULL ) 394 | ereport(ERROR, 395 | ( errmsg("could not connect allocate a connection to database '%s'", dbname))); 396 | if ( PQstatus(dbh) == CONNECTION_BAD ) 397 | ereport(ERROR, 398 | ( errmsg("could not connect to database %s using conninfo '%s', error: %s", dbname, conninfo, PQerrorMessage(dbh)))); 399 | 400 | ereport(DEBUG1, 401 | (errmsg("Connected to database %s", dbname))); 402 | 403 | initStringInfo(&buf); 404 | 405 | /* First determine if pgtt is even installed in this database */ 406 | appendStringInfo(&buf, "SELECT extname FROM pg_catalog.pg_extension WHERE extname = 'pgtt_rsl'"); 407 | 408 | ereport(DEBUG1, 409 | (errmsg("Checking if pgtt extension is installed in database: %s", dbname))); 410 | 411 | pgstat_report_activity(STATE_RUNNING, buf.data); 412 | if (( result = PQexec(dbh, buf.data)) == NULL ) 413 | ereport(ERROR, 414 | ( errmsg("Cannot determine if pgtt is installed in database %s: error: %s", 415 | dbname, PQerrorMessage( dbh )))); 416 | 417 | resetStringInfo(&buf); 418 | 419 | if (PQntuples( result ) != 1) 420 | { 421 | ereport(DEBUG1, 422 | (errmsg("pgtt not installed in database %s. Nothing to do exiting gracefully.", dbname))); 423 | /* Nothing left to do, go to end of function. */ 424 | } 425 | else 426 | { 427 | PQclear( result ); 428 | /* Look if we need to force an ANALYSE after the maintenance */ 429 | if (strcmp(pgtt_analyze, "on") == 0) { 430 | analyze = "true"; 431 | } else { 432 | analyze = "false"; 433 | } 434 | 435 | if (worker_iter) 436 | ereport(DEBUG1, 437 | (errmsg("%s dynamic bgworker running maintenance task on database %s", 438 | MyBgworkerEntry->bgw_name, dbname))); 439 | else 440 | ereport(DEBUG1, 441 | (errmsg("%s dynamic bgworker truncating GTT tables on database %s", 442 | MyBgworkerEntry->bgw_name, dbname))); 443 | 444 | appendStringInfo(&buf, "SELECT \"%s\".pgtt_maintenance(%d, %d, %s) AS nrows", PGTT_SCHEMA, worker_iter, pgtt_chunk_size, analyze); 445 | 446 | pgstat_report_activity(STATE_RUNNING, buf.data); 447 | 448 | if (( result = PQexec(dbh, buf.data)) == NULL ) 449 | { 450 | PQclear( result ); 451 | PQfinish(dbh); 452 | ereport(ERROR, 453 | ( errmsg("Cannot call pgtt_maintenance() function in database %s: error: %s", 454 | dbname, PQerrorMessage( dbh )))); 455 | } 456 | if (!PQgetisnull(result, 0, 0)) 457 | { 458 | int nrows; 459 | 460 | nrows = atoi(PQgetvalue(result, 0, 0)); 461 | if (nrows > 0) 462 | ereport(LOG, 463 | (errmsg("pgtt dynamic background worker removed %d obsolete rows from database %s", 464 | nrows, dbname))); 465 | } 466 | } 467 | PQclear( result ); 468 | 469 | 470 | PQfinish(dbh); 471 | pgstat_report_activity(STATE_IDLE, NULL); 472 | ereport(DEBUG1, 473 | (errmsg("pgtt dynamic bgworker shutting down gracefully for database %s.", dbname))); 474 | 475 | } 476 | 477 | /* 478 | * get_database_list 479 | * Return a list of all databases found in pg_database. 480 | * 481 | * Note: this is the only function in which the GTT launcher uses a 482 | * transaction. Although we aren't attached to any particular database and 483 | * therefore can't access most catalogs, we do have enough infrastructure 484 | * to do a seqscan on pg_database. 485 | */ 486 | static List * 487 | get_database_list(void) 488 | { 489 | List *dblist = NIL; 490 | Relation rel; 491 | #if (PG_VERSION_NUM >= 120000) 492 | TableScanDesc scan; 493 | #else 494 | HeapScanDesc scan; 495 | #endif 496 | HeapTuple tup; 497 | MemoryContext resultcxt; 498 | 499 | /* This is the context that we will allocate our output data in */ 500 | resultcxt = CurrentMemoryContext; 501 | 502 | /* 503 | * Start a transaction so we can access pg_database, and get a snapshot. 504 | * We don't have a use for the snapshot itself, but we're interested in 505 | * the secondary effect that it sets RecentGlobalXmin. (This is critical 506 | * for anything that reads heap pages, because HOT may decide to prune 507 | * them even if the process doesn't attempt to modify any tuples.) 508 | */ 509 | StartTransactionCommand(); 510 | (void) GetTransactionSnapshot(); 511 | 512 | #if (PG_VERSION_NUM >= 120000) 513 | rel = table_open(DatabaseRelationId, AccessShareLock); 514 | scan = table_beginscan_catalog(rel, 0, NULL); 515 | #else 516 | rel = heap_open(DatabaseRelationId, AccessShareLock); 517 | scan = heap_beginscan_catalog(rel, 0, NULL); 518 | #endif 519 | while (HeapTupleIsValid(tup = heap_getnext(scan, ForwardScanDirection))) 520 | { 521 | Form_pg_database pgdatabase = (Form_pg_database) GETSTRUCT(tup); 522 | MemoryContext oldcxt; 523 | 524 | /* do not consider template or database that do not allow connection */ 525 | if (pgdatabase->datistemplate || !pgdatabase->datallowconn) 526 | continue; 527 | 528 | /* 529 | * Allocate our results in the caller's context, not the 530 | * transaction's. We do this inside the loop, and restore the original 531 | * context at the end, so that leaky things like heap_getnext() are 532 | * not called in a potentially long-lived context. 533 | */ 534 | oldcxt = MemoryContextSwitchTo(resultcxt); 535 | 536 | dblist = lappend(dblist, pstrdup(NameStr(pgdatabase->datname))); 537 | 538 | MemoryContextSwitchTo(oldcxt); 539 | } 540 | 541 | #if (PG_VERSION_NUM >= 120000) 542 | table_endscan(scan); 543 | table_close(rel, AccessShareLock); 544 | #else 545 | heap_endscan(scan); 546 | heap_close(rel, AccessShareLock); 547 | #endif 548 | 549 | CommitTransactionCommand(); 550 | 551 | return dblist; 552 | } 553 | 554 | -------------------------------------------------------------------------------- /pgtt_rsl.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pgtt.c 4 | * Add support to Oracle-style Global Temporary Table in PostgreSQL. 5 | * You need PostgreSQL >= 9.4 as this extension use UNLOGGED tables 6 | * and a background worker. 7 | * 8 | * Author: Gilles Darold 9 | * Licence: PostgreSQL 10 | * Copyright (c) 2018-2022, Gilles Darold, 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | #include "postgres.h" 15 | #include 16 | #include "funcapi.h" 17 | #include "tcop/utility.h" 18 | #include "libpq/pqformat.h" 19 | #include "miscadmin.h" 20 | #include "access/parallel.h" 21 | #include "catalog/catalog.h" 22 | #include "catalog/pg_authid.h" 23 | #include "catalog/pg_class.h" 24 | #include "catalog/indexing.h" 25 | #include "catalog/pg_namespace.h" 26 | #include "catalog/namespace.h" 27 | #include "catalog/pg_type.h" 28 | #include "catalog/pg_operator.h" 29 | #include "utils/formatting.h" 30 | #include "utils/fmgroids.h" 31 | #include "utils/syscache.h" 32 | #include "nodes/pg_list.h" 33 | #include "nodes/makefuncs.h" 34 | #include "commands/tablecmds.h" 35 | #include "access/htup_details.h" 36 | #include "executor/spi.h" 37 | #include "storage/proc.h" 38 | #include "utils/builtins.h" 39 | #include "catalog/pg_collation.h" 40 | #include "utils/inval.h" 41 | #include "catalog/partition.h" 42 | #include "catalog/index.h" 43 | #include "storage/lmgr.h" 44 | #include "parser/analyze.h" 45 | 46 | /* for regexp search */ 47 | #include "regex/regexport.h" 48 | 49 | #if (PG_VERSION_NUM >= 120000) 50 | #include "access/genam.h" 51 | #include "access/heapam.h" 52 | #include "catalog/pg_class.h" 53 | #endif 54 | 55 | #if PG_VERSION_NUM >= 100000 56 | #include "utils/regproc.h" 57 | #endif 58 | 59 | #if PG_VERSION_NUM < 90500 60 | #error Minimum version of PostgreSQL required is 9.5 61 | #endif 62 | 63 | #define PGTT_NAMESPACE_NAME "pgtt_schema" 64 | #define CATALOG_GLOBAL_TEMP_REL "pgtt_global_temp" 65 | #define Anum_pgtt_relid 1 66 | #define Anum_pgtt_viewid 2 67 | #define Anum_pgtt_datcrea 3 68 | #define Anum_pgtt_preserved 4 69 | 70 | #if PG_VERSION_NUM >= 140000 71 | #define STMT_OBJTYPE(stmt) stmt->objtype 72 | #else 73 | #define STMT_OBJTYPE(stmt) stmt->relkind 74 | #endif 75 | 76 | PG_MODULE_MAGIC; 77 | 78 | #define NOT_IN_PARALLEL_WORKER (ParallelWorkerNumber < 0) 79 | 80 | PGDLLEXPORT Datum get_session_id(PG_FUNCTION_ARGS); 81 | PG_FUNCTION_INFO_V1(get_session_id); 82 | PGDLLEXPORT Datum generate_lsid(PG_FUNCTION_ARGS); 83 | PG_FUNCTION_INFO_V1(generate_lsid); 84 | 85 | PGDLLEXPORT Datum get_session_start_time(PG_FUNCTION_ARGS); 86 | PG_FUNCTION_INFO_V1(get_session_start_time); 87 | 88 | PGDLLEXPORT Datum get_session_pid(PG_FUNCTION_ARGS); 89 | PG_FUNCTION_INFO_V1(get_session_pid); 90 | 91 | PG_FUNCTION_INFO_V1(lsid_in); 92 | PG_FUNCTION_INFO_V1(lsid_out); 93 | PG_FUNCTION_INFO_V1(lsid_recv); 94 | PG_FUNCTION_INFO_V1(lsid_send); 95 | 96 | typedef struct Lsid { 97 | int backend_start_time; 98 | int backend_pid; 99 | } Lsid; 100 | 101 | struct DropRelationCallbackState 102 | { 103 | /* These fields are set by RemoveRelations: */ 104 | char expected_relkind; 105 | LOCKMODE heap_lockmode; 106 | /* These fields are state to track which subsidiary locks are held: */ 107 | Oid heapOid; 108 | Oid partParentOid; 109 | /* These fields are passed back by RangeVarCallbackForDropRelation: */ 110 | char actual_relkind; 111 | char actual_relpersistence; 112 | }; 113 | 114 | static void RangeVarCallbackForDropRelation(const RangeVar *rel, Oid relOid, 115 | Oid oldRelOid, void *arg); 116 | static bool is_gtt_registered(Oid relid); 117 | 118 | /* Regular expression search */ 119 | #define CREATE_GLOBAL_REGEXP "^\\s*CREATE\\s+(?:\\/\\*\\s*)?GLOBAL(?:\\s*\\*\\/)?" 120 | #define CREATE_WITH_FK_REGEXP "\\s*FOREIGN\\s+KEY" 121 | 122 | /* Default schema where GTT objects are saved */ 123 | #define PGTT_NSPNAME "pgtt_schema" 124 | 125 | /* Define ProcessUtility hook proto/parameters following the PostgreSQL version */ 126 | #if PG_VERSION_NUM >= 140000 127 | #define GTT_PROCESSUTILITY_PROTO PlannedStmt *pstmt, const char *queryString, \ 128 | bool readOnlyTree, \ 129 | ProcessUtilityContext context, ParamListInfo params, \ 130 | QueryEnvironment *queryEnv, DestReceiver *dest, \ 131 | QueryCompletion *qc 132 | #define GTT_PROCESSUTILITY_ARGS pstmt, queryString, readOnlyTree, context, params, queryEnv, dest, qc 133 | #else 134 | #if PG_VERSION_NUM >= 130000 135 | #define GTT_PROCESSUTILITY_PROTO PlannedStmt *pstmt, const char *queryString, \ 136 | ProcessUtilityContext context, ParamListInfo params, \ 137 | QueryEnvironment *queryEnv, DestReceiver *dest, \ 138 | QueryCompletion *qc 139 | #define GTT_PROCESSUTILITY_ARGS pstmt, queryString, context, params, queryEnv, dest, qc 140 | #else 141 | #if PG_VERSION_NUM >= 100000 142 | #define GTT_PROCESSUTILITY_PROTO PlannedStmt *pstmt, const char *queryString, \ 143 | ProcessUtilityContext context, ParamListInfo params, \ 144 | QueryEnvironment *queryEnv, DestReceiver *dest, \ 145 | char *completionTag 146 | #define GTT_PROCESSUTILITY_ARGS pstmt, queryString, context, params, queryEnv, dest, completionTag 147 | #elif PG_VERSION_NUM >= 90300 148 | #define GTT_PROCESSUTILITY_PROTO Node *parsetree, const char *queryString, \ 149 | ProcessUtilityContext context, ParamListInfo params, \ 150 | DestReceiver *dest, char *completionTag 151 | #define GTT_PROCESSUTILITY_ARGS parsetree, queryString, context, params, dest, completionTag 152 | #else 153 | #define GTT_PROCESSUTILITY_PROTO Node *parsetree, const char *queryString, \ 154 | ParamListInfo params, bool isTopLevel, \ 155 | DestReceiver *dest, char *completionTag 156 | #define GTT_PROCESSUTILITY_ARGS parsetree, queryString, params, isTopLevel, dest, completionTag 157 | #endif 158 | #endif 159 | #endif 160 | 161 | /* Saved hook values in case of unload */ 162 | static ProcessUtility_hook_type prev_ProcessUtility = NULL; 163 | static post_parse_analyze_hook_type prev_post_parse_analyze_hook = NULL; 164 | 165 | /* Hook to intercept CREATE GLOBAL TEMPORARY TABLE query */ 166 | static void gtt_ProcessUtility(GTT_PROCESSUTILITY_PROTO); 167 | static bool gtt_check_command(GTT_PROCESSUTILITY_PROTO); 168 | 169 | #if PG_VERSION_NUM >= 140000 170 | static void gtt_post_parse_analyze(ParseState *pstate, Query *query, struct JumbleState * jstate); 171 | #else 172 | static void gtt_post_parse_analyze(ParseState *pstate, Query *query); 173 | #endif 174 | 175 | /* Function declarations */ 176 | 177 | void _PG_init(void); 178 | void _PG_fini(void); 179 | 180 | int strpos(char *hay, char *needle, int offset); 181 | static void gtt_override_create_table(GTT_PROCESSUTILITY_PROTO); 182 | static void gtt_override_create_table_as(GTT_PROCESSUTILITY_PROTO); 183 | 184 | /* 185 | * Module load callback 186 | */ 187 | void 188 | _PG_init(void) 189 | { 190 | /* do not execute anything in parallel processes */ 191 | if (ParallelWorkerNumber >= 0) 192 | return; 193 | 194 | /* 195 | * In order to create our shared memory area, we have to be loaded via 196 | * shared_preload_libraries. If not, fall out without hooking into any of 197 | * the main system. (We don't throw error here because it seems useful to 198 | * allow the gtt_* functions to be created even when the module isn't active. 199 | * The functions must protect themselves against being called then, however.) 200 | */ 201 | if (!process_shared_preload_libraries_in_progress) 202 | return; 203 | 204 | /* 205 | * Define (or redefine) custom GUC variables. 206 | * No custom GUC variable at this time 207 | */ 208 | 209 | /* 210 | * Install hooks. 211 | */ 212 | 213 | /* Disable hook for the moment */ 214 | prev_ProcessUtility = ProcessUtility_hook; 215 | ProcessUtility_hook = gtt_ProcessUtility; 216 | prev_post_parse_analyze_hook = post_parse_analyze_hook; 217 | post_parse_analyze_hook = gtt_post_parse_analyze; 218 | } 219 | 220 | /* 221 | * Module unload callback 222 | */ 223 | void 224 | _PG_fini(void) 225 | { 226 | /* Uninstall hooks. */ 227 | /* 228 | ProcessUtility_hook = prev_ProcessUtility; 229 | */ 230 | } 231 | 232 | static void 233 | gtt_ProcessUtility(GTT_PROCESSUTILITY_PROTO) 234 | { 235 | //bool isTopLevel = (context == PROCESS_UTILITY_TOPLEVEL); 236 | 237 | /* only in the top process */ 238 | if (ParallelWorkerNumber == -1) 239 | { 240 | /* 241 | * Check if we have a CREATE GLOBAL TEMPORARY TABLE 242 | * in this case do more work than the simple table 243 | * creation see SQL file in sql/ subdirectory. 244 | * 245 | * If the current query use a GTT that is not already 246 | * created create it. 247 | */ 248 | if (gtt_check_command(GTT_PROCESSUTILITY_ARGS)) 249 | { 250 | elog(DEBUG1, "Work on GTT from Utility Hook done, get out of UtilityHook immediately."); 251 | return; 252 | } 253 | } 254 | 255 | elog(DEBUG1, "GTT DEBUG: restore ProcessUtility"); 256 | 257 | /* Excecute the utility command, we are not concerned */ 258 | PG_TRY(); 259 | { 260 | if (prev_ProcessUtility) 261 | prev_ProcessUtility(GTT_PROCESSUTILITY_ARGS); 262 | else 263 | standard_ProcessUtility(GTT_PROCESSUTILITY_ARGS); 264 | } 265 | PG_CATCH(); 266 | { 267 | PG_RE_THROW(); 268 | } 269 | PG_END_TRY(); 270 | } 271 | 272 | /* 273 | * Before acquiring a table lock, check whether we have sufficient rights. 274 | * In the case of DROP INDEX, also try to lock the table before the index. 275 | * Also, if the table to be dropped is a partition, we try to lock the parent 276 | * first. 277 | */ 278 | static void 279 | RangeVarCallbackForDropRelation(const RangeVar *rel, Oid relOid, Oid oldRelOid, 280 | void *arg) 281 | { 282 | // do nothing 283 | return; 284 | } 285 | 286 | /* 287 | * Look at utility command 288 | */ 289 | static bool 290 | gtt_check_command(GTT_PROCESSUTILITY_PROTO) 291 | { 292 | bool preserved = true; 293 | bool work_done = false; 294 | Oid schemaOid; 295 | char *name = NULL; 296 | #if PG_VERSION_NUM >= 100000 297 | Node *parsetree = pstmt->utilityStmt; 298 | #endif 299 | 300 | Assert(queryString != NULL); 301 | Assert(parsetree != NULL); 302 | 303 | elog(DEBUG1, "GTT DEBUG: processUtility query %s", queryString); 304 | 305 | /* 306 | * Check that the pgtt extension is available in this database by looking 307 | * for the pgtt schema otherwise get out of here we have nothing to do. 308 | */ 309 | schemaOid = get_namespace_oid(PGTT_NSPNAME, true); 310 | if (!OidIsValid(schemaOid)) 311 | return work_done; 312 | 313 | /* Intercept CREATE / DROP TABLE statements */ 314 | switch (nodeTag(parsetree)) 315 | { 316 | case T_CreateStmt: 317 | { 318 | /* CREATE TABLE statement */ 319 | CreateStmt *stmt = (CreateStmt *)parsetree; 320 | bool regexec_result; 321 | 322 | name = stmt->relation->relname; 323 | 324 | /* 325 | * Be sure to have GLOBAL TEMPORARY definition but RELPERSISTENCE_UNLOGGED 326 | * might be more appropriate. Actually parser should translate GLOBAL TEMPORARY 327 | * into persistant UNLOGGED table. 328 | */ 329 | if (stmt->relation->relpersistence != RELPERSISTENCE_TEMP) 330 | break; 331 | 332 | /* 333 | * We only take care here of statements with the GLOBAL keyword 334 | * even if it is deprecated and generate a warning. 335 | */ 336 | regexec_result = RE_compile_and_execute( 337 | cstring_to_text(CREATE_GLOBAL_REGEXP), 338 | VARDATA_ANY(cstring_to_text((char *) queryString)), 339 | VARSIZE_ANY_EXHDR(cstring_to_text((char *) queryString)), 340 | REG_ADVANCED | REG_ICASE | REG_NEWLINE, 341 | DEFAULT_COLLATION_OID, 342 | 0, NULL); 343 | 344 | if (!regexec_result) 345 | break; 346 | 347 | /* Check if there is foreign key defined in the statement */ 348 | regexec_result = RE_compile_and_execute( 349 | cstring_to_text(CREATE_WITH_FK_REGEXP), 350 | VARDATA_ANY(cstring_to_text((char *) queryString)), 351 | VARSIZE_ANY_EXHDR(cstring_to_text((char *) queryString)), 352 | REG_ADVANCED | REG_ICASE | REG_NEWLINE, 353 | DEFAULT_COLLATION_OID, 354 | 0, NULL); 355 | if (regexec_result) 356 | ereport(ERROR, 357 | (errcode(ERRCODE_INVALID_TABLE_DEFINITION), 358 | errmsg("attempt to create referential integrity constraint on global temporary table"))); 359 | 360 | #if (PG_VERSION_NUM >= 100000) 361 | /* 362 | * We do not allow partitioning on GTT, not that PostgreSQL can 363 | * not do it but because we want to mimic the Oracle or other 364 | * RDBMS behavior. 365 | */ 366 | if (stmt->partspec != NULL) 367 | elog(ERROR, "Global Temporary Table do not support partitioning."); 368 | #endif 369 | 370 | /* 371 | * What to do at commit time for global temporary relations 372 | * default is ON COMMIT PRESERVE ROWS (do nothing) 373 | */ 374 | if (stmt->oncommit == ONCOMMIT_DELETE_ROWS) 375 | preserved = false; 376 | 377 | /* 378 | * Case of ON COMMIT DROP and GLOBAL TEMPORARY might not be 379 | * allowed, this is the same as using a normal temporary table 380 | * inside a transaction. Here the table should be dropped after 381 | * commit so it will not survive a transaction. 382 | * Throw an error to prevent the use of this clause. 383 | */ 384 | if (stmt->oncommit == ONCOMMIT_DROP) 385 | ereport(ERROR, 386 | (errmsg("use of ON COMMIT DROP with GLOBAL TEMPORARY is not allowed"), 387 | errhint("Create a local temporary table inside a transaction instead, this is the default behavior."))); 388 | 389 | elog(DEBUG1, "Create table %s, rows persistance: %d, GLOBAL at position: %d", 390 | name, preserved, 391 | strpos(asc_toupper(queryString, strlen(queryString)), "GLOBAL", 0)); 392 | 393 | /* Create the Global Temporary Table with all associated object */ 394 | gtt_override_create_table(GTT_PROCESSUTILITY_ARGS); 395 | 396 | work_done = true; 397 | break; 398 | } 399 | 400 | case T_CreateTableAsStmt: 401 | { 402 | /* CREATE TABLE AS statement */ 403 | CreateTableAsStmt *stmt = (CreateTableAsStmt *)parsetree; 404 | 405 | bool regexec_result; 406 | 407 | name = stmt->into->rel->relname; 408 | 409 | /* 410 | * CREATE TABLE AS is similar as SELECT INTO, 411 | * so avoid going further in this last case. 412 | */ 413 | if (stmt->is_select_into) 414 | break; 415 | 416 | /* do not proceed OBJECT_MATVIEW */ 417 | if (STMT_OBJTYPE(stmt) != OBJECT_TABLE) 418 | break; 419 | 420 | /* 421 | * Be sure to have CREATE TEMPORARY TABLE definition 422 | */ 423 | if (stmt->into->rel->relpersistence != RELPERSISTENCE_TEMP) 424 | break; 425 | 426 | /* 427 | * We only take care here of statements with the GLOBAL keyword 428 | * even if it is deprecated and generate a warning. 429 | */ 430 | regexec_result = RE_compile_and_execute( 431 | cstring_to_text(CREATE_GLOBAL_REGEXP), 432 | VARDATA_ANY(cstring_to_text((char *) queryString)), 433 | VARSIZE_ANY_EXHDR(cstring_to_text((char *) queryString)), 434 | REG_ADVANCED | REG_ICASE | REG_NEWLINE, 435 | DEFAULT_COLLATION_OID, 436 | 0, NULL); 437 | 438 | if (!regexec_result) 439 | break; 440 | 441 | /* 442 | * What to do at commit time for global temporary relations 443 | * default is ON COMMIT PRESERVE ROWS (do nothing) 444 | */ 445 | if (stmt->into->onCommit == ONCOMMIT_DELETE_ROWS) 446 | preserved = false; 447 | 448 | 449 | /* 450 | * Case of ON COMMIT DROP and GLOBAL TEMPORARY might not be 451 | * allowed, this is the same as using a normal temporary table 452 | * inside a transaction. Here the table should be dropped after 453 | * commit so it will not survive a transaction. 454 | * Throw an error to prevent the use of this clause. 455 | */ 456 | if (stmt->into->onCommit == ONCOMMIT_DROP) 457 | ereport(ERROR, 458 | (errmsg("use of ON COMMIT DROP with GLOBAL TEMPORARY is not allowed"), 459 | errhint("Create a local temporary table inside a transaction instead, this is the default behavior."))); 460 | 461 | elog(DEBUG1, "Create table %s, rows persistance: %d, GLOBAL at position: %d", 462 | name, preserved, 463 | strpos(asc_toupper(queryString, strlen(queryString)), "GLOBAL", 0)); 464 | 465 | /* Create the Global Temporary Table with all associated object */ 466 | gtt_override_create_table_as(GTT_PROCESSUTILITY_ARGS); 467 | 468 | work_done = true; 469 | break; 470 | } 471 | 472 | case T_DropStmt: 473 | { 474 | /* 475 | * we don't do nothing here, it is too late to detect 476 | * that the table to be dropped have been changed into 477 | * a view. This is done at parse analysis level. 478 | */ 479 | break; 480 | } 481 | 482 | default: 483 | break; 484 | } 485 | 486 | return work_done; 487 | } 488 | 489 | int 490 | strpos(char *hay, char *needle, int offset) 491 | { 492 | char *haystack; 493 | char *p; 494 | 495 | haystack = (char *) malloc(strlen(hay)); 496 | if (haystack == NULL) 497 | { 498 | fprintf(stderr, _("out of memory\n")); 499 | exit(EXIT_FAILURE); 500 | return -1; 501 | } 502 | memset(haystack, 0, strlen(hay)); 503 | 504 | strncpy(haystack, hay+offset, strlen(hay)-offset); 505 | p = strstr(haystack, needle); 506 | if (p) 507 | return p - haystack+offset; 508 | 509 | return -1; 510 | } 511 | 512 | /* 513 | * Create the Global Temporary Table with all associated objects just 514 | * like PLPGSQL function pgtt_create_table(). 515 | * 516 | * The processus followed by the extension to emulate the Oracle-style 517 | * Global Temporary Table is the following: 518 | * 519 | * 1) create an unlogged table of the same name but prefixed with 'pgtt_' 520 | * with the "hidden" column for a GTT (pgtt_sessid). 521 | * The table is stored in extension schema pgtt_schema and the users 522 | * must not access to this table directly. They have to use the view 523 | * instead. The pgtt_sessid column has default to pg_backend_pid(). 524 | * 2) grant SELECT,INSERT,UPDATE,DELETE on the table to PUBLIC. 525 | * 3) activate RLS on the table and create two RLS policies to hide rows 526 | * to other sessions or transactions when required. 527 | * 4) force RLS to be active for the owner of the table. 528 | * 5) create an updatable view using the original table name with a 529 | * a WHERE clause to hide the "hidden" column of the table. 530 | * 6) set owner of the view to current_user which might be a superuser, 531 | * grants to other users are the responsability of the administrator. 532 | * 7) insert the relation between the gtt and the view in the catalog 533 | * table pgtt_global_temp. 534 | * 535 | * The gtt_bgworker is responsible to remove all rows that are no more 536 | * visible to any session or transaction. 537 | */ 538 | static void 539 | gtt_override_create_table(GTT_PROCESSUTILITY_PROTO) 540 | { 541 | bool need_priv_escalation = !superuser(); /* we might be a SU */ 542 | Oid save_userid; 543 | int save_sec_context; 544 | int pos, end; 545 | char *newQueryString = NULL; 546 | bool preserved = true; 547 | ListCell *elements; 548 | char *colnames = NULL; 549 | int connected = 0; 550 | int finished = 0; 551 | int result = 0; 552 | Oid oidRel; 553 | Oid oidView; 554 | bool isnull; 555 | #if PG_VERSION_NUM >= 100000 556 | Node *parsetree = pstmt->utilityStmt; 557 | #endif 558 | /*The CREATE TABLE statement */ 559 | CreateStmt *stmt = (CreateStmt *)parsetree; 560 | 561 | /* Compute a string with the list of column names */ 562 | foreach(elements, stmt->tableElts) 563 | { 564 | Node *element = lfirst(elements); 565 | 566 | switch (nodeTag(element)) 567 | { 568 | case T_ColumnDef: 569 | if (colnames == NULL) 570 | colnames = ((ColumnDef *) element)->colname; 571 | else 572 | colnames = psprintf("%s,%s", colnames, ((ColumnDef *) element)->colname); 573 | break; 574 | default: 575 | break; 576 | } 577 | } 578 | 579 | elog(DEBUG1, "GTT DEBUG: Execute CREATE TABLE + RLS + VIEW grant"); 580 | 581 | /* The Global Temporary Table objects must be created as SU */ 582 | if (need_priv_escalation) 583 | { 584 | /* Get current user's Oid and security context */ 585 | GetUserIdAndSecContext(&save_userid, &save_sec_context); 586 | /* Become superuser */ 587 | SetUserIdAndSecContext(BOOTSTRAP_SUPERUSERID, save_sec_context 588 | | SECURITY_LOCAL_USERID_CHANGE 589 | | SECURITY_RESTRICTED_OPERATION); 590 | } 591 | 592 | /* 593 | * What to do at commit time for global temporary relations 594 | * default is ON COMMIT PRESERVE ROWS (do nothing) 595 | */ 596 | if (stmt->oncommit == ONCOMMIT_DELETE_ROWS) 597 | preserved = false; 598 | stmt->oncommit = ONCOMMIT_NOOP; 599 | 600 | /* Connect to the current database */ 601 | connected = SPI_connect(); 602 | if (connected != SPI_OK_CONNECT) 603 | ereport(ERROR, (errmsg("could not connect to SPI manager"))); 604 | 605 | /* Set DDL to create the unlogged table */ 606 | pos = strpos(asc_toupper(queryString, strlen(queryString)), asc_toupper(stmt->relation->relname, strlen(stmt->relation->relname)), 0) + strlen(stmt->relation->relname); 607 | newQueryString = psprintf("CREATE UNLOGGED TABLE pgtt_schema.%s %s", stmt->relation->relname, queryString+pos); 608 | end = strpos(asc_toupper(newQueryString, strlen(newQueryString)), asc_toupper("ON COMMIT", 9), 0); 609 | if (end > 0) 610 | newQueryString[end-1] = '\0'; 611 | result = SPI_exec(newQueryString, 0); 612 | if (result < 0) 613 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 614 | 615 | /* Add pgtt_sessid column */ 616 | newQueryString = psprintf("ALTER TABLE pgtt_schema.%s ADD COLUMN pgtt_sessid lsid DEFAULT get_session_id()", stmt->relation->relname); 617 | result = SPI_exec(newQueryString, 0); 618 | if (result < 0) 619 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 620 | 621 | /* Get OID of the GTT table */ 622 | newQueryString = psprintf("SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = '%s' AND n.nspname = 'pgtt_schema'", stmt->relation->relname); 623 | result = SPI_exec(newQueryString, 0); 624 | if (result != SPI_OK_SELECT) 625 | 626 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 627 | if (SPI_processed != 1) 628 | ereport(ERROR, (errmsg("query must return a single Oid: \"%s\"", newQueryString))); 629 | 630 | oidRel = DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0], 631 | SPI_tuptable->tupdesc, 632 | 1, &isnull)); 633 | if (isnull) 634 | ereport(ERROR, (errmsg("query must not return NULL: \"%s\"", newQueryString))); 635 | 636 | /* Rename the table with its oid */ 637 | newQueryString = psprintf("ALTER TABLE pgtt_schema.%s RENAME TO pgtt_%d", stmt->relation->relname, oidRel); 638 | result = SPI_exec(newQueryString, 0); 639 | if (result < 0) 640 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 641 | 642 | /* Create an index on pgtt_sessid column */ 643 | newQueryString = psprintf("CREATE INDEX ON pgtt_schema.pgtt_%d (pgtt_sessid)", oidRel); 644 | result = SPI_exec(newQueryString, 0); 645 | if (result < 0) 646 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 647 | 648 | /* Allow all on the global temporary table except truncate and drop to everyone */ 649 | newQueryString = psprintf("GRANT SELECT,INSERT,UPDATE,DELETE ON pgtt_schema.pgtt_%d TO PUBLIC", oidRel); 650 | result = SPI_exec(newQueryString, 0); 651 | if (result < 0) 652 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 653 | 654 | /* Activate RLS to set policy based on session */ 655 | newQueryString = psprintf("ALTER TABLE pgtt_schema.pgtt_%d ENABLE ROW LEVEL SECURITY", oidRel); 656 | result = SPI_exec(newQueryString, 0); 657 | if (result < 0) 658 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 659 | 660 | if (preserved) 661 | /* 662 | * Create the policy that must be applied on the table 663 | * to show only rows where pgtt_sessid is the same as 664 | * current pid. 665 | */ 666 | newQueryString = psprintf("CREATE POLICY pgtt_rls_session ON pgtt_schema.pgtt_%d USING (pgtt_sessid = get_session_id()) WITH CHECK (true)", oidRel); 667 | else 668 | /* 669 | * Create the policy that must be applied on the table 670 | * to show only rows where pgtt_sessid is the same as 671 | * current pid and rows that have been created in the 672 | * current transaction. 673 | */ 674 | newQueryString = psprintf("CREATE POLICY pgtt_rls_transaction ON pgtt_schema.pgtt_%d USING (pgtt_sessid = get_session_id() AND xmin::text >= txid_current()::text) WITH CHECK (true)", oidRel); 675 | 676 | result = SPI_exec(newQueryString, 0); 677 | if (result < 0) 678 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 679 | 680 | /* Force policy to be active for the owner of the table */ 681 | newQueryString = psprintf("ALTER TABLE pgtt_schema.pgtt_%d FORCE ROW LEVEL SECURITY", oidRel); 682 | result = SPI_exec(newQueryString, 0); 683 | if (result < 0) 684 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 685 | 686 | /* Create the view */ 687 | if (preserved) 688 | newQueryString = psprintf("CREATE VIEW %s%s%s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%d WHERE pgtt_sessid=get_session_id()", (stmt->relation->schemaname) ? stmt->relation->schemaname : "", (stmt->relation->schemaname) ? "." : "", stmt->relation->relname, colnames, oidRel); 689 | else 690 | newQueryString = psprintf("CREATE VIEW %s%s%s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%d WHERE pgtt_sessid=get_session_id() AND xmin::text >= txid_current()::text", (stmt->relation->schemaname) ? stmt->relation->schemaname : "", (stmt->relation->schemaname) ? "." : "", stmt->relation->relname, colnames, oidRel); 691 | result = SPI_exec(newQueryString, 0); 692 | if (result < 0) 693 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 694 | 695 | /* Set owner of the view to current user, not the function definer (superuser)*/ 696 | newQueryString = psprintf("ALTER VIEW %s%s%s OWNER TO %s", (stmt->relation->schemaname) ? stmt->relation->schemaname : "", (stmt->relation->schemaname) ? "." : "", stmt->relation->relname, GetUserNameFromId(GetSessionUserId(), false)); 697 | result = SPI_exec(newQueryString, 0); 698 | if (result < 0) 699 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 700 | 701 | /* Get OID of the corresponding view */ 702 | newQueryString = psprintf("SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = '%s' AND n.nspname = %s", stmt->relation->relname, (stmt->relation->schemaname) ? quote_literal_cstr(stmt->relation->schemaname) : "current_schema()"); 703 | result = SPI_exec(newQueryString, 0); 704 | if (result != SPI_OK_SELECT) 705 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 706 | if (SPI_processed != 1) 707 | ereport(ERROR, (errmsg("query must return a single Oid: \"%s\"", newQueryString))); 708 | 709 | oidView = DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0], 710 | SPI_tuptable->tupdesc, 711 | 1, &isnull)); 712 | if (isnull) 713 | ereport(ERROR, (errmsg("query must not return NULL: \"%s\"", newQueryString))); 714 | 715 | /* Register the link between the view and the unlogged table */ 716 | newQueryString = psprintf("INSERT INTO pgtt_schema.pgtt_global_temp (relid, viewid, datcrea, preserved) VALUES (%d, %d, now(), '%d')", oidRel, oidView, preserved); 717 | result = SPI_exec(newQueryString, 0); 718 | if (result < 0) 719 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 720 | 721 | finished = SPI_finish(); 722 | if (finished != SPI_OK_FINISH) 723 | { 724 | ereport(ERROR, (errmsg("could not disconnect from SPI manager"))); 725 | } 726 | 727 | /* Restore user's privileges */ 728 | if (need_priv_escalation) 729 | SetUserIdAndSecContext(save_userid, save_sec_context); 730 | } 731 | 732 | static void 733 | gtt_override_create_table_as(GTT_PROCESSUTILITY_PROTO) 734 | { 735 | bool need_priv_escalation = !superuser(); /* we might be a SU */ 736 | Oid save_userid; 737 | int save_sec_context; 738 | int pos; 739 | char *newQueryString = NULL; 740 | bool preserved = true; 741 | char *colnames = NULL; 742 | int connected = 0; 743 | int finished = 0; 744 | int result = 0; 745 | Oid oidRel; 746 | Oid oidView; 747 | bool isnull; 748 | Datum final_sql; 749 | #if PG_VERSION_NUM >= 100000 750 | Node *parsetree = pstmt->utilityStmt; 751 | #endif 752 | /*The CREATE TABLE AS statement */ 753 | CreateTableAsStmt *stmt = (CreateTableAsStmt *)parsetree; 754 | 755 | /* replace temporary state from the table to unlogged table */ 756 | stmt->into->rel->relpersistence = RELPERSISTENCE_UNLOGGED; 757 | /* Do not copy data in the unlogged table */ 758 | stmt->into->skipData = true; 759 | 760 | elog(DEBUG1, "GTT DEBUG: Execute CREATE TABLE AS + RLS + VIEW grant"); 761 | 762 | /* The Global Temporary Table objects must be created as SU */ 763 | if (need_priv_escalation) 764 | { 765 | /* Get current user's Oid and security context */ 766 | GetUserIdAndSecContext(&save_userid, &save_sec_context); 767 | /* Become superuser */ 768 | SetUserIdAndSecContext(BOOTSTRAP_SUPERUSERID, save_sec_context 769 | | SECURITY_LOCAL_USERID_CHANGE 770 | | SECURITY_RESTRICTED_OPERATION); 771 | } 772 | 773 | /* 774 | * What to do at commit time for global temporary relations 775 | * default is ON COMMIT PRESERVE ROWS (do nothing) 776 | */ 777 | if (stmt->into->onCommit == ONCOMMIT_DELETE_ROWS) 778 | preserved = false; 779 | stmt->into->onCommit = ONCOMMIT_NOOP; 780 | 781 | /* Connect to the current database */ 782 | connected = SPI_connect(); 783 | if (connected != SPI_OK_CONNECT) 784 | { 785 | ereport(ERROR, (errmsg("could not connect to SPI manager"))); 786 | } 787 | 788 | /* Set DDL to create the unlogged table */ 789 | final_sql = CStringGetTextDatum(queryString); 790 | final_sql = DirectFunctionCall4Coll(textregexreplace, 791 | C_COLLATION_OID, 792 | final_sql, 793 | CStringGetTextDatum("ON COMMIT.*ROWS AS "), 794 | CStringGetTextDatum("AS "), 795 | CStringGetTextDatum("i")); 796 | newQueryString = TextDatumGetCString(final_sql); 797 | 798 | pos = strpos(asc_toupper(newQueryString, strlen(newQueryString)), asc_toupper(stmt->into->rel->relname, strlen(stmt->into->rel->relname)), 0) + strlen(stmt->into->rel->relname); 799 | newQueryString = psprintf("CREATE UNLOGGED TABLE pgtt_schema.%s %s", stmt->into->rel->relname, newQueryString+pos); 800 | result = SPI_exec(newQueryString, 0); 801 | if (result < 0) 802 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 803 | 804 | /* Add pgtt_sessid column */ 805 | newQueryString = psprintf("ALTER TABLE pgtt_schema.%s ADD COLUMN pgtt_sessid lsid DEFAULT get_session_id()", stmt->into->rel->relname); 806 | result = SPI_exec(newQueryString, 0); 807 | if (result < 0) 808 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 809 | 810 | /* Get OID of the GTT table */ 811 | newQueryString = psprintf("SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = '%s' AND n.nspname = 'pgtt_schema'", stmt->into->rel->relname); 812 | result = SPI_exec(newQueryString, 0); 813 | if (result != SPI_OK_SELECT) 814 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 815 | 816 | if (SPI_processed != 1) 817 | ereport(ERROR, (errmsg("query must return a single Oid: \"%s\"", newQueryString))); 818 | 819 | oidRel = DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0], 820 | SPI_tuptable->tupdesc, 821 | 1, &isnull)); 822 | if (isnull) 823 | ereport(ERROR, (errmsg("query must not return NULL: \"%s\"", newQueryString))); 824 | 825 | /* Get column list of the newly created table */ 826 | newQueryString = psprintf("SELECT string_agg(attname, ',') FROM pg_attribute WHERE attrelid = %d AND attnum > 0 AND attname != 'pgtt_sessid'", 827 | oidRel); 828 | 829 | result = SPI_exec(newQueryString, 0); 830 | if (result != SPI_OK_SELECT && SPI_processed != 1) 831 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 832 | 833 | colnames = SPI_getvalue(SPI_tuptable->vals[0], SPI_tuptable->tupdesc, 1); 834 | if (colnames == NULL) 835 | ereport(ERROR, (errmsg("no column returned using query: \"%s\"", newQueryString))); 836 | 837 | /* Rename the table with its oid */ 838 | newQueryString = psprintf("ALTER TABLE pgtt_schema.%s RENAME TO pgtt_%d", stmt->into->rel->relname, oidRel); 839 | result = SPI_exec(newQueryString, 0); 840 | if (result < 0) 841 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 842 | 843 | /* Create an index on pgtt_sessid column */ 844 | newQueryString = psprintf("CREATE INDEX ON pgtt_schema.pgtt_%d (pgtt_sessid)", oidRel); 845 | result = SPI_exec(newQueryString, 0); 846 | if (result < 0) 847 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 848 | 849 | /* Allow all on the global temporary table except truncate and drop to everyone */ 850 | newQueryString = psprintf("GRANT SELECT,INSERT,UPDATE,DELETE ON pgtt_schema.pgtt_%d TO PUBLIC", oidRel); 851 | result = SPI_exec(newQueryString, 0); 852 | if (result < 0) 853 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 854 | 855 | /* Activate RLS to set policy based on session */ 856 | newQueryString = psprintf("ALTER TABLE pgtt_schema.pgtt_%d ENABLE ROW LEVEL SECURITY", oidRel); 857 | result = SPI_exec(newQueryString, 0); 858 | if (result < 0) 859 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 860 | 861 | if (preserved) 862 | /* 863 | * Create the policy that must be applied on the table 864 | * to show only rows where pgtt_sessid is the same as 865 | * current pid. 866 | */ 867 | newQueryString = psprintf("CREATE POLICY pgtt_rls_session ON pgtt_schema.pgtt_%d USING (pgtt_sessid = get_session_id()) WITH CHECK (true)", oidRel); 868 | else 869 | /* 870 | * Create the policy that must be applied on the table 871 | * to show only rows where pgtt_sessid is the same as 872 | * current pid and rows that have been created in the 873 | * current transaction. 874 | */ 875 | newQueryString = psprintf("CREATE POLICY pgtt_rls_transaction ON pgtt_schema.pgtt_%d USING (pgtt_sessid = get_session_id() AND xmin::text >= txid_current()::text) WITH CHECK (true)", oidRel); 876 | 877 | result = SPI_exec(newQueryString, 0); 878 | if (result < 0) 879 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 880 | 881 | /* Force policy to be active for the owner of the table */ 882 | newQueryString = psprintf("ALTER TABLE pgtt_schema.pgtt_%d FORCE ROW LEVEL SECURITY", oidRel); 883 | result = SPI_exec(newQueryString, 0); 884 | if (result < 0) 885 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 886 | 887 | /* Create the view */ 888 | if (preserved) 889 | newQueryString = psprintf("CREATE VIEW %s%s%s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%d WHERE pgtt_sessid=get_session_id()", (stmt->into->rel->schemaname) ? stmt->into->rel->schemaname : "", (stmt->into->rel->schemaname) ? "." : "", stmt->into->rel->relname, colnames, oidRel); 890 | else 891 | newQueryString = psprintf("CREATE VIEW %s%s%s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%d WHERE pgtt_sessid=get_session_id() AND xmin::text >= txid_current()::text", (stmt->into->rel->schemaname) ? stmt->into->rel->schemaname : "", (stmt->into->rel->schemaname) ? "." : "", stmt->into->rel->relname, colnames, oidRel); 892 | result = SPI_exec(newQueryString, 0); 893 | if (result < 0) 894 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 895 | 896 | pfree(colnames); 897 | 898 | /* Set owner of the view to current user, not the function definer (superuser)*/ 899 | newQueryString = psprintf("ALTER VIEW %s%s%s OWNER TO %s", (stmt->into->rel->schemaname) ? stmt->into->rel->schemaname : "", (stmt->into->rel->schemaname) ? "." : "", stmt->into->rel->relname, GetUserNameFromId(GetSessionUserId(), false)); 900 | result = SPI_exec(newQueryString, 0); 901 | if (result < 0) 902 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 903 | 904 | /* Get OID of the corresponding view */ 905 | newQueryString = psprintf("SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = '%s' AND n.nspname = %s", stmt->into->rel->relname, (stmt->into->rel->schemaname) ? quote_literal_cstr(stmt->into->rel->schemaname) : "current_schema()"); 906 | result = SPI_exec(newQueryString, 0); 907 | if (result != SPI_OK_SELECT) 908 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 909 | if (SPI_processed != 1) 910 | ereport(ERROR, (errmsg("query must return a single Oid: \"%s\"", newQueryString))); 911 | 912 | oidView = DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0], 913 | SPI_tuptable->tupdesc, 914 | 1, &isnull)); 915 | if (isnull) 916 | ereport(ERROR, (errmsg("query must not return NULL: \"%s\"", newQueryString))); 917 | 918 | /* Register the link between the view and the unlogged table */ 919 | newQueryString = psprintf("INSERT INTO pgtt_schema.pgtt_global_temp (relid, viewid, datcrea, preserved) VALUES (%d, %d, now(), '%d')", oidRel, oidView, preserved); 920 | result = SPI_exec(newQueryString, 0); 921 | if (result < 0) 922 | ereport(ERROR, (errmsg("execution failure on query: \"%s\"", newQueryString))); 923 | 924 | finished = SPI_finish(); 925 | if (finished != SPI_OK_FINISH) 926 | { 927 | ereport(ERROR, (errmsg("could not disconnect from SPI manager"))); 928 | } 929 | 930 | /* Restore user's privileges */ 931 | if (need_priv_escalation) 932 | SetUserIdAndSecContext(save_userid, save_sec_context); 933 | } 934 | 935 | 936 | /* 937 | * Function used to generate a local session id composed 938 | * with the timestamp (epoch) and the pid of the current 939 | * backend. 940 | */ 941 | Datum 942 | get_session_id(PG_FUNCTION_ARGS) 943 | { 944 | Lsid *res; 945 | 946 | res = (Lsid *) palloc(sizeof(Lsid)); 947 | res->backend_start_time = (int) MyStartTime; 948 | res->backend_pid = MyProcPid; 949 | 950 | PG_RETURN_POINTER(res); 951 | } 952 | 953 | Datum 954 | lsid_in(PG_FUNCTION_ARGS) 955 | { 956 | char *str = PG_GETARG_CSTRING(0); 957 | int backend_start_time, 958 | backend_pid; 959 | Lsid *res; 960 | 961 | if (sscanf(str, "{ %d, %d }", &backend_start_time, &backend_pid) != 2) 962 | ereport(ERROR, 963 | (errcode(ERRCODE_INVALID_TEXT_REPRESENTATION), 964 | errmsg("invalid input syntax for local session id: \"%s\"", 965 | str))); 966 | 967 | res = (Lsid *) palloc(sizeof(Lsid)); 968 | res->backend_start_time = backend_start_time; 969 | res->backend_pid = backend_pid; 970 | 971 | PG_RETURN_POINTER(res); 972 | } 973 | 974 | Datum 975 | lsid_out(PG_FUNCTION_ARGS) 976 | { 977 | Lsid *lsid = (Lsid *) PG_GETARG_POINTER(0); 978 | char *res; 979 | 980 | res = psprintf("{%d,%d}", lsid->backend_start_time, lsid->backend_pid); 981 | 982 | PG_RETURN_CSTRING(res); 983 | } 984 | 985 | Datum 986 | lsid_recv(PG_FUNCTION_ARGS) 987 | { 988 | StringInfo buf = (StringInfo) PG_GETARG_POINTER(0); 989 | Lsid *res; 990 | 991 | res = (Lsid *) palloc(sizeof(Lsid)); 992 | res->backend_start_time = pq_getmsgint(buf, sizeof(int32)); 993 | res->backend_pid = pq_getmsgint(buf, sizeof(int32)); 994 | 995 | PG_RETURN_POINTER(res); 996 | } 997 | 998 | Datum 999 | lsid_send(PG_FUNCTION_ARGS) 1000 | { 1001 | Lsid *lsid = (Lsid *) PG_GETARG_POINTER(0); 1002 | StringInfoData buf; 1003 | 1004 | pq_begintypsend(&buf); 1005 | pq_sendint(&buf, lsid->backend_start_time, 4); 1006 | pq_sendint(&buf, lsid->backend_pid, 4); 1007 | 1008 | PG_RETURN_BYTEA_P(pq_endtypsend(&buf)); 1009 | } 1010 | 1011 | /* 1012 | * Functions used to extract the backend start time 1013 | * and backend pid from lsid type. 1014 | */ 1015 | Datum 1016 | get_session_start_time(PG_FUNCTION_ARGS) 1017 | { 1018 | Lsid *lsid = (Lsid *) PG_GETARG_POINTER(0); 1019 | 1020 | PG_RETURN_INT32(lsid->backend_start_time); 1021 | } 1022 | 1023 | Datum 1024 | get_session_pid(PG_FUNCTION_ARGS) 1025 | { 1026 | Lsid *lsid = (Lsid *) PG_GETARG_POINTER(0); 1027 | 1028 | PG_RETURN_INT32(lsid->backend_pid); 1029 | } 1030 | 1031 | /* 1032 | * Given two integers representing the number of seconds since epoch of 1033 | * the backend start time and the pid number of the backenreturns a lsid 1034 | */ 1035 | Datum 1036 | generate_lsid(PG_FUNCTION_ARGS) 1037 | { 1038 | Lsid *res; 1039 | int st = Int32GetDatum((int32) PG_GETARG_INT32(0)); 1040 | int pid = Int32GetDatum((int32) PG_GETARG_INT32(1)); 1041 | 1042 | Assert(st); 1043 | Assert(pid); 1044 | 1045 | if (st <= 0 || pid <= 0) 1046 | ereport(ERROR, 1047 | ( errmsg("one of the argument is null, this is not supported"))); 1048 | 1049 | res = (Lsid *) palloc(sizeof(Lsid)); 1050 | res->backend_start_time = st; 1051 | res->backend_pid = pid; 1052 | 1053 | PG_RETURN_POINTER(res); 1054 | } 1055 | 1056 | 1057 | /* 1058 | * Operator class for defining B-tree index 1059 | */ 1060 | static int 1061 | lsid_cmp_internal(Lsid * a, Lsid * b) 1062 | { 1063 | if (a->backend_start_time < b->backend_start_time) 1064 | return -1; 1065 | if (a->backend_start_time > b->backend_start_time) 1066 | return 1; 1067 | /* 1068 | * a->backend_start_time = b->backend_start_time 1069 | * so continue the comparison on pid number 1070 | */ 1071 | if (a->backend_pid < b->backend_pid) 1072 | return -1; 1073 | if (a->backend_pid > b->backend_pid) 1074 | return 1; 1075 | 1076 | return 0; 1077 | } 1078 | 1079 | PG_FUNCTION_INFO_V1(lsid_lt); 1080 | 1081 | Datum 1082 | lsid_lt(PG_FUNCTION_ARGS) 1083 | { 1084 | Lsid *a = (Lsid *) PG_GETARG_POINTER(0); 1085 | Lsid *b = (Lsid *) PG_GETARG_POINTER(1); 1086 | 1087 | PG_RETURN_BOOL(lsid_cmp_internal(a, b) < 0); 1088 | } 1089 | 1090 | PG_FUNCTION_INFO_V1(lsid_le); 1091 | 1092 | Datum 1093 | lsid_le(PG_FUNCTION_ARGS) 1094 | { 1095 | Lsid *a = (Lsid *) PG_GETARG_POINTER(0); 1096 | Lsid *b = (Lsid *) PG_GETARG_POINTER(1); 1097 | 1098 | PG_RETURN_BOOL(lsid_cmp_internal(a, b) <= 0); 1099 | } 1100 | 1101 | PG_FUNCTION_INFO_V1(lsid_eq); 1102 | 1103 | Datum 1104 | lsid_eq(PG_FUNCTION_ARGS) 1105 | { 1106 | Lsid *a = (Lsid *) PG_GETARG_POINTER(0); 1107 | Lsid *b = (Lsid *) PG_GETARG_POINTER(1); 1108 | 1109 | PG_RETURN_BOOL(lsid_cmp_internal(a, b) == 0); 1110 | } 1111 | 1112 | PG_FUNCTION_INFO_V1(lsid_ge); 1113 | 1114 | Datum 1115 | lsid_ge(PG_FUNCTION_ARGS) 1116 | { 1117 | Lsid *a = (Lsid *) PG_GETARG_POINTER(0); 1118 | Lsid *b = (Lsid *) PG_GETARG_POINTER(1); 1119 | 1120 | PG_RETURN_BOOL(lsid_cmp_internal(a, b) >= 0); 1121 | } 1122 | 1123 | PG_FUNCTION_INFO_V1(lsid_gt); 1124 | 1125 | Datum 1126 | lsid_gt(PG_FUNCTION_ARGS) 1127 | { 1128 | Lsid *a = (Lsid *) PG_GETARG_POINTER(0); 1129 | Lsid *b = (Lsid *) PG_GETARG_POINTER(1); 1130 | 1131 | PG_RETURN_BOOL(lsid_cmp_internal(a, b) > 0); 1132 | } 1133 | 1134 | PG_FUNCTION_INFO_V1(lsid_cmp); 1135 | 1136 | Datum 1137 | lsid_cmp(PG_FUNCTION_ARGS) 1138 | { 1139 | Lsid *a = (Lsid *) PG_GETARG_POINTER(0); 1140 | Lsid *b = (Lsid *) PG_GETARG_POINTER(1); 1141 | 1142 | PG_RETURN_INT32(lsid_cmp_internal(a, b)); 1143 | } 1144 | 1145 | /* 1146 | * Post-parse-analysis hook: mark query with a queryId 1147 | */ 1148 | static void 1149 | #if PG_VERSION_NUM >= 140000 1150 | gtt_post_parse_analyze(ParseState *pstate, Query *query, struct JumbleState * jstate) 1151 | #else 1152 | gtt_post_parse_analyze(ParseState *pstate, Query *query) 1153 | #endif 1154 | { 1155 | if (query->commandType == CMD_UTILITY && IsA(query->utilityStmt, DropStmt)) 1156 | { 1157 | DropStmt *drop = (DropStmt *) query->utilityStmt; 1158 | 1159 | /* 1160 | * When a DROP TABLE is issued we verify if this is a GTT. 1161 | * If this is the case we change the object type to not have 1162 | * error on not using the right object keyword in the statement. 1163 | */ 1164 | if (drop->removeType == OBJECT_TABLE) 1165 | { 1166 | ObjectAddresses *objects; 1167 | ListCell *cell; 1168 | int nb_rel = 0; 1169 | LOCKMODE lockmode = AccessExclusiveLock; 1170 | 1171 | /* Lock and validate each relation; build a list of object addresses */ 1172 | objects = new_object_addresses(); 1173 | /* 1174 | * we are there just for relation because of the DROP TABLE 1175 | * but we want to search if it is a view instead created by 1176 | * our GTT extension. If this is really a table we will have 1177 | * an invalid oid. 1178 | */ 1179 | foreach(cell, drop->objects) 1180 | { 1181 | RangeVar *rel = makeRangeVarFromNameList((List *) lfirst(cell)); 1182 | Oid relOid; 1183 | struct DropRelationCallbackState state; 1184 | 1185 | AcceptInvalidationMessages(); 1186 | 1187 | nb_rel++; 1188 | 1189 | /* Look up the appropriate relation using namespace search. */ 1190 | state.expected_relkind = RELKIND_RELATION; 1191 | state.heap_lockmode = AccessShareLock; 1192 | /* We must initialize these fields to show that no locks are held: */ 1193 | state.heapOid = InvalidOid; 1194 | state.partParentOid = InvalidOid; 1195 | 1196 | relOid = RangeVarGetRelidExtended(rel, lockmode, RVR_MISSING_OK | RVR_SKIP_LOCKED, 1197 | RangeVarCallbackForDropRelation, 1198 | (void *) &state); 1199 | 1200 | /* Not a GTT? */ 1201 | if (!is_gtt_registered(relOid)) 1202 | continue; 1203 | 1204 | /* change the object type as we have create a view for this table */ 1205 | drop->removeType = OBJECT_VIEW; 1206 | } 1207 | /* We don't allow multiple relation drop with GTT, we will have an error */ 1208 | if (nb_rel > 1) 1209 | drop->removeType = OBJECT_TABLE; 1210 | 1211 | free_object_addresses(objects); 1212 | } 1213 | } 1214 | 1215 | /* restore hook */ 1216 | if (prev_post_parse_analyze_hook) { 1217 | #if PG_VERSION_NUM >= 140000 1218 | prev_post_parse_analyze_hook(pstate, query, jstate); 1219 | #else 1220 | prev_post_parse_analyze_hook(pstate, query); 1221 | #endif 1222 | } 1223 | } 1224 | 1225 | static bool 1226 | is_gtt_registered(Oid relid) 1227 | { 1228 | RangeVar *rv; 1229 | Relation rel; 1230 | ScanKeyData key[1]; 1231 | SysScanDesc scan; 1232 | HeapTuple tuple; 1233 | bool is_gtt = false; 1234 | 1235 | elog(DEBUG1, "Looking for registered GTT relid = %d", relid); 1236 | 1237 | /* Set and open the GTT relation */ 1238 | rv = makeRangeVar(PGTT_NAMESPACE_NAME, CATALOG_GLOBAL_TEMP_REL, -1); 1239 | #if (PG_VERSION_NUM >= 120000) 1240 | rel = table_openrv(rv, RowExclusiveLock); 1241 | #else 1242 | rel = heap_openrv(rv, RowExclusiveLock); 1243 | #endif 1244 | /* Define scanning */ 1245 | ScanKeyInit(&key[0], Anum_pgtt_viewid, BTEqualStrategyNumber, F_OIDEQ, ObjectIdGetDatum(relid)); 1246 | 1247 | /* Start search of relation */ 1248 | scan = systable_beginscan(rel, 0, true, NULL, 1, key); 1249 | 1250 | /* we found it in the GTT table */ 1251 | if (HeapTupleIsValid(tuple = systable_getnext(scan))) 1252 | is_gtt = true; 1253 | 1254 | /* Cleanup. */ 1255 | systable_endscan(scan); 1256 | #if (PG_VERSION_NUM >= 120000) 1257 | table_close(rel, RowExclusiveLock); 1258 | #else 1259 | heap_close(rel, RowExclusiveLock); 1260 | #endif 1261 | return is_gtt; 1262 | } 1263 | 1264 | -------------------------------------------------------------------------------- /pgtt_rsl.control: -------------------------------------------------------------------------------- 1 | default_version = '2.0.0' 2 | comment = 'Extension to add Oracle or DB2 style Global Temporary Tables feature to PostgreSQL. It is based on unlogged table, Row Security Level and views.' 3 | module_pathname = '$libdir/pgtt_rsl' 4 | relocatable = false 5 | -------------------------------------------------------------------------------- /sql/pgtt_rsl--1.2.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION pgtt_rsl" to load this file. \quit 3 | 4 | -- Create the type used to store the local session id 5 | CREATE TYPE lsid; 6 | CREATE FUNCTION lsid_in(cstring) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 7 | CREATE FUNCTION lsid_out(lsid) RETURNS cstring AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 8 | CREATE FUNCTION lsid_recv(internal) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 9 | CREATE FUNCTION lsid_send(lsid) RETURNS bytea AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 10 | 11 | CREATE TYPE lsid ( 12 | INTERNALLENGTH = 8, -- Composed of 2 int4 13 | INPUT = lsid_in, 14 | OUTPUT = lsid_out, 15 | RECEIVE = lsid_recv, 16 | SEND = lsid_send, 17 | ALIGNMENT = int4 18 | ); 19 | 20 | ---- 21 | -- Interfacing new lsid type with indexes: 22 | ---- 23 | 24 | -- Define the required operators 25 | CREATE FUNCTION lsid_lt(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 26 | CREATE FUNCTION lsid_le(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 27 | CREATE FUNCTION lsid_eq(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 28 | CREATE FUNCTION lsid_ge(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 29 | CREATE FUNCTION lsid_gt(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 30 | 31 | CREATE OPERATOR < ( 32 | leftarg = lsid, rightarg = lsid, procedure = lsid_lt, 33 | commutator = > , negator = >= , 34 | restrict = scalarltsel, join = scalarltjoinsel 35 | ); 36 | CREATE OPERATOR <= ( 37 | leftarg = lsid, rightarg = lsid, procedure = lsid_le, 38 | commutator = >= , negator = > , 39 | restrict = scalarltsel, join = scalarltjoinsel 40 | ); 41 | CREATE OPERATOR = ( 42 | leftarg = lsid, rightarg = lsid, procedure = lsid_eq, 43 | commutator = = , -- leave out negator since we didn't create <> operator 44 | restrict = eqsel, join = eqjoinsel 45 | ); 46 | CREATE OPERATOR >= ( 47 | leftarg = lsid, rightarg = lsid, procedure = lsid_ge, 48 | commutator = <= , negator = < , 49 | restrict = scalargtsel, join = scalargtjoinsel 50 | ); 51 | 52 | CREATE OPERATOR > ( 53 | leftarg = lsid, rightarg = lsid, procedure = lsid_gt, 54 | commutator = < , negator = <= , 55 | restrict = scalargtsel, join = scalargtjoinsel 56 | ); 57 | 58 | -- create the support function too 59 | CREATE FUNCTION lsid_cmp(lsid, lsid) RETURNS int4 AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 60 | 61 | -- now we can make the operator class 62 | CREATE OPERATOR CLASS lsid_ops 63 | DEFAULT FOR TYPE lsid USING btree AS 64 | OPERATOR 1 < , 65 | OPERATOR 2 <= , 66 | OPERATOR 3 = , 67 | OPERATOR 4 >= , 68 | OPERATOR 5 > , 69 | FUNCTION 1 lsid_cmp(lsid, lsid); 70 | 71 | CREATE CAST (lsid AS int[]) WITH INOUT AS ASSIGNMENT; 72 | CREATE CAST (int[] AS lsid) WITH INOUT AS ASSIGNMENT; 73 | 74 | 75 | CREATE FUNCTION get_session_id() RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 76 | CREATE FUNCTION generate_lsid(int, int) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 77 | CREATE FUNCTION get_session_start_time(lsid) RETURNS int AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 78 | CREATE FUNCTION get_session_pid(lsid) RETURNS int AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 79 | 80 | ---- 81 | -- Create schema dedicated to the global temporary table 82 | ---- 83 | CREATE SCHEMA pgtt_schema; 84 | REVOKE ALL ON SCHEMA pgtt_schema FROM PUBLIC; 85 | GRANT USAGE ON SCHEMA pgtt_schema TO PUBLIC; 86 | 87 | SET LOCAL search_path TO pgtt_schema,pg_catalog; 88 | 89 | ---- 90 | -- Table for meta information about Global Temporary Table. 91 | -- - relid : oid of the GTT table 92 | -- - relname : name of the GTT table 93 | -- - viewid : oid of the corresponding view acceeded by the users 94 | -- - viewname: name of the view pointing to the GTT 95 | -- - datcrea : creation date of the GTT relation 96 | ---- 97 | CREATE TABLE pgtt_global_temp ( 98 | relid oid NOT NULL, 99 | viewid oid NOT NULL, 100 | datcrea timestamp NOT NULL, 101 | preserved boolean, 102 | UNIQUE (relid, viewid) 103 | ); 104 | 105 | -- Include tables into pg_dump 106 | SELECT pg_catalog.pg_extension_config_dump('pgtt_global_temp', ''); 107 | 108 | ---- 109 | -- Global temporary tables are created using function 110 | -- pgtt_create_table(name, code, preserved) 111 | -- Parameters: 112 | -- tb_name : name of the global temporary table limited to 54 characters 113 | -- code : columns definition or SQL query 114 | -- preserved: 115 | -- true : Rows are deleted after session ends (ON COMMIT PRESERVE ROWS) 116 | -- false: Rows are deleted after COMMIT (ON COMMIT DELETE ROWS) - Default 117 | -- This function must be called only one time at database schema creation 118 | -- or after a call to pgtt_drop_table() to be recreated. It use RLS to 119 | -- restrict access to session and transaction id, we FORCE RLS so that the 120 | -- database owner will have restriction too. As superuser you may be able to 121 | -- see all rows, as database owner use NO FORCE RLS before to see all rows. 122 | -- 123 | -- It is possible to create indexes on GTT, statistics are maintained. 124 | -- Global temporary tables are truncated at postmaster startup. 125 | -- 126 | -- This function can be used in replacement of CREATE GLOBAL TEMPORARY TABLE 127 | -- syntax until GLOBAL TEMPORARY will be supported and not reported as obsolete. 128 | -- It is also already possible to use [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ] 129 | -- The pgtt extenstion allow intercepting this syntax in the processUtility hook and 130 | -- create the GTT. 131 | ---- 132 | CREATE FUNCTION pgtt_create_table (tb_name varchar(54), code text, preserved boolean DEFAULT false) 133 | RETURNS boolean 134 | AS $$ 135 | DECLARE 136 | qbased text DEFAULT NULL; 137 | column_list text; 138 | BEGIN 139 | -- Compute the query to create the global temporary table 140 | 141 | -- Look if the table is created from a SELECT/WITH statement or not 142 | SELECT REGEXP_MATCHES(code, E'^(SELECT|WITH)', 'i') INTO qbased; 143 | IF qbased IS NULL THEN 144 | -- With a basic declaration 145 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.pgtt_%s (%s)', tb_name, code); 146 | ELSE 147 | -- With a declaration based on a query 148 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.pgtt_%s AS %s', tb_name, code); 149 | END IF; 150 | -- Append pgtt_sessid "internal" column to the GTT table 151 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s ADD COLUMN pgtt_sessid lsid DEFAULT get_session_id()', tb_name); 152 | 153 | -- Create an index on pgtt_sessid column, this will slow 154 | -- down insert but this will help for select from the view 155 | EXECUTE format('CREATE INDEX ON pgtt_schema.pgtt_%s (pgtt_sessid)', tb_name); 156 | 157 | -- Allow all on the global temporary table except 158 | -- truncate and drop to everyone 159 | EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON pgtt_schema.pgtt_%s TO PUBLIC', tb_name); 160 | 161 | -- Activate RLS to set policy based on session 162 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s ENABLE ROW LEVEL SECURITY', tb_name); 163 | -- if ON COMMIT PRESERVE ROWS is enabled 164 | IF preserved THEN 165 | -- Create the policy that must be applied on the table 166 | -- to show only rows where pgtt_sessid is the same as 167 | -- current pid. 168 | EXECUTE format('CREATE POLICY pgtt_rls_session ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id()) WITH CHECK (true)', tb_name); 169 | ELSE 170 | -- Create the policy that must be applied on the table 171 | -- to show only rows where pgtt_sessid is the same as 172 | -- current pid and rows that have been created in the 173 | -- current transaction. 174 | EXECUTE format('CREATE POLICY pgtt_rls_transaction ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id() AND xmin::text = txid_current()::text) WITH CHECK (true)', tb_name); 175 | END IF; 176 | -- Force policy to be active for the owner of the table 177 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s FORCE ROW LEVEL SECURITY', tb_name); 178 | 179 | -- Collect all visible column of the table attnum >= 1 as 180 | -- column pgtt_sessid must not be reported by the view. 181 | SELECT string_agg(attname, ',' ORDER BY attnum) INTO column_list FROM pg_attribute WHERE attrelid=('pgtt_schema.pgtt_'||tb_name)::regclass AND attname != 'pgtt_sessid' AND attnum >= 1 AND NOT attisdropped; 182 | 183 | -- Create a view named as the table name given by the user 184 | -- so that he will only deal with this name, and never the 185 | -- internal name of the corresponding table prefixed with 186 | -- pgtt_. The view is also used to hide the pgtt_sessid column. 187 | IF preserved THEN 188 | EXECUTE format('CREATE VIEW %s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id()', tb_name, column_list, tb_name); 189 | ELSE 190 | EXECUTE format('CREATE VIEW %s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id() AND xmin::text = txid_current()::text', tb_name, column_list, tb_name); 191 | END IF; 192 | 193 | -- Set owner of the view to current user, not the function definer (superuser) 194 | EXECUTE format('ALTER VIEW %s OWNER TO %s', tb_name, current_user); 195 | 196 | -- Allow read+write to every one on this view - disable here because the 197 | -- owner is responsible of setting privilege on this view 198 | -- EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON %s TO PUBLIC', tb_name); 199 | 200 | -- Register the link between the view and the unlogged table 201 | EXECUTE format('INSERT INTO pgtt_schema.pgtt_global_temp (relid, viewid, datcrea, preserved) VALUES (%s, %s, now(), %L)', 202 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 'pgtt_'||tb_name AND n.nspname = 'pgtt_schema'), 203 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = tb_name AND n.nspname = current_schema), preserved); 204 | 205 | RETURN true; 206 | END; 207 | $$ 208 | LANGUAGE plpgsql SECURITY DEFINER; 209 | 210 | ---- 211 | -- Global temporary tables are droped using function 212 | -- pgtt_drop_table(name) 213 | -- Parameters: 214 | -- tb_name : name of the global temporary table 215 | -- This function can be called at any time. Associated indexes 216 | -- will be automatically removed. 217 | -- 218 | -- This function can be use in replacement of "DROP TABLE tbname" 219 | -- but it is not necessary, the ProcessUtility hook used in pgtt extension 220 | -- take care of removing everything. 221 | ---- 222 | CREATE FUNCTION pgtt_schema.pgtt_drop_table (tb_name name) 223 | RETURNS boolean 224 | AS $$ 225 | BEGIN 226 | -- Unregister the table/view relation from pgtt_schema.pgtt_global_temp table. 227 | EXECUTE format('DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=%s', 228 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 'pgtt_'||tb_name AND n.nspname = 'pgtt_schema')); 229 | 230 | -- Compute the query to remove the global temporary table and 231 | -- related indexes, with CASCADE associated view will be removed. 232 | EXECUTE format('DROP TABLE IF EXISTS pgtt_schema.pgtt_%s CASCADE', tb_name); 233 | 234 | RETURN true; 235 | END; 236 | $$ 237 | LANGUAGE plpgsql SECURITY DEFINER; 238 | 239 | ---- 240 | -- This function is called internally by the background worker pgtt_bgw 241 | -- to remove obsolete rows from all global temporary tables. 242 | -- Rows are removed by chunk of chunk_size (250000 irows by default) to 243 | -- try to preserve the performances. 244 | -- 245 | -- When the function is called at postmaster startup (iter = 0) it will 246 | -- just truncate all the global temporary tables. 247 | ---- 248 | CREATE OR REPLACE FUNCTION pgtt_maintenance (iter bigint DEFAULT 1, chunk_size integer DEFAULT 250000, analyze_table boolean DEFAULT false) 249 | RETURNS bigint 250 | AS $$ 251 | DECLARE 252 | cur_gtt_tables CURSOR FOR SELECT relid,preserved FROM pgtt_schema.pgtt_global_temp; 253 | class_info RECORD; 254 | query text; 255 | rec RECORD; 256 | nrows bigint; 257 | total_nrows bigint; 258 | alive integer; 259 | BEGIN 260 | total_nrows := 0; 261 | 262 | -- For all global temporary tables defined in pgtt_schema.pgtt_global_temp 263 | OPEN cur_gtt_tables; 264 | LOOP 265 | FETCH NEXT FROM cur_gtt_tables INTO class_info; 266 | EXIT WHEN NOT FOUND; 267 | -- Check that the table have not been removed with a direct DROP 268 | -- in this case regclass doesn't change oid to table name. 269 | IF (class_info.relid::regclass::text = class_info.relid::text) THEN 270 | -- Cleanup all references to this table 271 | EXECUTE 'DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=' || class_info.relid; 272 | CONTINUE; 273 | END IF; 274 | 275 | -- At startup iter = 0 then we just have to truncate the table 276 | IF (iter = 0) THEN 277 | EXECUTE 'TRUNCATE ' || class_info.relid::regclass; 278 | -- RAISE LOG 'GTT table "%" has been truncated at startup.', class_info.relid::regclass; 279 | CONTINUE; 280 | END IF; 281 | 282 | -- With a GTT that preserves tuples in an entire session 283 | IF (class_info.preserved) THEN 284 | -- delete rows from the GTT table that do not belong to an active session 285 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (pgtt_sessid = ANY(ARRAY(SELECT generate_lsid(extract(epoch from backend_start)::int, pid) FROM pg_stat_activity))) LIMIT ' || chunk_size || '))'; 286 | 287 | GET DIAGNOSTICS nrows = ROW_COUNT; 288 | total_nrows := total_nrows + nrows; 289 | -- With GTT where tuples do not survive a transaction 290 | ELSE 291 | -- delete rows from the GTT table that do not belong to an active transaction 292 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (xmin = ANY(ARRAY(SELECT backend_xid FROM pg_stat_activity))) LIMIT ' || chunk_size || '))'; 293 | GET DIAGNOSTICS nrows = ROW_COUNT; 294 | total_nrows := total_nrows + nrows; 295 | END IF; 296 | 297 | -- Force an analyze of the table if required 298 | IF analyze_table AND total_nrows > 0 THEN 299 | EXECUTE 'ANALYZE ' || class_info.relid::regclass; 300 | END IF; 301 | END LOOP; 302 | CLOSE cur_gtt_tables; 303 | 304 | RETURN total_nrows; 305 | END; 306 | $$ 307 | LANGUAGE plpgsql SECURITY DEFINER; 308 | -------------------------------------------------------------------------------- /sql/pgtt_rsl--1.3.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION pgtt_rsl" to load this file. \quit 3 | 4 | -- Create the type used to store the local session id 5 | CREATE TYPE lsid; 6 | CREATE FUNCTION lsid_in(cstring) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 7 | CREATE FUNCTION lsid_out(lsid) RETURNS cstring AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 8 | CREATE FUNCTION lsid_recv(internal) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 9 | CREATE FUNCTION lsid_send(lsid) RETURNS bytea AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 10 | 11 | CREATE TYPE lsid ( 12 | INTERNALLENGTH = 8, -- Composed of 2 int4 13 | INPUT = lsid_in, 14 | OUTPUT = lsid_out, 15 | RECEIVE = lsid_recv, 16 | SEND = lsid_send, 17 | ALIGNMENT = int4 18 | ); 19 | 20 | ---- 21 | -- Interfacing new lsid type with indexes: 22 | ---- 23 | 24 | -- Define the required operators 25 | CREATE FUNCTION lsid_lt(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 26 | CREATE FUNCTION lsid_le(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 27 | CREATE FUNCTION lsid_eq(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 28 | CREATE FUNCTION lsid_ge(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 29 | CREATE FUNCTION lsid_gt(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 30 | 31 | CREATE OPERATOR < ( 32 | leftarg = lsid, rightarg = lsid, procedure = lsid_lt, 33 | commutator = > , negator = >= , 34 | restrict = scalarltsel, join = scalarltjoinsel 35 | ); 36 | CREATE OPERATOR <= ( 37 | leftarg = lsid, rightarg = lsid, procedure = lsid_le, 38 | commutator = >= , negator = > , 39 | restrict = scalarltsel, join = scalarltjoinsel 40 | ); 41 | CREATE OPERATOR = ( 42 | leftarg = lsid, rightarg = lsid, procedure = lsid_eq, 43 | commutator = = , -- leave out negator since we didn't create <> operator 44 | restrict = eqsel, join = eqjoinsel 45 | ); 46 | CREATE OPERATOR >= ( 47 | leftarg = lsid, rightarg = lsid, procedure = lsid_ge, 48 | commutator = <= , negator = < , 49 | restrict = scalargtsel, join = scalargtjoinsel 50 | ); 51 | 52 | CREATE OPERATOR > ( 53 | leftarg = lsid, rightarg = lsid, procedure = lsid_gt, 54 | commutator = < , negator = <= , 55 | restrict = scalargtsel, join = scalargtjoinsel 56 | ); 57 | 58 | -- create the support function too 59 | CREATE FUNCTION lsid_cmp(lsid, lsid) RETURNS int4 AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 60 | 61 | -- now we can make the operator class 62 | CREATE OPERATOR CLASS lsid_ops 63 | DEFAULT FOR TYPE lsid USING btree AS 64 | OPERATOR 1 < , 65 | OPERATOR 2 <= , 66 | OPERATOR 3 = , 67 | OPERATOR 4 >= , 68 | OPERATOR 5 > , 69 | FUNCTION 1 lsid_cmp(lsid, lsid); 70 | 71 | CREATE CAST (lsid AS int[]) WITH INOUT AS ASSIGNMENT; 72 | CREATE CAST (int[] AS lsid) WITH INOUT AS ASSIGNMENT; 73 | 74 | 75 | CREATE FUNCTION get_session_id() RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 76 | CREATE FUNCTION generate_lsid(int, int) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 77 | CREATE FUNCTION get_session_start_time(lsid) RETURNS int AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 78 | CREATE FUNCTION get_session_pid(lsid) RETURNS int AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 79 | 80 | ---- 81 | -- Create schema dedicated to the global temporary table 82 | ---- 83 | CREATE SCHEMA pgtt_schema; 84 | REVOKE ALL ON SCHEMA pgtt_schema FROM PUBLIC; 85 | GRANT USAGE ON SCHEMA pgtt_schema TO PUBLIC; 86 | 87 | SET LOCAL search_path TO pgtt_schema,pg_catalog; 88 | 89 | ---- 90 | -- Table for meta information about Global Temporary Table. 91 | -- - relid : oid of the GTT table 92 | -- - relname : name of the GTT table 93 | -- - viewid : oid of the corresponding view acceeded by the users 94 | -- - viewname: name of the view pointing to the GTT 95 | -- - datcrea : creation date of the GTT relation 96 | ---- 97 | CREATE TABLE pgtt_global_temp ( 98 | relid oid NOT NULL, 99 | viewid oid NOT NULL, 100 | datcrea timestamp NOT NULL, 101 | preserved boolean, 102 | UNIQUE (relid, viewid) 103 | ); 104 | 105 | -- Include tables into pg_dump 106 | SELECT pg_catalog.pg_extension_config_dump('pgtt_global_temp', ''); 107 | 108 | ---- 109 | -- Global temporary tables are created using function 110 | -- pgtt_create_table(name, code, preserved) 111 | -- Parameters: 112 | -- tb_name : name of the global temporary table limited to 54 characters 113 | -- code : columns definition or SQL query 114 | -- preserved: 115 | -- true : Rows are deleted after session ends (ON COMMIT PRESERVE ROWS) 116 | -- false: Rows are deleted after COMMIT (ON COMMIT DELETE ROWS) - Default 117 | -- This function must be called only one time at database schema creation 118 | -- or after a call to pgtt_drop_table() to be recreated. It use RLS to 119 | -- restrict access to session and transaction id, we FORCE RLS so that the 120 | -- database owner will have restriction too. As superuser you may be able to 121 | -- see all rows, as database owner use NO FORCE RLS before to see all rows. 122 | -- 123 | -- It is possible to create indexes on GTT, statistics are maintained. 124 | -- Global temporary tables are truncated at postmaster startup. 125 | -- 126 | -- This function can be used in replacement of CREATE GLOBAL TEMPORARY TABLE 127 | -- syntax until GLOBAL TEMPORARY will be supported and not reported as obsolete. 128 | -- It is also already possible to use [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ] 129 | -- The pgtt extenstion allow intercepting this syntax in the processUtility hook and 130 | -- create the GTT. 131 | ---- 132 | CREATE FUNCTION pgtt_create_table (tb_name varchar(54), code text, preserved boolean DEFAULT false) 133 | RETURNS boolean 134 | AS $$ 135 | DECLARE 136 | qbased text DEFAULT NULL; 137 | column_list text; 138 | BEGIN 139 | -- Compute the query to create the global temporary table 140 | 141 | -- Look if the table is created from a SELECT/WITH statement or not 142 | SELECT REGEXP_MATCHES(code, E'^(SELECT|WITH)', 'i') INTO qbased; 143 | IF qbased IS NULL THEN 144 | -- With a basic declaration 145 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.pgtt_%s (%s)', tb_name, code); 146 | ELSE 147 | -- With a declaration based on a query 148 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.pgtt_%s AS %s', tb_name, code); 149 | END IF; 150 | -- Append pgtt_sessid "internal" column to the GTT table 151 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s ADD COLUMN pgtt_sessid lsid DEFAULT get_session_id()', tb_name); 152 | 153 | -- Create an index on pgtt_sessid column, this will slow 154 | -- down insert but this will help for select from the view 155 | EXECUTE format('CREATE INDEX ON pgtt_schema.pgtt_%s (pgtt_sessid)', tb_name); 156 | 157 | -- Allow all on the global temporary table except 158 | -- truncate and drop to everyone 159 | EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON pgtt_schema.pgtt_%s TO PUBLIC', tb_name); 160 | 161 | -- Activate RLS to set policy based on session 162 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s ENABLE ROW LEVEL SECURITY', tb_name); 163 | -- if ON COMMIT PRESERVE ROWS is enabled 164 | IF preserved THEN 165 | -- Create the policy that must be applied on the table 166 | -- to show only rows where pgtt_sessid is the same as 167 | -- current pid. 168 | EXECUTE format('CREATE POLICY pgtt_rls_session ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id()) WITH CHECK (true)', tb_name); 169 | ELSE 170 | -- Create the policy that must be applied on the table 171 | -- to show only rows where pgtt_sessid is the same as 172 | -- current pid and rows that have been created in the 173 | -- current transaction. 174 | EXECUTE format('CREATE POLICY pgtt_rls_transaction ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id() AND xmin::text = txid_current()::text) WITH CHECK (true)', tb_name); 175 | END IF; 176 | -- Force policy to be active for the owner of the table 177 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s FORCE ROW LEVEL SECURITY', tb_name); 178 | 179 | -- Collect all visible column of the table attnum >= 1 as 180 | -- column pgtt_sessid must not be reported by the view. 181 | SELECT string_agg(attname, ',' ORDER BY attnum) INTO column_list FROM pg_attribute WHERE attrelid=('pgtt_schema.pgtt_'||tb_name)::regclass AND attname != 'pgtt_sessid' AND attnum >= 1 AND NOT attisdropped; 182 | 183 | -- Create a view named as the table name given by the user 184 | -- so that he will only deal with this name, and never the 185 | -- internal name of the corresponding table prefixed with 186 | -- pgtt_. The view is also used to hide the pgtt_sessid column. 187 | IF preserved THEN 188 | EXECUTE format('CREATE VIEW %s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id()', tb_name, column_list, tb_name); 189 | ELSE 190 | EXECUTE format('CREATE VIEW %s WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id() AND xmin::text = txid_current()::text', tb_name, column_list, tb_name); 191 | END IF; 192 | 193 | -- Set owner of the view to current user, not the function definer (superuser) 194 | EXECUTE format('ALTER VIEW %s OWNER TO %s', tb_name, current_user); 195 | 196 | -- Allow read+write to every one on this view - disable here because the 197 | -- owner is responsible of setting privilege on this view 198 | -- EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON %s TO PUBLIC', tb_name); 199 | 200 | -- Register the link between the view and the unlogged table 201 | EXECUTE format('INSERT INTO pgtt_schema.pgtt_global_temp (relid, viewid, datcrea, preserved) VALUES (%s, %s, now(), %L)', 202 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 'pgtt_'||tb_name AND n.nspname = 'pgtt_schema'), 203 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = tb_name AND n.nspname = current_schema), preserved); 204 | 205 | RETURN true; 206 | END; 207 | $$ 208 | LANGUAGE plpgsql SECURITY DEFINER; 209 | 210 | ---- 211 | -- Global temporary tables are droped using function 212 | -- pgtt_drop_table(name) 213 | -- Parameters: 214 | -- tb_name : name of the global temporary table 215 | -- This function can be called at any time. Associated indexes 216 | -- will be automatically removed. 217 | -- 218 | -- This function can be use in replacement of "DROP TABLE tbname" 219 | -- but it is not necessary, the ProcessUtility hook used in pgtt extension 220 | -- take care of removing everything. 221 | ---- 222 | CREATE FUNCTION pgtt_schema.pgtt_drop_table (tb_name name) 223 | RETURNS boolean 224 | AS $$ 225 | BEGIN 226 | -- Unregister the table/view relation from pgtt_schema.pgtt_global_temp table. 227 | EXECUTE format('DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=%s', 228 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 'pgtt_'||tb_name AND n.nspname = 'pgtt_schema')); 229 | 230 | -- Compute the query to remove the global temporary table and 231 | -- related indexes, with CASCADE associated view will be removed. 232 | EXECUTE format('DROP TABLE IF EXISTS pgtt_schema.pgtt_%s CASCADE', tb_name); 233 | 234 | RETURN true; 235 | END; 236 | $$ 237 | LANGUAGE plpgsql SECURITY DEFINER; 238 | 239 | ---- 240 | -- This function is called internally by the background worker pgtt_bgw 241 | -- to remove obsolete rows from all global temporary tables. 242 | -- Rows are removed by chunk of chunk_size (250000 irows by default) to 243 | -- try to preserve the performances. 244 | -- 245 | -- When the function is called at postmaster startup (iter = 0) it will 246 | -- just truncate all the global temporary tables. 247 | ---- 248 | CREATE OR REPLACE FUNCTION pgtt_maintenance (iter bigint DEFAULT 1, chunk_size integer DEFAULT 250000, analyze_table boolean DEFAULT false) 249 | RETURNS bigint 250 | AS $$ 251 | DECLARE 252 | cur_gtt_tables CURSOR FOR SELECT relid,preserved FROM pgtt_schema.pgtt_global_temp; 253 | class_info RECORD; 254 | query text; 255 | rec RECORD; 256 | nrows bigint; 257 | total_nrows bigint; 258 | alive integer; 259 | BEGIN 260 | total_nrows := 0; 261 | 262 | -- For all global temporary tables defined in pgtt_schema.pgtt_global_temp 263 | OPEN cur_gtt_tables; 264 | LOOP 265 | FETCH NEXT FROM cur_gtt_tables INTO class_info; 266 | EXIT WHEN NOT FOUND; 267 | -- Check that the table have not been removed with a direct DROP 268 | -- in this case regclass doesn't change oid to table name. 269 | IF (class_info.relid::regclass::text = class_info.relid::text) THEN 270 | -- Cleanup all references to this table 271 | EXECUTE 'DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=' || class_info.relid; 272 | CONTINUE; 273 | END IF; 274 | 275 | -- At startup iter = 0 then we just have to truncate the table 276 | IF (iter = 0) THEN 277 | EXECUTE 'TRUNCATE ' || class_info.relid::regclass; 278 | -- RAISE LOG 'GTT table "%" has been truncated at startup.', class_info.relid::regclass; 279 | CONTINUE; 280 | END IF; 281 | 282 | -- With a GTT that preserves tuples in an entire session 283 | IF (class_info.preserved) THEN 284 | -- delete rows from the GTT table that do not belong to an active session 285 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (pgtt_sessid = ANY(ARRAY(SELECT generate_lsid(extract(epoch from backend_start)::int, pid) FROM pg_stat_activity))) LIMIT ' || chunk_size || '))'; 286 | 287 | GET DIAGNOSTICS nrows = ROW_COUNT; 288 | total_nrows := total_nrows + nrows; 289 | -- With GTT where tuples do not survive a transaction 290 | ELSE 291 | -- delete rows from the GTT table that do not belong to an active transaction 292 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (xmin = ANY(ARRAY(SELECT backend_xid FROM pg_stat_activity))) LIMIT ' || chunk_size || '))'; 293 | GET DIAGNOSTICS nrows = ROW_COUNT; 294 | total_nrows := total_nrows + nrows; 295 | END IF; 296 | 297 | -- Force an analyze of the table if required 298 | IF analyze_table AND total_nrows > 0 THEN 299 | EXECUTE 'ANALYZE ' || class_info.relid::regclass; 300 | END IF; 301 | END LOOP; 302 | CLOSE cur_gtt_tables; 303 | 304 | RETURN total_nrows; 305 | END; 306 | $$ 307 | LANGUAGE plpgsql SECURITY DEFINER; 308 | -------------------------------------------------------------------------------- /sql/pgtt_rsl--2.0.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION pgtt_rsl" to load this file. \quit 3 | 4 | -- Create the type used to store the local session id 5 | CREATE TYPE lsid; 6 | CREATE FUNCTION lsid_in(cstring) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 7 | CREATE FUNCTION lsid_out(lsid) RETURNS cstring AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 8 | CREATE FUNCTION lsid_recv(internal) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 9 | CREATE FUNCTION lsid_send(lsid) RETURNS bytea AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 10 | 11 | CREATE TYPE lsid ( 12 | INTERNALLENGTH = 8, -- Composed of 2 int4 13 | INPUT = lsid_in, 14 | OUTPUT = lsid_out, 15 | RECEIVE = lsid_recv, 16 | SEND = lsid_send, 17 | ALIGNMENT = int4 18 | ); 19 | 20 | ---- 21 | -- Interfacing new lsid type with indexes: 22 | ---- 23 | 24 | -- Define the required operators 25 | CREATE FUNCTION lsid_lt(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 26 | CREATE FUNCTION lsid_le(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 27 | CREATE FUNCTION lsid_eq(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 28 | CREATE FUNCTION lsid_ge(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 29 | CREATE FUNCTION lsid_gt(lsid, lsid) RETURNS bool AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 30 | 31 | CREATE OPERATOR < ( 32 | leftarg = lsid, rightarg = lsid, procedure = lsid_lt, 33 | commutator = > , negator = >= , 34 | restrict = scalarltsel, join = scalarltjoinsel 35 | ); 36 | CREATE OPERATOR <= ( 37 | leftarg = lsid, rightarg = lsid, procedure = lsid_le, 38 | commutator = >= , negator = > , 39 | restrict = scalarltsel, join = scalarltjoinsel 40 | ); 41 | CREATE OPERATOR = ( 42 | leftarg = lsid, rightarg = lsid, procedure = lsid_eq, 43 | commutator = = , -- leave out negator since we didn't create <> operator 44 | restrict = eqsel, join = eqjoinsel 45 | ); 46 | CREATE OPERATOR >= ( 47 | leftarg = lsid, rightarg = lsid, procedure = lsid_ge, 48 | commutator = <= , negator = < , 49 | restrict = scalargtsel, join = scalargtjoinsel 50 | ); 51 | 52 | CREATE OPERATOR > ( 53 | leftarg = lsid, rightarg = lsid, procedure = lsid_gt, 54 | commutator = < , negator = <= , 55 | restrict = scalargtsel, join = scalargtjoinsel 56 | ); 57 | 58 | -- create the support function too 59 | CREATE FUNCTION lsid_cmp(lsid, lsid) RETURNS int4 AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 60 | 61 | -- now we can make the operator class 62 | CREATE OPERATOR CLASS lsid_ops 63 | DEFAULT FOR TYPE lsid USING btree AS 64 | OPERATOR 1 < , 65 | OPERATOR 2 <= , 66 | OPERATOR 3 = , 67 | OPERATOR 4 >= , 68 | OPERATOR 5 > , 69 | FUNCTION 1 lsid_cmp(lsid, lsid); 70 | 71 | CREATE CAST (lsid AS int[]) WITH INOUT AS ASSIGNMENT; 72 | CREATE CAST (int[] AS lsid) WITH INOUT AS ASSIGNMENT; 73 | 74 | 75 | CREATE FUNCTION get_session_id() RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 76 | CREATE FUNCTION generate_lsid(int, int) RETURNS lsid AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 77 | CREATE FUNCTION get_session_start_time(lsid) RETURNS int AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 78 | CREATE FUNCTION get_session_pid(lsid) RETURNS int AS 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE STRICT; 79 | 80 | ---- 81 | -- Create schema dedicated to the global temporary table 82 | ---- 83 | CREATE SCHEMA pgtt_schema; 84 | REVOKE ALL ON SCHEMA pgtt_schema FROM PUBLIC; 85 | GRANT USAGE ON SCHEMA pgtt_schema TO PUBLIC; 86 | 87 | SET LOCAL search_path TO pgtt_schema,pg_catalog; 88 | 89 | ---- 90 | -- Table for meta information about Global Temporary Table. 91 | -- - relid : oid of the GTT table 92 | -- - viewid : oid of the corresponding view acceeded by the users 93 | -- - datcrea : creation date of the GTT relation 94 | -- - preserved: use ON COMMIT PRESERVE ROWS 95 | ---- 96 | CREATE TABLE pgtt_schema.pgtt_global_temp ( 97 | relid oid UNIQUE NOT NULL, 98 | viewid oid UNIQUE NOT NULL, 99 | datcrea timestamp NOT NULL, 100 | preserved boolean, 101 | PRIMARY KEY (relid, viewid) 102 | ); 103 | GRANT SELECT ON pgtt_schema.pgtt_global_temp TO PUBLIC; 104 | 105 | -- Include tables into pg_dump 106 | SELECT pg_catalog.pg_extension_config_dump('pgtt_global_temp', ''); 107 | 108 | ---- 109 | -- Global temporary tables are created using function 110 | -- pgtt_create_table(name, code, preserved) 111 | -- Parameters: 112 | -- tb_name : name of the global temporary table limited to 54 characters 113 | -- code : columns definition or SQL query 114 | -- preserved: 115 | -- true : Rows are deleted after session ends (ON COMMIT PRESERVE ROWS) 116 | -- false: Rows are deleted after COMMIT (ON COMMIT DELETE ROWS) - Default 117 | -- This function must be called only one time at database schema creation 118 | -- or after a call to pgtt_drop_table() to be recreated. It use RLS to 119 | -- restrict access to session and transaction id, we FORCE RLS so that the 120 | -- database owner will have restriction too. As superuser you may be able to 121 | -- see all rows, as database owner use NO FORCE RLS before to see all rows. 122 | -- 123 | -- It is possible to create indexes on GTT, statistics are maintained. 124 | -- Global temporary tables are truncated at postmaster startup. 125 | -- 126 | -- This function can be used in replacement of CREATE GLOBAL TEMPORARY TABLE 127 | -- syntax until GLOBAL TEMPORARY will be supported and not reported as obsolete. 128 | -- It is also already possible to use [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ] 129 | -- The pgtt extenstion allow intercepting this syntax in the processUtility hook and 130 | -- create the GTT. 131 | ---- 132 | CREATE FUNCTION pgtt_schema.pgtt_create_table (tb_name name, code text, preserved boolean DEFAULT false, relnspname name DEFAULT 'public') 133 | RETURNS boolean 134 | AS $$ 135 | DECLARE 136 | qbased text DEFAULT NULL; 137 | column_list text; 138 | relid oid; 139 | BEGIN 140 | -- Compute the query to create the global temporary table 141 | 142 | -- Look if the table is created from a SELECT/WITH statement or not 143 | SELECT REGEXP_MATCHES(code, E'^(SELECT|WITH)', 'i') INTO qbased; 144 | IF qbased IS NULL THEN 145 | -- With a basic declaration 146 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.%I (%s)', tb_name, code); 147 | ELSE 148 | -- With a declaration based on a query 149 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.%I AS %s', tb_name, code); 150 | END IF; 151 | -- Append pgtt_sessid "internal" column to the GTT table 152 | EXECUTE format('ALTER TABLE pgtt_schema.%I ADD COLUMN pgtt_sessid lsid DEFAULT get_session_id()', tb_name); 153 | 154 | -- Get the oid of the relation and rename it using this oid. 155 | SELECT c.oid INTO relid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = tb_name AND n.nspname = 'pgtt_schema'; 156 | EXECUTE format('ALTER TABLE pgtt_schema.%I RENAME TO pgtt_%s', tb_name, relid); 157 | 158 | -- Create an index on pgtt_sessid column, this will slow 159 | -- down insert but this will help for select from the view 160 | EXECUTE format('CREATE INDEX ON pgtt_schema.pgtt_%s (pgtt_sessid)', relid); 161 | 162 | -- Allow all on the global temporary table except 163 | -- truncate and drop to everyone 164 | EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON pgtt_schema.pgtt_%s TO PUBLIC', relid); 165 | 166 | -- Activate RLS to set policy based on session 167 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s ENABLE ROW LEVEL SECURITY', relid); 168 | 169 | -- if ON COMMIT PRESERVE ROWS is enabled 170 | IF preserved THEN 171 | -- Create the policy that must be applied on the table 172 | -- to show only rows where pgtt_sessid is the same as 173 | -- current pid. 174 | EXECUTE format('CREATE POLICY pgtt_rls_session ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id()) WITH CHECK (true)', relid); 175 | ELSE 176 | -- Create the policy that must be applied on the table 177 | -- to show only rows where pgtt_sessid is the same as 178 | -- current pid and rows that have been created in the 179 | -- current transaction. 180 | EXECUTE format('CREATE POLICY pgtt_rls_transaction ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id() AND xmin::text >= txid_current()::text) WITH CHECK (true)', relid); 181 | END IF; 182 | -- Force policy to be active for the owner of the table 183 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s FORCE ROW LEVEL SECURITY', relid); 184 | 185 | -- Collect all visible column of the table attnum >= 1 as 186 | -- column pgtt_sessid must not be reported by the view. 187 | SELECT string_agg(attname, ',' ORDER BY attnum) INTO column_list FROM pg_attribute WHERE attrelid=('pgtt_schema.pgtt_'||relid)::regclass AND attname != 'pgtt_sessid' AND attnum >= 1 AND NOT attisdropped; 188 | 189 | -- Create a view named as the table name given by the user 190 | -- so that he will only deal with this name, and never the 191 | -- internal name of the corresponding table prefixed with 192 | -- pgtt_. The view is also used to hide the pgtt_sessid column. 193 | IF preserved THEN 194 | EXECUTE format('CREATE VIEW %I.%I WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id()', relnspname, tb_name, column_list, relid); 195 | ELSE 196 | EXECUTE format('CREATE VIEW %I.%I WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id() AND xmin::text >= txid_current()::text', relnspname, tb_name, column_list, relid); 197 | END IF; 198 | 199 | -- Set owner of the view to session user, not the function definer (superuser) 200 | EXECUTE format('ALTER VIEW %I.%I OWNER TO %s', relnspname, tb_name, session_user); 201 | 202 | -- Allow read+write to every one on this view - disable here because the 203 | -- owner is responsible of setting privilege on this view 204 | -- EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON %s TO PUBLIC', tb_name); 205 | 206 | -- Register the link between the view and the unlogged table 207 | EXECUTE format('INSERT INTO pgtt_schema.pgtt_global_temp (relid, viewid, datcrea, preserved) VALUES (%s, %s, now(), %L)', 208 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 'pgtt_'||relid AND n.nspname = 'pgtt_schema'), 209 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = tb_name AND n.nspname = relnspname), preserved); 210 | 211 | RETURN true; 212 | END; 213 | $$ 214 | LANGUAGE plpgsql SECURITY DEFINER; 215 | 216 | ---- 217 | -- Global temporary tables are droped using function 218 | -- pgtt_drop_table(name) 219 | -- Parameters: 220 | -- tb_name : name of the global temporary table 221 | -- This function can be called at any time. Associated indexes 222 | -- will be automatically removed. 223 | -- 224 | -- This function can be use in replacement of "DROP TABLE tbname" 225 | -- but it is not necessary, the ProcessUtility hook used in pgtt extension 226 | -- take care of removing everything. 227 | ---- 228 | CREATE FUNCTION pgtt_schema.pgtt_drop_table (tb_name name, nspname name DEFAULT 'public') 229 | RETURNS boolean 230 | AS $$ 231 | DECLARE 232 | relid oid; 233 | BEGIN 234 | -- Get the view Oid 235 | EXECUTE format('SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = %L AND n.nspname = %L', tb_name, nspname) INTO relid; 236 | -- Unregister the table/view relation from pgtt_schema.pgtt_global_temp table and return the relation oid 237 | EXECUTE format('DELETE FROM pgtt_schema.pgtt_global_temp WHERE viewid=%s RETURNING relid', relid) INTO relid; 238 | -- Compute the query to remove the global temporary table and 239 | -- related objects, with CASCADE associated view will be removed. 240 | EXECUTE format('DROP TABLE IF EXISTS pgtt_schema.pgtt_%s CASCADE', relid); 241 | 242 | RETURN true; 243 | END; 244 | $$ 245 | LANGUAGE plpgsql SECURITY DEFINER; 246 | 247 | ---- 248 | -- This function is called internally by the background worker pgtt_bgw 249 | -- to remove obsolete rows from all global temporary tables. 250 | -- Rows are removed by chunk of chunk_size (250000 irows by default) to 251 | -- try to preserve the performances. 252 | -- 253 | -- When the function is called at postmaster startup (iter = 0) it will 254 | -- just truncate all the global temporary tables. 255 | ---- 256 | CREATE OR REPLACE FUNCTION pgtt_schema.pgtt_maintenance (iter integer DEFAULT 1, chunk_size integer DEFAULT 250000, analyze_table boolean DEFAULT false) 257 | RETURNS bigint 258 | AS $$ 259 | DECLARE 260 | cur_gtt_tables CURSOR FOR SELECT viewid,relid,preserved FROM pgtt_schema.pgtt_global_temp; 261 | class_info RECORD; 262 | query text; 263 | rec RECORD; 264 | nrows bigint; 265 | total_nrows bigint; 266 | alive integer; 267 | relid oid; 268 | BEGIN 269 | total_nrows := 0; 270 | 271 | -- For all global temporary tables defined in pgtt_schema.pgtt_global_temp 272 | OPEN cur_gtt_tables; 273 | LOOP 274 | FETCH NEXT FROM cur_gtt_tables INTO class_info; 275 | EXIT WHEN NOT FOUND; 276 | -- Check if the table have been removed with a direct DROP+CASCADE 277 | EXECUTE 'SELECT oid FROM pg_class WHERE oid=' || class_info.relid INTO relid; 278 | IF relid IS NULL THEN 279 | -- Cleanup all references to this table in our GTT registery table 280 | EXECUTE 'DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=' || class_info.relid; 281 | CONTINUE; 282 | END IF; 283 | -- Check if the view have been removed with a direct DROP 284 | EXECUTE 'SELECT oid FROM pg_class WHERE oid=' || class_info.viewid INTO relid; 285 | IF relid IS NULL THEN 286 | -- Drop the table if it is not already the case 287 | EXECUTE 'DROP TABLE pgtt_schema.pgtt_' || class_info.relid; 288 | -- Cleanup all references to this table 289 | EXECUTE 'DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=' || class_info.relid; 290 | CONTINUE; 291 | END IF; 292 | 293 | -- At startup iter = 0 then we just have to truncate the table 294 | IF (iter = 0) THEN 295 | EXECUTE 'TRUNCATE ' || class_info.relid::regclass; 296 | -- RAISE LOG 'GTT table "%" has been truncated at startup.', class_info.relid::regclass; 297 | CONTINUE; 298 | END IF; 299 | 300 | -- With a GTT that preserves tuples in an entire session 301 | IF (class_info.preserved) THEN 302 | -- delete rows from the GTT table that do not belong to an active session 303 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (pgtt_sessid = ANY(ARRAY(SELECT generate_lsid(extract(epoch from backend_start)::int, pid) FROM pg_stat_activity))) LIMIT ' || chunk_size || '))'; 304 | 305 | GET DIAGNOSTICS nrows = ROW_COUNT; 306 | total_nrows := total_nrows + nrows; 307 | -- With GTT where tuples do not survive a transaction 308 | ELSE 309 | -- delete rows from the GTT table that do not belong to an active transaction 310 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (xmin = ANY(ARRAY(SELECT DISTINCT backend_xmin FROM pg_stat_activity WHERE backend_xmin IS NOT NULL))) LIMIT ' || chunk_size || '))'; 311 | GET DIAGNOSTICS nrows = ROW_COUNT; 312 | total_nrows := total_nrows + nrows; 313 | END IF; 314 | 315 | -- Force an analyze of the table if required 316 | IF analyze_table AND total_nrows > 0 THEN 317 | EXECUTE 'ANALYZE ' || class_info.relid::regclass; 318 | END IF; 319 | END LOOP; 320 | CLOSE cur_gtt_tables; 321 | 322 | RETURN total_nrows; 323 | END; 324 | $$ 325 | LANGUAGE plpgsql SECURITY DEFINER; 326 | -------------------------------------------------------------------------------- /test/bench/README: -------------------------------------------------------------------------------- 1 | # To run the bench execute the following commands: 2 | 3 | createdb test 4 | psql test -c "CREATE USER test_gtt1;" 5 | psql test -c "CREATE EXTENSION pgtt;" 6 | psql test -c "SELECT pgtt_schema.pgtt_create_table('t1', 'id integer, lbl text', true);" 7 | psql test -c "GRANT ALL ON t1 TO test_gtt1;" 8 | 9 | #pgbench -h localhost -U test_gtt1 -c 20 -j 4 -T 60 -f test/bench/local_temp1.bench test 10 | #pgbench -h localhost -U test_gtt1 -c 20 -j 4 -T 60 -f test/bench/local2_temp.bench test 11 | pgbench -h localhost -U test_gtt1 -c 20 -j 4 -T 60 -f test/bench/global_temp.bench test 12 | 13 | -------------------------------------------------------------------------------- /test/bench/global_temp.bench: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | INSERT INTO t1 (id, lbl) SELECT i, md5(i::text) FROM generate_series(1, 10000) i; 3 | SELECT * FROM t1; 4 | COMMIT; 5 | 6 | -- transaction type: test/local_temp3.bench 7 | -- scaling factor: 1 8 | -- query mode: simple 9 | -- number of clients: 20 10 | -- number of threads: 4 11 | -- duration: 60 s 12 | -- number of transactions actually processed: 872 13 | -- latency average = 1402.185 ms 14 | -- tps = 14.263457 (including connections establishing) 15 | -- tps = 14.269886 (excluding connections establishing) 16 | -- 17 | -- INSERT only with index on pgtt_sessid: 18 | -- 19 | -- transaction type: test/bench/global_temp.bench 20 | -- scaling factor: 1 21 | -- query mode: simple 22 | -- number of clients: 20 23 | -- number of threads: 4 24 | -- duration: 60 s 25 | -- number of transactions actually processed: 864 26 | -- latency average = 1424.550 ms 27 | -- tps = 14.039523 (including connections establishing) 28 | -- tps = 14.041116 (excluding connections establishing) 29 | -- 30 | -- INSERT only without index: 31 | -- 32 | -- transaction type: test/global_temp.bench 33 | -- scaling factor: 1 34 | -- query mode: simple 35 | -- number of clients: 20 36 | -- number of threads: 4 37 | -- duration: 60 s 38 | -- number of transactions actually processed: 13033 39 | -- latency average = 92.174 ms 40 | -- tps = 216.981611 (including connections establishing) 41 | -- tps = 216.992958 (excluding connections establishing) 42 | 43 | -------------------------------------------------------------------------------- /test/bench/local_temp1.bench: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE TEMPORARY TABLE t1(id int, lbl text); 3 | INSERT INTO t1 (id, lbl) SELECT i, md5(i::text) FROM generate_series(1, 10000) i; 4 | SELECT * FROM t1 ; 5 | DROP TABLE t1; 6 | COMMIT; 7 | 8 | -- transaction type: test/bench/local_temp1.bench 9 | -- scaling factor: 1 10 | -- query mode: simple 11 | -- number of clients: 20 12 | -- number of threads: 4 13 | -- duration: 60 s 14 | -- number of transactions actually processed: 10780 15 | -- latency average = 111.452 ms 16 | -- tps = 179.449391 (including connections establishing) 17 | -- tps = 179.459616 (excluding connections establishing) 18 | -- 19 | -- INSERT only: 20 | -- transaction type: test/local_temp.bench 21 | -- scaling factor: 1 22 | -- query mode: simple 23 | -- number of clients: 20 24 | -- number of threads: 4 25 | -- duration: 60 s 26 | -- number of transactions actually processed: 15450 27 | -- latency average = 77.777 ms 28 | -- tps = 257.146917 (including connections establishing) 29 | -- tps = 257.163559 (excluding connections establishing) 30 | 31 | -------------------------------------------------------------------------------- /test/bench/local_temp2.bench: -------------------------------------------------------------------------------- 1 | -- Create this function first in the test database: 2 | -- 3 | -- CREATE OR REPLACE FUNCTION test_temp_table () 4 | -- RETURNS boolean 5 | -- AS $$ 6 | -- BEGIN 7 | -- 8 | -- CREATE TEMPORARY TABLE t1(id int, lbl text)ON COMMIT DROP; 9 | -- INSERT INTO t1 (id, lbl) SELECT i, md5(i::text) FROM generate_series(1, 10000) i; 10 | -- PERFORM * FROM t1 ; 11 | -- RETURN true; 12 | -- END; 13 | -- $$ 14 | -- LANGUAGE plpgsql SECURITY DEFINER; 15 | 16 | SELECT test_temp_table(); 17 | 18 | -- transaction type: test/bench/local_temp2.bench 19 | -- scaling factor: 1 20 | -- query mode: simple 21 | -- number of clients: 20 22 | -- number of threads: 4 23 | -- duration: 60 s 24 | -- number of transactions actually processed: 14496 25 | -- latency average = 82.901 ms 26 | -- tps = 241.250620 (including connections establishing) 27 | -- tps = 241.268262 (excluding connections establishing) 28 | -- 29 | -- INSERT only: 30 | -- transaction type: test/local_temp2.bench 31 | -- scaling factor: 1 32 | -- query mode: simple 33 | -- number of clients: 20 34 | -- number of threads: 4 35 | -- duration: 60 s 36 | -- number of transactions actually processed: 15517 37 | -- latency average = 77.437 ms 38 | -- tps = 258.275703 (including connections establishing) 39 | -- tps = 258.293318 (excluding connections establishing) 40 | 41 | -------------------------------------------------------------------------------- /test/expected/test_gtt.txt: -------------------------------------------------------------------------------- 1 | psql:test/test_gtt.sql:8: NOTICE: database "gtt_testdb" does not exist, skipping 2 | DROP DATABASE 3 | psql:test/test_gtt.sql:9: NOTICE: role "test_gtt1" does not exist, skipping 4 | DROP ROLE 5 | psql:test/test_gtt.sql:10: NOTICE: role "test_gtt2" does not exist, skipping 6 | DROP ROLE 7 | CREATE ROLE 8 | CREATE ROLE 9 | CREATE DATABASE 10 | You are now connected to database "gtt_testdb" as user "gilles". 11 | CREATE EXTENSION 12 | pgtt_create_table 13 | ------------------- 14 | t 15 | (1 row) 16 | 17 | GRANT 18 | pgtt_create_table 19 | ------------------- 20 | t 21 | (1 row) 22 | 23 | GRANT 24 | CREATE SCHEMA 25 | GRANT 26 | pgtt_create_table 27 | ------------------- 28 | t 29 | (1 row) 30 | 31 | GRANT 32 | CREATE FUNCTION 33 | GRANT 34 | You are now connected to database "gtt_testdb" as user "test_gtt1". 35 | INSERT 0 3 36 | count 37 | ------- 38 | 3 39 | (1 row) 40 | 41 | BEGIN 42 | INSERT 0 3 43 | SAVEPOINT 44 | count 45 | ------- 46 | 3 47 | (1 row) 48 | 49 | COMMIT 50 | count 51 | ------- 52 | 3 53 | (1 row) 54 | 55 | You are now connected to database "gtt_testdb" as user "test_gtt2". 56 | count 57 | ------- 58 | 0 59 | (1 row) 60 | 61 | count 62 | ------- 63 | 0 64 | (1 row) 65 | 66 | INSERT 0 3 67 | count 68 | ------- 69 | 3 70 | (1 row) 71 | 72 | You are now connected to database "gtt_testdb" as user "test_gtt1". 73 | INSERT 0 3 74 | count 75 | ------- 76 | 3 77 | (1 row) 78 | 79 | count 80 | ------- 81 | 3 82 | (1 row) 83 | 84 | You are now connected to database "gtt_testdb" as user "postgres". 85 | count 86 | ------- 87 | 9 88 | (1 row) 89 | 90 | count 91 | ------- 92 | 0 93 | (1 row) 94 | 95 | You are now connected to database "gtt_testdb" as user "test_gtt2". 96 | DELETE 0 97 | INSERT 0 3 98 | count 99 | ------- 100 | 3 101 | (1 row) 102 | 103 | count 104 | ------- 105 | 3 106 | (1 row) 107 | 108 | DELETE 3 109 | count 110 | ------- 111 | 0 112 | (1 row) 113 | 114 | INSERT 0 3 115 | UPDATE 3 116 | count 117 | ------- 118 | 1 119 | (1 row) 120 | 121 | count 122 | ------- 123 | 1 124 | (1 row) 125 | 126 | count 127 | ------- 128 | 1 129 | (1 row) 130 | 131 | DO 132 | count 133 | ------- 134 | 1 135 | (1 row) 136 | 137 | count 138 | ------- 139 | 1 140 | (1 row) 141 | 142 | count 143 | ------- 144 | 1 145 | (1 row) 146 | 147 | You are now connected to database "gtt_testdb" as user "postgres". 148 | count 149 | ------- 150 | 12 151 | (1 row) 152 | 153 | count 154 | ------- 155 | 0 156 | (1 row) 157 | 158 | count 159 | ------- 160 | 0 161 | (1 row) 162 | 163 | You are now connected to database "gtt_testdb" as user "test_gtt1". 164 | BEGIN 165 | INSERT 0 3 166 | count 167 | ------- 168 | 3 169 | (1 row) 170 | 171 | INSERT 0 3 172 | count 173 | ------- 174 | 6 175 | (1 row) 176 | 177 | COMMIT 178 | count 179 | ------- 180 | 0 181 | (1 row) 182 | 183 | count 184 | ------- 185 | 0 186 | (1 row) 187 | 188 | You are now connected to database "gtt_testdb" as user "test_gtt2". 189 | BEGIN 190 | INSERT 0 3 191 | count 192 | ------- 193 | 3 194 | (1 row) 195 | 196 | DELETE 3 197 | count 198 | ------- 199 | 0 200 | (1 row) 201 | 202 | COMMIT 203 | count 204 | ------- 205 | 0 206 | (1 row) 207 | 208 | count 209 | ------- 210 | 0 211 | (1 row) 212 | 213 | You are now connected to database "gtt_testdb" as user "test_gtt2". 214 | BEGIN 215 | INSERT 0 3 216 | count 217 | ------- 218 | 3 219 | (1 row) 220 | 221 | count 222 | ------- 223 | 3 224 | (1 row) 225 | 226 | UPDATE 3 227 | count 228 | ------- 229 | 1 230 | (1 row) 231 | 232 | count 233 | ------- 234 | 1 235 | (1 row) 236 | 237 | count 238 | ------- 239 | 1 240 | (1 row) 241 | 242 | COMMIT 243 | count 244 | ------- 245 | 0 246 | (1 row) 247 | 248 | count 249 | ------- 250 | 0 251 | (1 row) 252 | 253 | BEGIN 254 | INSERT 0 3 255 | count 256 | ------- 257 | 3 258 | (1 row) 259 | 260 | count 261 | ------- 262 | 3 263 | (1 row) 264 | 265 | ROLLBACK 266 | count 267 | ------- 268 | 0 269 | (1 row) 270 | 271 | count 272 | ------- 273 | 0 274 | (1 row) 275 | 276 | You are now connected to database "gtt_testdb" as user "postgres". 277 | count 278 | ------- 279 | 9 280 | (1 row) 281 | 282 | count 283 | ------- 284 | 0 285 | (1 row) 286 | 287 | psql:test/test_gtt.sql:255: NOTICE: drop cascades to view t_glob_temptable1 288 | pgtt_drop_table 289 | ----------------- 290 | t 291 | (1 row) 292 | 293 | psql:test/test_gtt.sql:258: NOTICE: drop cascades to view t_glob_temptable2 294 | pgtt_drop_table 295 | ----------------- 296 | t 297 | (1 row) 298 | 299 | psql:test/test_gtt.sql:261: NOTICE: drop cascades to view foo.t_glob_temptable1 300 | pgtt_drop_table 301 | ----------------- 302 | t 303 | (1 row) 304 | 305 | generate_lsid 306 | -------------------- 307 | {1527703231,11007} 308 | (1 row) 309 | 310 | get_session_start_time 311 | ------------------------ 312 | 1527703231 313 | (1 row) 314 | 315 | get_session_pid 316 | ----------------- 317 | 11007 318 | (1 row) 319 | 320 | ?column? 321 | ---------- 322 | f 323 | (1 row) 324 | 325 | ?column? 326 | ---------- 327 | t 328 | (1 row) 329 | 330 | ?column? 331 | ---------- 332 | t 333 | (1 row) 334 | 335 | ?column? 336 | ---------- 337 | t 338 | (1 row) 339 | 340 | ?column? 341 | ---------- 342 | t 343 | (1 row) 344 | 345 | ?column? 346 | ---------- 347 | f 348 | (1 row) 349 | 350 | ?column? 351 | ---------- 352 | t 353 | (1 row) 354 | 355 | ?column? 356 | ---------- 357 | f 358 | (1 row) 359 | 360 | ?column? 361 | ---------- 362 | f 363 | (1 row) 364 | 365 | You are now connected to database "postgres" as user "postgres". 366 | DROP DATABASE 367 | DROP ROLE 368 | DROP ROLE 369 | -------------------------------------------------------------------------------- /test/expected/test_gtt2.txt: -------------------------------------------------------------------------------- 1 | psql:test/test_gtt2.sql:8: NOTICE: database "gtt_testdb" does not exist, skipping 2 | DROP DATABASE 3 | psql:test/test_gtt2.sql:9: NOTICE: role "test_gtt1" does not exist, skipping 4 | DROP ROLE 5 | psql:test/test_gtt2.sql:10: NOTICE: role "test_gtt2" does not exist, skipping 6 | DROP ROLE 7 | CREATE ROLE 8 | CREATE ROLE 9 | CREATE DATABASE 10 | You are now connected to database "gtt_testdb" as user "gilles". 11 | CREATE EXTENSION 12 | psql:test/test_gtt2.sql:23: WARNING: GLOBAL is deprecated in temporary table creation 13 | LINE 1: CREATE GLOBAL TEMPORARY TABLE t_glob_temptable1 (id integer,... 14 | ^ 15 | CREATE TABLE 16 | GRANT 17 | psql:test/test_gtt2.sql:27: WARNING: GLOBAL is deprecated in temporary table creation 18 | LINE 1: CREATE GLOBAL TEMPORARY TABLE t_glob_temptable2 ON COMMIT DE... 19 | ^ 20 | CREATE TABLE AS 21 | GRANT 22 | CREATE SCHEMA 23 | GRANT 24 | psql:test/test_gtt2.sql:32: WARNING: GLOBAL is deprecated in temporary table creation 25 | LINE 1: CREATE GLOBAL TEMPORARY TABLE foo.t_glob_temptable1 (id inte... 26 | ^ 27 | CREATE TABLE 28 | GRANT 29 | CREATE FUNCTION 30 | GRANT 31 | You are now connected to database "gtt_testdb" as user "test_gtt1". 32 | INSERT 0 3 33 | count 34 | ------- 35 | 3 36 | (1 row) 37 | 38 | BEGIN 39 | INSERT 0 3 40 | SAVEPOINT 41 | count 42 | ------- 43 | 3 44 | (1 row) 45 | 46 | COMMIT 47 | count 48 | ------- 49 | 3 50 | (1 row) 51 | 52 | You are now connected to database "gtt_testdb" as user "test_gtt2". 53 | count 54 | ------- 55 | 0 56 | (1 row) 57 | 58 | count 59 | ------- 60 | 0 61 | (1 row) 62 | 63 | INSERT 0 3 64 | count 65 | ------- 66 | 3 67 | (1 row) 68 | 69 | You are now connected to database "gtt_testdb" as user "test_gtt1". 70 | INSERT 0 3 71 | count 72 | ------- 73 | 3 74 | (1 row) 75 | 76 | count 77 | ------- 78 | 3 79 | (1 row) 80 | 81 | You are now connected to database "gtt_testdb" as user "postgres". 82 | count 83 | ------- 84 | 9 85 | (1 row) 86 | 87 | count 88 | ------- 89 | 0 90 | (1 row) 91 | 92 | You are now connected to database "gtt_testdb" as user "test_gtt2". 93 | DELETE 0 94 | INSERT 0 3 95 | count 96 | ------- 97 | 3 98 | (1 row) 99 | 100 | count 101 | ------- 102 | 3 103 | (1 row) 104 | 105 | DELETE 3 106 | count 107 | ------- 108 | 0 109 | (1 row) 110 | 111 | INSERT 0 3 112 | UPDATE 3 113 | count 114 | ------- 115 | 1 116 | (1 row) 117 | 118 | count 119 | ------- 120 | 1 121 | (1 row) 122 | 123 | count 124 | ------- 125 | 1 126 | (1 row) 127 | 128 | DO 129 | count 130 | ------- 131 | 1 132 | (1 row) 133 | 134 | count 135 | ------- 136 | 1 137 | (1 row) 138 | 139 | count 140 | ------- 141 | 1 142 | (1 row) 143 | 144 | You are now connected to database "gtt_testdb" as user "postgres". 145 | count 146 | ------- 147 | 12 148 | (1 row) 149 | 150 | count 151 | ------- 152 | 0 153 | (1 row) 154 | 155 | count 156 | ------- 157 | 0 158 | (1 row) 159 | 160 | You are now connected to database "gtt_testdb" as user "test_gtt1". 161 | BEGIN 162 | INSERT 0 3 163 | count 164 | ------- 165 | 3 166 | (1 row) 167 | 168 | INSERT 0 3 169 | count 170 | ------- 171 | 6 172 | (1 row) 173 | 174 | COMMIT 175 | count 176 | ------- 177 | 0 178 | (1 row) 179 | 180 | count 181 | ------- 182 | 0 183 | (1 row) 184 | 185 | You are now connected to database "gtt_testdb" as user "test_gtt2". 186 | BEGIN 187 | INSERT 0 3 188 | count 189 | ------- 190 | 3 191 | (1 row) 192 | 193 | DELETE 3 194 | count 195 | ------- 196 | 0 197 | (1 row) 198 | 199 | COMMIT 200 | count 201 | ------- 202 | 0 203 | (1 row) 204 | 205 | count 206 | ------- 207 | 0 208 | (1 row) 209 | 210 | You are now connected to database "gtt_testdb" as user "test_gtt2". 211 | BEGIN 212 | INSERT 0 3 213 | count 214 | ------- 215 | 3 216 | (1 row) 217 | 218 | count 219 | ------- 220 | 3 221 | (1 row) 222 | 223 | UPDATE 3 224 | count 225 | ------- 226 | 1 227 | (1 row) 228 | 229 | count 230 | ------- 231 | 1 232 | (1 row) 233 | 234 | count 235 | ------- 236 | 1 237 | (1 row) 238 | 239 | COMMIT 240 | count 241 | ------- 242 | 0 243 | (1 row) 244 | 245 | count 246 | ------- 247 | 0 248 | (1 row) 249 | 250 | BEGIN 251 | INSERT 0 3 252 | count 253 | ------- 254 | 3 255 | (1 row) 256 | 257 | count 258 | ------- 259 | 3 260 | (1 row) 261 | 262 | ROLLBACK 263 | count 264 | ------- 265 | 0 266 | (1 row) 267 | 268 | count 269 | ------- 270 | 0 271 | (1 row) 272 | 273 | You are now connected to database "gtt_testdb" as user "postgres". 274 | count 275 | ------- 276 | 9 277 | (1 row) 278 | 279 | count 280 | ------- 281 | 0 282 | (1 row) 283 | 284 | DROP TABLE 285 | DROP TABLE 286 | DROP TABLE 287 | generate_lsid 288 | -------------------- 289 | {1527703231,11007} 290 | (1 row) 291 | 292 | get_session_start_time 293 | ------------------------ 294 | 1527703231 295 | (1 row) 296 | 297 | get_session_pid 298 | ----------------- 299 | 11007 300 | (1 row) 301 | 302 | ?column? 303 | ---------- 304 | f 305 | (1 row) 306 | 307 | ?column? 308 | ---------- 309 | t 310 | (1 row) 311 | 312 | ?column? 313 | ---------- 314 | t 315 | (1 row) 316 | 317 | ?column? 318 | ---------- 319 | t 320 | (1 row) 321 | 322 | ?column? 323 | ---------- 324 | t 325 | (1 row) 326 | 327 | ?column? 328 | ---------- 329 | f 330 | (1 row) 331 | 332 | ?column? 333 | ---------- 334 | t 335 | (1 row) 336 | 337 | ?column? 338 | ---------- 339 | f 340 | (1 row) 341 | 342 | ?column? 343 | ---------- 344 | f 345 | (1 row) 346 | 347 | You are now connected to database "postgres" as user "postgres". 348 | DROP DATABASE 349 | DROP ROLE 350 | DROP ROLE 351 | -------------------------------------------------------------------------------- /test/test_gtt.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Regression test to Global Temporary Table RSL implementation with use of 3 | -- pgtt_schema.pgtt_create_table and pgtt_schema.pgtt_drop_table functions. 4 | -- 5 | -- LANG=C psql -f test/test_gtt.sql > result.txt 2>&1 6 | -- diff result.txt test/expected/test_gtt.txt 7 | ---- 8 | DROP DATABASE IF EXISTS gtt_testdb; 9 | DROP ROLE IF EXISTS test_gtt1; 10 | DROP ROLE IF EXISTS test_gtt2; 11 | CREATE ROLE test_gtt1 LOGIN PASSWORD 'test_gtt1'; 12 | CREATE ROLE test_gtt2 LOGIN PASSWORD 'test_gtt2'; 13 | 14 | CREATE DATABASE gtt_testdb OWNER test_gtt1 ; 15 | 16 | -- Connect as superuser 17 | \c gtt_testdb 18 | 19 | -- Create the PostgreSQL extension 20 | CREATE EXTENSION pgtt_rsl; 21 | 22 | -- Create a GTT like table to test ON COMMIT PRESERVE ROWS 23 | SELECT pgtt_schema.pgtt_create_table('t_glob_temptable1', 'id integer, lbl text', true); 24 | -- This syntax is not yet available 25 | -- CREATE GLOBAL TEMPORARY TABLE t_glob_temptable1 (id integer, lbl text) ON COMMIT PRESERVE ROWS; 26 | GRANT ALL ON t_glob_temptable1 TO test_gtt1,test_gtt2; 27 | 28 | -- Create a GTT like table to test ON COMMIT DELETE ROWS using CREATE GLOBAL TEMPORARY syntax 29 | SELECT pgtt_schema.pgtt_create_table('t_glob_temptable2', 'SELECT id, lbl FROM t_glob_temptable1', false); 30 | -- This syntax is not yet available 31 | -- CREATE GLOBAL TEMPORARY TABLE t_glob_temptable2 AS (SELECT id, lbl FROM t_glob_temptable1) ON COMMIT DELETE ROWS; 32 | GRANT ALL ON t_glob_temptable2 TO test_gtt1,test_gtt2; 33 | 34 | CREATE SCHEMA foo; 35 | GRANT ALL ON SCHEMA foo TO test_gtt1,test_gtt2; 36 | SELECT pgtt_schema.pgtt_create_table('t_glob_temptable1', 'id integer, lbl text', true, 'foo'); 37 | GRANT ALL ON foo.t_glob_temptable1 TO test_gtt1,test_gtt2; 38 | 39 | CREATE FUNCTION check_pgtt_count (tbname name, nspname name DEFAULT 'public') RETURNS bigint AS $$ 40 | DECLARE 41 | v_relid oid; 42 | ret bigint; 43 | BEGIN 44 | EXECUTE format('SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = %L AND n.nspname = %L', tbname, nspname) INTO v_relid; 45 | EXECUTE format('SELECT relid FROM pgtt_schema.pgtt_global_temp WHERE viewid=%s', v_relid) INTO v_relid; 46 | EXECUTE 'SELECT count(*) FROM pgtt_schema.pgtt_'||v_relid INTO ret; 47 | RETURN ret; 48 | END 49 | $$ LANGUAGE plpgsql; 50 | GRANT EXECUTE ON FUNCTION check_pgtt_count TO PUBLIC; 51 | 52 | ---- 53 | -- Test ON COMMIT PRESERVE ROWS feature 54 | ---- 55 | 56 | -- Connect as test_gtt1 user 57 | \c gtt_testdb test_gtt1 58 | 59 | -- Insert 3 record in the view 60 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(1,3); 61 | 62 | -- Should return 3 as we are still in the same session 63 | SELECT count(*) FROM t_glob_temptable1; 64 | 65 | BEGIN; 66 | -- Insert 3 record in the view 67 | INSERT INTO foo.t_glob_temptable1 SELECT * FROM generate_series(1,3); 68 | 69 | -- Add a SAVEPOINT to increase the transaction id 70 | SAVEPOINT sp_foo; 71 | 72 | -- Should return 3 as we are still in the same transaction 73 | SELECT count(*) FROM foo.t_glob_temptable1; 74 | 75 | COMMIT; 76 | 77 | -- Should return 0 as we are still in the same session 78 | SELECT count(*) FROM foo.t_glob_temptable1; 79 | 80 | -- Reconnect as test_gtt2 user, data must not be visible anymore unless to be superuser 81 | \c - test_gtt2 82 | 83 | -- From the view it must return 0 row 84 | SELECT count(*) FROM t_glob_temptable1; 85 | 86 | -- from the table directly too 87 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 88 | 89 | -- Insert some other records and select them 90 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(4,6); 91 | 92 | -- must returns the last 3 records saved 93 | SELECT count(*) FROM t_glob_temptable1; 94 | 95 | -- Reconnect as test_gtt1 old and test_gtt2 data must not be visible 96 | \c - test_gtt1 97 | 98 | -- Insert some other records and select them 99 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(7,9); 100 | 101 | -- Only last inserted records should be visible, 3 rows 102 | SELECT count(*) FROM t_glob_temptable1; 103 | 104 | -- even from the unlogged table 105 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 106 | 107 | -- Verify that from a superuser point of view everything is visible 108 | \c - postgres 109 | 110 | -- Everything is visible as superuser are not limited by RLS, 9 rows 111 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 112 | 113 | -- Nothing must appears here as we are looking through the view filter 114 | SELECT count(*) FROM t_glob_temptable1 ; 115 | 116 | -- Connect again as test_gtt2 user to test DELETE an UPDATE statements 117 | \c - test_gtt2 118 | 119 | -- Nothing must be deleted 120 | DELETE FROM t_glob_temptable1 ; 121 | 122 | -- Insert some other records into the view 123 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(10,12); 124 | 125 | -- then the last three records must be returned 126 | SELECT count(*) FROM t_glob_temptable1 ; 127 | 128 | -- Same with a direct select from the unlogged table 129 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 130 | 131 | -- Ok delete every thing from the view, only 3 records may have been deleted 132 | DELETE FROM t_glob_temptable1 ; 133 | 134 | -- And a new select must return nothing 135 | SELECT count(*) FROM t_glob_temptable1 ; 136 | 137 | -- Insert some new records for update testing 138 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(10,12); 139 | 140 | -- Increment all visible records from the table, 3 record must be updated 141 | UPDATE t_glob_temptable1 SET id=id+1; 142 | 143 | -- Look at individual the records, each must return one line 144 | SELECT count(*) FROM t_glob_temptable1 WHERE id=11; 145 | SELECT count(*) FROM t_glob_temptable1 WHERE id=12; 146 | SELECT count(*) FROM t_glob_temptable1 WHERE id=13; 147 | 148 | -- Update directly from table, we must have the same behavior 149 | DO $$ 150 | DECLARE 151 | v_relid oid; 152 | BEGIN 153 | SELECT c.oid INTO v_relid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 't_glob_temptable1' AND n.nspname = 'public'; 154 | EXECUTE format('SELECT relid FROM pgtt_schema.pgtt_global_temp WHERE viewid=%s', v_relid) INTO v_relid; 155 | EXECUTE 'UPDATE pgtt_schema.pgtt_'||v_relid||' SET id=id+1'; 156 | END 157 | $$; 158 | 159 | SELECT count(*) FROM t_glob_temptable1 WHERE id=12; 160 | SELECT count(*) FROM t_glob_temptable1 WHERE id=13; 161 | SELECT count(*) FROM t_glob_temptable1 WHERE id=14; 162 | 163 | \c - postgres 164 | 165 | -- Everything is visible as superuser are not limited by RLS, must 166 | -- return 12 records with a hole on id = 10 and id = 11 167 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 168 | 169 | -- Nothing must appears here as we are looking through the view filter 170 | SELECT count(*) FROM t_glob_temptable1 ; 171 | 172 | ---- 173 | -- Test ON COMMIT DELETE ROWS feature 174 | ---- 175 | 176 | -- Nothing must be return by this query as we have not inserted any row 177 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 178 | 179 | -- Connect as simple user to process some test 180 | \c - test_gtt1 181 | 182 | -- Insert some records now in a transaction 183 | BEGIN; 184 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(1,3); 185 | -- Must return 3 186 | SELECT count(*) FROM t_glob_temptable2; 187 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(4,6); 188 | -- Both select must return 6 189 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 190 | COMMIT; 191 | 192 | -- Outside the transaction nothing must be visible 193 | SELECT count(*) FROM t_glob_temptable2; 194 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 195 | 196 | \c - test_gtt2 197 | 198 | -- Insert some more records in a transaction 199 | BEGIN; 200 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(7,9); 201 | -- must return 3 202 | SELECT count(*) FROM t_glob_temptable2; 203 | DELETE FROM t_glob_temptable2; 204 | -- must return 0 205 | SELECT count(*) FROM t_glob_temptable2; 206 | COMMIT; 207 | 208 | -- Outside the transaction nothing must be visible 209 | SELECT count(*) FROM t_glob_temptable2; 210 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 211 | 212 | \c - test_gtt2 213 | 214 | -- Insert some more rows to test UPDATE 215 | BEGIN; 216 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(10,12); 217 | -- Both select must return 3 218 | SELECT count(*) FROM t_glob_temptable2; 219 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 220 | 221 | -- 3 rows must be updated 222 | UPDATE t_glob_temptable2 SET id=id+1; 223 | -- The following select must return 1 each 224 | SELECT count(*) FROM t_glob_temptable2 WHERE id=11; 225 | SELECT count(*) FROM t_glob_temptable2 WHERE id=12; 226 | SELECT count(*) FROM t_glob_temptable2 WHERE id=13; 227 | COMMIT; 228 | 229 | -- Outside the transaction nothing must be visible 230 | SELECT count(*) FROM t_glob_temptable2; 231 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 232 | 233 | -- Check for ROLLBACK but obviously no rows are expected at output 234 | BEGIN; 235 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(14,16); 236 | -- Both select must return 3 237 | SELECT count(*) FROM t_glob_temptable2; 238 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 239 | ROLLBACK; 240 | 241 | -- Outside the transaction nothing must be visible 242 | SELECT count(*) FROM t_glob_temptable2; 243 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 244 | 245 | \c - postgres 246 | 247 | -- Everything is visible as superuser are not limited by RLS, must 248 | -- return 9 records with a hole on id between 7 and 10 249 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 250 | 251 | -- Nothing must appears here as we are looking through the view filter 252 | SELECT count(*) FROM t_glob_temptable2; 253 | 254 | -- Drop the global temporary tables using the two syntax 255 | SELECT pgtt_schema.pgtt_drop_table('t_glob_temptable1'); 256 | -- This syntax is not yet available 257 | -- DROP TABLE t_glob_temptable2; 258 | SELECT pgtt_schema.pgtt_drop_table('t_glob_temptable2'); 259 | -- This syntax is not yet available 260 | -- DROP TABLE t_glob_temptable2; 261 | SELECT pgtt_schema.pgtt_drop_table('t_glob_temptable1', 'foo'); 262 | 263 | -- Tests of the LSID related functions 264 | -- Must return {1527703231,11007} 265 | SELECT generate_lsid(1527703231, 11007); 266 | -- Must return 1527703231 267 | SELECT get_session_start_time(generate_lsid(1527703231, 11007)); 268 | -- Must return 11007 269 | SELECT get_session_pid(generate_lsid(1527703231, 11007)); 270 | 271 | -- Tests of the custom operators 272 | -- Must return false 273 | SELECT generate_lsid(1527703231, 11007) > generate_lsid(1527703232, 11007); 274 | -- Must return true 275 | SELECT generate_lsid(1527703231, 11007) >= generate_lsid(1527703231, 11007); 276 | -- Must return true 277 | SELECT generate_lsid(1527703231, 11007) <= generate_lsid(1527703231, 11007); 278 | -- Must return true 279 | SELECT generate_lsid(1527703231,11007) > generate_lsid(1527703230,11007); 280 | -- Must return true 281 | SELECT generate_lsid(1527703231,11007) > generate_lsid(1527703231,11006); 282 | -- Must return false 283 | SELECT generate_lsid(1527703231,11007) > generate_lsid(1527703231,11008); 284 | -- Must return true 285 | SELECT generate_lsid(1527703231,11007) = generate_lsid(1527703231,11007); 286 | -- Must return false 287 | SELECT generate_lsid(1527703231,11007) = generate_lsid(1527703231,11008); 288 | -- Must return false 289 | SELECT generate_lsid(1527703231,11007) = generate_lsid(1527703230,11007); 290 | 291 | \c postgres 292 | 293 | -- -- Clean all 294 | DROP DATABASE gtt_testdb; 295 | DROP ROLE test_gtt2; 296 | DROP ROLE test_gtt1; 297 | 298 | -------------------------------------------------------------------------------- /test/test_gtt2.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Regression test to Global Temporary Table RSL implementation with 3 | -- CREATE GLOBAL TEMPORARY and DROP TABLE syntax. 4 | -- 5 | -- LANG=C psql -f test/test_gtt2.sql > result.txt 2>&1 6 | -- diff result.txt test/expected/test_gtt2.txt 7 | ---- 8 | DROP DATABASE IF EXISTS gtt_testdb; 9 | DROP ROLE IF EXISTS test_gtt1; 10 | DROP ROLE IF EXISTS test_gtt2; 11 | CREATE ROLE test_gtt1 LOGIN PASSWORD 'test_gtt1'; 12 | CREATE ROLE test_gtt2 LOGIN PASSWORD 'test_gtt2'; 13 | 14 | CREATE DATABASE gtt_testdb OWNER test_gtt1 ; 15 | 16 | -- Connect as superuser 17 | \c gtt_testdb 18 | 19 | -- Create the PostgreSQL extension 20 | CREATE EXTENSION pgtt_rsl; 21 | 22 | -- Create a GTT like table to test ON COMMIT PRESERVE ROWS 23 | CREATE GLOBAL TEMPORARY TABLE t_glob_temptable1 (id integer, lbl text) ON COMMIT PRESERVE ROWS; 24 | GRANT ALL ON t_glob_temptable1 TO test_gtt1,test_gtt2; 25 | 26 | -- Create a GTT like table to test ON COMMIT DELETE ROWS using CREATE GLOBAL TEMPORARY syntax 27 | CREATE GLOBAL TEMPORARY TABLE t_glob_temptable2 ON COMMIT DELETE ROWS AS (SELECT id, lbl FROM t_glob_temptable1); 28 | GRANT ALL ON t_glob_temptable2 TO test_gtt1,test_gtt2; 29 | 30 | CREATE SCHEMA foo; 31 | GRANT ALL ON SCHEMA foo TO test_gtt1,test_gtt2; 32 | CREATE GLOBAL TEMPORARY TABLE foo.t_glob_temptable1 (id integer, lbl text) ON COMMIT PRESERVE ROWS; 33 | GRANT ALL ON foo.t_glob_temptable1 TO test_gtt1,test_gtt2; 34 | 35 | CREATE FUNCTION check_pgtt_count (tbname name, nspname name DEFAULT 'public') RETURNS bigint AS $$ 36 | DECLARE 37 | v_relid oid; 38 | ret bigint; 39 | BEGIN 40 | EXECUTE format('SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = %L AND n.nspname = %L', tbname, nspname) INTO v_relid; 41 | EXECUTE format('SELECT relid FROM pgtt_schema.pgtt_global_temp WHERE viewid=%s', v_relid) INTO v_relid; 42 | EXECUTE 'SELECT count(*) FROM pgtt_schema.pgtt_'||v_relid INTO ret; 43 | RETURN ret; 44 | END 45 | $$ LANGUAGE plpgsql; 46 | GRANT EXECUTE ON FUNCTION check_pgtt_count TO PUBLIC; 47 | 48 | ---- 49 | -- Test ON COMMIT PRESERVE ROWS feature 50 | ---- 51 | 52 | -- Connect as test_gtt1 user 53 | \c gtt_testdb test_gtt1 54 | 55 | -- Insert 3 record in the view 56 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(1,3); 57 | 58 | -- Should return 3 as we are still in the same session 59 | SELECT count(*) FROM t_glob_temptable1; 60 | 61 | BEGIN; 62 | -- Insert 3 record in the view 63 | INSERT INTO foo.t_glob_temptable1 SELECT * FROM generate_series(1,3); 64 | 65 | -- Add a SAVEPOINT to increase the transaction id 66 | SAVEPOINT sp_foo; 67 | 68 | -- Should return 3 as we are still in the same transaction 69 | SELECT count(*) FROM foo.t_glob_temptable1; 70 | 71 | COMMIT; 72 | 73 | -- Should return 0 as we are still in the same session 74 | SELECT count(*) FROM foo.t_glob_temptable1; 75 | 76 | -- Reconnect as test_gtt2 user, data must not be visible anymore unless to be superuser 77 | \c - test_gtt2 78 | 79 | -- From the view it must return 0 row 80 | SELECT count(*) FROM t_glob_temptable1; 81 | 82 | -- from the table directly too 83 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 84 | 85 | -- Insert some other records and select them 86 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(4,6); 87 | 88 | -- must returns the last 3 records saved 89 | SELECT count(*) FROM t_glob_temptable1; 90 | 91 | -- Reconnect as test_gtt1 old and test_gtt2 data must not be visible 92 | \c - test_gtt1 93 | 94 | -- Insert some other records and select them 95 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(7,9); 96 | 97 | -- Only last inserted records should be visible, 3 rows 98 | SELECT count(*) FROM t_glob_temptable1; 99 | 100 | -- even from the unlogged table 101 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 102 | 103 | -- Verify that from a superuser point of view everything is visible 104 | \c - postgres 105 | 106 | -- Everything is visible as superuser are not limited by RLS, 9 rows 107 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 108 | 109 | -- Nothing must appears here as we are looking through the view filter 110 | SELECT count(*) FROM t_glob_temptable1 ; 111 | 112 | -- Connect again as test_gtt2 user to test DELETE an UPDATE statements 113 | \c - test_gtt2 114 | 115 | -- Nothing must be deleted 116 | DELETE FROM t_glob_temptable1 ; 117 | 118 | -- Insert some other records into the view 119 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(10,12); 120 | 121 | -- then the last three records must be returned 122 | SELECT count(*) FROM t_glob_temptable1 ; 123 | 124 | -- Same with a direct select from the unlogged table 125 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 126 | 127 | -- Ok delete every thing from the view, only 3 records may have been deleted 128 | DELETE FROM t_glob_temptable1 ; 129 | 130 | -- And a new select must return nothing 131 | SELECT count(*) FROM t_glob_temptable1 ; 132 | 133 | -- Insert some new records for update testing 134 | INSERT INTO t_glob_temptable1 SELECT * FROM generate_series(10,12); 135 | 136 | -- Increment all visible records from the table, 3 record must be updated 137 | UPDATE t_glob_temptable1 SET id=id+1; 138 | 139 | -- Look at individual the records, each must return one line 140 | SELECT count(*) FROM t_glob_temptable1 WHERE id=11; 141 | SELECT count(*) FROM t_glob_temptable1 WHERE id=12; 142 | SELECT count(*) FROM t_glob_temptable1 WHERE id=13; 143 | 144 | -- Update directly from table, we must have the same behavior 145 | DO $$ 146 | DECLARE 147 | v_relid oid; 148 | BEGIN 149 | SELECT c.oid INTO v_relid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 't_glob_temptable1' AND n.nspname = 'public'; 150 | EXECUTE format('SELECT relid FROM pgtt_schema.pgtt_global_temp WHERE viewid=%s', v_relid) INTO v_relid; 151 | EXECUTE 'UPDATE pgtt_schema.pgtt_'||v_relid||' SET id=id+1'; 152 | END 153 | $$; 154 | 155 | SELECT count(*) FROM t_glob_temptable1 WHERE id=12; 156 | SELECT count(*) FROM t_glob_temptable1 WHERE id=13; 157 | SELECT count(*) FROM t_glob_temptable1 WHERE id=14; 158 | 159 | \c - postgres 160 | 161 | -- Everything is visible as superuser are not limited by RLS, must 162 | -- return 12 records with a hole on id = 10 and id = 11 163 | SELECT check_pgtt_count('t_glob_temptable1') AS "count"; 164 | 165 | -- Nothing must appears here as we are looking through the view filter 166 | SELECT count(*) FROM t_glob_temptable1 ; 167 | 168 | ---- 169 | -- Test ON COMMIT DELETE ROWS feature 170 | ---- 171 | 172 | -- Nothing must be return by this query as we have not inserted any row 173 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 174 | 175 | -- Connect as simple user to process some test 176 | \c - test_gtt1 177 | 178 | -- Insert some records now in a transaction 179 | BEGIN; 180 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(1,3); 181 | -- Must return 3 182 | SELECT count(*) FROM t_glob_temptable2; 183 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(4,6); 184 | -- Both select must return 6 185 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 186 | COMMIT; 187 | 188 | -- Outside the transaction nothing must be visible 189 | SELECT count(*) FROM t_glob_temptable2; 190 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 191 | 192 | \c - test_gtt2 193 | 194 | -- Insert some more records in a transaction 195 | BEGIN; 196 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(7,9); 197 | -- must return 3 198 | SELECT count(*) FROM t_glob_temptable2; 199 | DELETE FROM t_glob_temptable2; 200 | -- must return 0 201 | SELECT count(*) FROM t_glob_temptable2; 202 | COMMIT; 203 | 204 | -- Outside the transaction nothing must be visible 205 | SELECT count(*) FROM t_glob_temptable2; 206 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 207 | 208 | \c - test_gtt2 209 | 210 | -- Insert some more rows to test UPDATE 211 | BEGIN; 212 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(10,12); 213 | -- Both select must return 3 214 | SELECT count(*) FROM t_glob_temptable2; 215 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 216 | 217 | -- 3 rows must be updated 218 | UPDATE t_glob_temptable2 SET id=id+1; 219 | -- The following select must return 1 each 220 | SELECT count(*) FROM t_glob_temptable2 WHERE id=11; 221 | SELECT count(*) FROM t_glob_temptable2 WHERE id=12; 222 | SELECT count(*) FROM t_glob_temptable2 WHERE id=13; 223 | COMMIT; 224 | 225 | -- Outside the transaction nothing must be visible 226 | SELECT count(*) FROM t_glob_temptable2; 227 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 228 | 229 | -- Check for ROLLBACK but obviously no rows are expected at output 230 | BEGIN; 231 | INSERT INTO t_glob_temptable2 SELECT * FROM generate_series(14,16); 232 | -- Both select must return 3 233 | SELECT count(*) FROM t_glob_temptable2; 234 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 235 | ROLLBACK; 236 | 237 | -- Outside the transaction nothing must be visible 238 | SELECT count(*) FROM t_glob_temptable2; 239 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 240 | 241 | \c - postgres 242 | 243 | -- Everything is visible as superuser are not limited by RLS, must 244 | -- return 9 records with a hole on id between 7 and 10 245 | SELECT check_pgtt_count('t_glob_temptable2') AS "count"; 246 | 247 | -- Nothing must appears here as we are looking through the view filter 248 | SELECT count(*) FROM t_glob_temptable2; 249 | 250 | -- Drop the global temporary tables using the two syntax 251 | DROP TABLE t_glob_temptable1; 252 | DROP TABLE t_glob_temptable2; 253 | DROP TABLE foo.t_glob_temptable1; 254 | 255 | -- Tests of the LSID related functions 256 | -- Must return {1527703231,11007} 257 | SELECT generate_lsid(1527703231, 11007); 258 | -- Must return 1527703231 259 | SELECT get_session_start_time(generate_lsid(1527703231, 11007)); 260 | -- Must return 11007 261 | SELECT get_session_pid(generate_lsid(1527703231, 11007)); 262 | 263 | -- Tests of the custom operators 264 | -- Must return false 265 | SELECT generate_lsid(1527703231, 11007) > generate_lsid(1527703232, 11007); 266 | -- Must return true 267 | SELECT generate_lsid(1527703231, 11007) >= generate_lsid(1527703231, 11007); 268 | -- Must return true 269 | SELECT generate_lsid(1527703231, 11007) <= generate_lsid(1527703231, 11007); 270 | -- Must return true 271 | SELECT generate_lsid(1527703231,11007) > generate_lsid(1527703230,11007); 272 | -- Must return true 273 | SELECT generate_lsid(1527703231,11007) > generate_lsid(1527703231,11006); 274 | -- Must return false 275 | SELECT generate_lsid(1527703231,11007) > generate_lsid(1527703231,11008); 276 | -- Must return true 277 | SELECT generate_lsid(1527703231,11007) = generate_lsid(1527703231,11007); 278 | -- Must return false 279 | SELECT generate_lsid(1527703231,11007) = generate_lsid(1527703231,11008); 280 | -- Must return false 281 | SELECT generate_lsid(1527703231,11007) = generate_lsid(1527703230,11007); 282 | 283 | \c postgres 284 | 285 | -- -- Clean all 286 | DROP DATABASE gtt_testdb; 287 | DROP ROLE test_gtt2; 288 | DROP ROLE test_gtt1; 289 | 290 | -------------------------------------------------------------------------------- /updates/pgtt_rsl--1.2.0--1.3.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 2 | \echo Use "ALTER EXTENSION pgtt_rsl" to load this file. \quit 3 | 4 | -------------------------------------------------------------------------------- /updates/pgtt_rsl--1.3.0--2.0.0.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION pgtt_schema.pgtt_create_table (tb_name name, code text, preserved boolean DEFAULT false, relnspname name DEFAULT 'public') 2 | RETURNS boolean 3 | AS $$ 4 | DECLARE 5 | qbased text DEFAULT NULL; 6 | column_list text; 7 | relid oid; 8 | BEGIN 9 | -- Compute the query to create the global temporary table 10 | 11 | -- Look if the table is created from a SELECT/WITH statement or not 12 | SELECT REGEXP_MATCHES(code, E'^(SELECT|WITH)', 'i') INTO qbased; 13 | IF qbased IS NULL THEN 14 | -- With a basic declaration 15 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.%I (%s)', tb_name, code); 16 | ELSE 17 | -- With a declaration based on a query 18 | EXECUTE format('CREATE UNLOGGED TABLE pgtt_schema.%I AS %s', tb_name, code); 19 | END IF; 20 | -- Append pgtt_sessid "internal" column to the GTT table 21 | EXECUTE format('ALTER TABLE pgtt_schema.%I ADD COLUMN pgtt_sessid lsid DEFAULT get_session_id()', tb_name); 22 | 23 | -- Get the oid of the relation and rename it using this oid. 24 | SELECT c.oid INTO relid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = tb_name AND n.nspname = 'pgtt_schema'; 25 | EXECUTE format('ALTER TABLE pgtt_schema.%I RENAME TO pgtt_%s', tb_name, relid); 26 | 27 | -- Create an index on pgtt_sessid column, this will slow 28 | -- down insert but this will help for select from the view 29 | EXECUTE format('CREATE INDEX ON pgtt_schema.pgtt_%s (pgtt_sessid)', relid); 30 | 31 | -- Allow all on the global temporary table except 32 | -- truncate and drop to everyone 33 | EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON pgtt_schema.pgtt_%s TO PUBLIC', relid); 34 | 35 | -- Activate RLS to set policy based on session 36 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s ENABLE ROW LEVEL SECURITY', relid); 37 | 38 | -- if ON COMMIT PRESERVE ROWS is enabled 39 | IF preserved THEN 40 | -- Create the policy that must be applied on the table 41 | -- to show only rows where pgtt_sessid is the same as 42 | -- current pid. 43 | EXECUTE format('CREATE POLICY pgtt_rls_session ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id()) WITH CHECK (true)', relid); 44 | ELSE 45 | -- Create the policy that must be applied on the table 46 | -- to show only rows where pgtt_sessid is the same as 47 | -- current pid and rows that have been created in the 48 | -- current transaction. 49 | EXECUTE format('CREATE POLICY pgtt_rls_transaction ON pgtt_schema.pgtt_%s USING (pgtt_sessid = get_session_id() AND xmin::text >= txid_current()::text) WITH CHECK (true)', relid); 50 | END IF; 51 | -- Force policy to be active for the owner of the table 52 | EXECUTE format('ALTER TABLE pgtt_schema.pgtt_%s FORCE ROW LEVEL SECURITY', relid); 53 | 54 | -- Collect all visible column of the table attnum >= 1 as 55 | -- column pgtt_sessid must not be reported by the view. 56 | SELECT string_agg(attname, ',' ORDER BY attnum) INTO column_list FROM pg_attribute WHERE attrelid=('pgtt_schema.pgtt_'||relid)::regclass AND attname != 'pgtt_sessid' AND attnum >= 1 AND NOT attisdropped; 57 | 58 | -- Create a view named as the table name given by the user 59 | -- so that he will only deal with this name, and never the 60 | -- internal name of the corresponding table prefixed with 61 | -- pgtt_. The view is also used to hide the pgtt_sessid column. 62 | IF preserved THEN 63 | EXECUTE format('CREATE VIEW %I.%I WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id()', relnspname, tb_name, column_list, relid); 64 | ELSE 65 | EXECUTE format('CREATE VIEW %I.%I WITH (security_barrier) AS SELECT %s from pgtt_schema.pgtt_%s WHERE pgtt_sessid=get_session_id() AND xmin::text >= txid_current()::text', relnspname, tb_name, column_list, relid); 66 | END IF; 67 | 68 | -- Set owner of the view to session user, not the function definer (superuser) 69 | EXECUTE format('ALTER VIEW %I.%I OWNER TO %s', relnspname, tb_name, session_user); 70 | 71 | -- Allow read+write to every one on this view - disable here because the 72 | -- owner is responsible of setting privilege on this view 73 | -- EXECUTE format('GRANT SELECT,INSERT,UPDATE,DELETE ON %s TO PUBLIC', tb_name); 74 | 75 | -- Register the link between the view and the unlogged table 76 | EXECUTE format('INSERT INTO pgtt_schema.pgtt_global_temp (relid, viewid, datcrea, preserved) VALUES (%s, %s, now(), %L)', 77 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = 'pgtt_'||relid AND n.nspname = 'pgtt_schema'), 78 | (SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = tb_name AND n.nspname = relnspname), preserved); 79 | 80 | RETURN true; 81 | END; 82 | $$ 83 | LANGUAGE plpgsql SECURITY DEFINER; 84 | 85 | CREATE OR REPLACE FUNCTION pgtt_schema.pgtt_drop_table (tb_name name, nspname name DEFAULT 'public') 86 | RETURNS boolean 87 | AS $$ 88 | DECLARE 89 | relid oid; 90 | BEGIN 91 | -- Get the view Oid 92 | EXECUTE format('SELECT c.oid FROM pg_class c JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE c.relname = %L AND n.nspname = %L', tb_name, nspname) INTO relid; 93 | -- Unregister the table/view relation from pgtt_schema.pgtt_global_temp table and return the relation oid 94 | EXECUTE format('DELETE FROM pgtt_schema.pgtt_global_temp WHERE viewid=%s RETURNING relid', relid) INTO relid; 95 | -- Compute the query to remove the global temporary table and 96 | -- related objects, with CASCADE associated view will be removed. 97 | EXECUTE format('DROP TABLE IF EXISTS pgtt_schema.pgtt_%s CASCADE', relid); 98 | 99 | RETURN true; 100 | END; 101 | $$ 102 | LANGUAGE plpgsql SECURITY DEFINER; 103 | 104 | CREATE OR REPLACE FUNCTION pgtt_schema.pgtt_maintenance (iter integer DEFAULT 1, chunk_size integer DEFAULT 250000, analyze_table boolean DEFAULT false) 105 | RETURNS bigint 106 | AS $$ 107 | DECLARE 108 | cur_gtt_tables CURSOR FOR SELECT viewid,relid,preserved FROM pgtt_schema.pgtt_global_temp; 109 | class_info RECORD; 110 | query text; 111 | rec RECORD; 112 | nrows bigint; 113 | total_nrows bigint; 114 | alive integer; 115 | relid oid; 116 | BEGIN 117 | total_nrows := 0; 118 | 119 | -- For all global temporary tables defined in pgtt_schema.pgtt_global_temp 120 | OPEN cur_gtt_tables; 121 | LOOP 122 | FETCH NEXT FROM cur_gtt_tables INTO class_info; 123 | EXIT WHEN NOT FOUND; 124 | -- Check if the table have been removed with a direct DROP+CASCADE 125 | EXECUTE 'SELECT oid FROM pg_class WHERE oid=' || class_info.relid INTO relid; 126 | IF relid IS NULL THEN 127 | -- Cleanup all references to this table in our GTT registery table 128 | EXECUTE 'DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=' || class_info.relid; 129 | CONTINUE; 130 | END IF; 131 | -- Check if the view have been removed with a direct DROP 132 | EXECUTE 'SELECT oid FROM pg_class WHERE oid=' || class_info.viewid INTO relid; 133 | IF relid IS NULL THEN 134 | -- Drop the table if it is not already the case 135 | EXECUTE 'DROP TABLE pgtt_schema.pgtt_' || class_info.relid; 136 | -- Cleanup all references to this table 137 | EXECUTE 'DELETE FROM pgtt_schema.pgtt_global_temp WHERE relid=' || class_info.relid; 138 | CONTINUE; 139 | END IF; 140 | 141 | -- At startup iter = 0 then we just have to truncate the table 142 | IF (iter = 0) THEN 143 | EXECUTE 'TRUNCATE ' || class_info.relid::regclass; 144 | -- RAISE LOG 'GTT table "%" has been truncated at startup.', class_info.relid::regclass; 145 | CONTINUE; 146 | END IF; 147 | 148 | -- With a GTT that preserves tuples in an entire session 149 | IF (class_info.preserved) THEN 150 | -- delete rows from the GTT table that do not belong to an active session 151 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (pgtt_sessid = ANY(ARRAY(SELECT generate_lsid(extract(epoch from backend_start)::int, pid) FROM pg_stat_activity))) LIMIT ' || chunk_size || '))'; 152 | 153 | GET DIAGNOSTICS nrows = ROW_COUNT; 154 | total_nrows := total_nrows + nrows; 155 | -- With GTT where tuples do not survive a transaction 156 | ELSE 157 | -- delete rows from the GTT table that do not belong to an active transaction 158 | EXECUTE 'DELETE FROM ' || class_info.relid::regclass || ' WHERE ctid = ANY(ARRAY(SELECT ctid FROM ' || class_info.relid::regclass || ' WHERE NOT (xmin = ANY(ARRAY(SELECT DISTINCT backend_xmin FROM pg_stat_activity WHERE backend_xmin IS NOT NULL))) LIMIT ' || chunk_size || '))'; 159 | GET DIAGNOSTICS nrows = ROW_COUNT; 160 | total_nrows := total_nrows + nrows; 161 | END IF; 162 | 163 | -- Force an analyze of the table if required 164 | IF analyze_table AND total_nrows > 0 THEN 165 | EXECUTE 'ANALYZE ' || class_info.relid::regclass; 166 | END IF; 167 | END LOOP; 168 | CLOSE cur_gtt_tables; 169 | 170 | RETURN total_nrows; 171 | END; 172 | $$ 173 | LANGUAGE plpgsql SECURITY DEFINER; 174 | --------------------------------------------------------------------------------