├── .editorconfig ├── .gitignore ├── .travis.yml ├── COPYRIGHT.dbms_sql ├── INSTALL.dbms_sql ├── Makefile ├── NEWS ├── README.md ├── dbms_sql--1.0.sql ├── dbms_sql.c ├── dbms_sql.control ├── expected ├── dbms_sql.out └── init.out └── sql ├── dbms_sql.sql └── init.sql /.editorconfig: -------------------------------------------------------------------------------- 1 | root = true 2 | 3 | [*.{c,h,l,y,pl,pm}] 4 | indent_style = tab 5 | indent_size = tab 6 | tab_width = 4 7 | 8 | [*.{sgml,xml}] 9 | indent_style = space 10 | indent_size = 1 11 | 12 | [*.xsl] 13 | indent_style = space 14 | indent_size = 2 15 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Prerequisites 2 | *.d 3 | 4 | # Object files 5 | *.o 6 | *.ko 7 | *.obj 8 | *.elf 9 | 10 | # Linker output 11 | *.ilk 12 | *.map 13 | *.exp 14 | 15 | # Precompiled Headers 16 | *.gch 17 | *.pch 18 | 19 | # Libraries 20 | *.lib 21 | *.a 22 | *.la 23 | *.lo 24 | 25 | # Shared objects (inc. Windows DLLs) 26 | *.dll 27 | *.so 28 | *.so.* 29 | *.dylib 30 | 31 | # Executables 32 | *.exe 33 | *.out 34 | *.app 35 | *.i*86 36 | *.x86_64 37 | *.hex 38 | 39 | # Debug files 40 | *.dSYM/ 41 | *.su 42 | *.idb 43 | *.pdb 44 | 45 | # Kernel Module Compile Results 46 | *.mod* 47 | *.cmd 48 | .tmp_versions/ 49 | modules.order 50 | Module.symvers 51 | Mkfile.old 52 | dkms.conf 53 | pspg 54 | 55 | /config.cache 56 | /config.log 57 | /config.status 58 | /config.make -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | # run the testsuite on travis-ci.org 2 | --- 3 | # run once for each of these 4 | env: 5 | - PGVERSION=11 6 | - PGVERSION=12 7 | - PGVERSION=13 8 | 9 | language: C 10 | dist: xenial 11 | sudo: required 12 | 13 | before_install: 14 | - sudo apt-get update -qq 15 | 16 | install: 17 | # remove all existing clusters 18 | - sudo rm -rf /etc/postgresql /var/lib/postgresql 19 | # upgrade postgresql-common for new apt.postgresql.org.sh 20 | - sudo apt-get install -y postgresql-common 21 | - sudo /usr/share/postgresql-common/pgdg/apt.postgresql.org.sh -p -v $PGVERSION -i 22 | - sudo apt-get install -y libicu-dev libssl-dev 23 | - sudo -u postgres createuser --superuser $USER 24 | 25 | script: 26 | - make 27 | - sudo make install 28 | - make installcheck 29 | - if test -s regression.diffs; then cat regression.diffs; fi 30 | -------------------------------------------------------------------------------- /COPYRIGHT.dbms_sql: -------------------------------------------------------------------------------- 1 | 0-clause license ("Zero Clause BSD") 2 | 3 | Copyright (C) 2008-2020 by Pavel Stehule 4 | 5 | Permission to use, copy, modify, and/or distribute this software for any purpose 6 | with or without fee is hereby granted. 7 | 8 | THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES WITH 9 | REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY 10 | AND FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, 11 | INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM 12 | LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE 13 | OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR 14 | PERFORMANCE OF THIS SOFTWARE. 15 | -------------------------------------------------------------------------------- /INSTALL.dbms_sql: -------------------------------------------------------------------------------- 1 | Installation 2 | ============ 3 | 4 | This module is normally distributed as a PostgreSQL 'contrib' module. To 5 | install it from a pre-configured source tree run the following commands 6 | as a user with appropriate privileges from the orafce source directory: 7 | 8 | export NO_PGXS=1 9 | make 10 | make install 11 | 12 | Alternatively, if you have no source tree you can install using PGXS. Simply 13 | run the following commands the adminpack source directory: 14 | 15 | make 16 | make install 17 | 18 | CREATE EXTENSION dbms_sql; 19 | 20 | Other administration tools that use this module may have different requirements, 21 | please consult the tool's documentation for further details. 22 | 23 | This package requires PostgreSQL 11 or later. 24 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # $PostgreSQL: pgsql/contrib/plpgsql_check/Makefile 2 | 3 | MODULE_big = dbms_sql 4 | OBJS = dbms_sql.o 5 | DATA = dbms_sql--1.0.sql 6 | EXTENSION = dbms_sql 7 | 8 | REGRESS = init dbms_sql 9 | 10 | ifdef NO_PGXS 11 | subdir = contrib/dbms_sql 12 | top_builddir = ../.. 13 | include $(top_builddir)/src/Makefile.global 14 | include $(top_srcdir)/contrib/contrib-global.mk 15 | else 16 | PG_CONFIG = pg_config 17 | PGXS := $(shell $(PG_CONFIG) --pgxs) 18 | include $(PGXS) 19 | endif 20 | 21 | override CFLAGS += -Wextra 22 | 23 | -------------------------------------------------------------------------------- /NEWS: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/okbob/orafce_sql/76f311c75074131f4d076bf28981e5f97bc8bf6a/NEWS -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | [![Build Status](https://travis-ci.org/okbob/dbms_sql.svg?branch=master)](https://travis-ci.org/okbob/dbms_sql) 2 | 3 | # DBMS_SQL 4 | 5 | This is implementation of Oracle's API of package DBMS_SQL 6 | 7 | It doesn't ensure full compatibility, but should to decrease a work necessary for 8 | successful migration. 9 | 10 | ## Functionality 11 | 12 | This extension implements subset of Oracle's dbms_sql interface. The goal of this extension 13 | is not a compatibility with Oracle, it is designed to reduce some work related migration 14 | Oracle's applications to Postgres. Some basic bulk DML functionality is supported: 15 | 16 | do $$ 17 | declare 18 | c int; 19 | a int[]; 20 | b varchar[]; 21 | ca numeric[]; 22 | begin 23 | c := dbms_sql.open_cursor(); 24 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 25 | a := ARRAY[1, 2, 3, 4, 5]; 26 | b := ARRAY['Ahoj', 'Nazdar', 'Bazar']; 27 | ca := ARRAY[3.14, 2.22, 3.8, 4]; 28 | 29 | call dbms_sql.bind_array(c, 'a', a, 2, 3); 30 | call dbms_sql.bind_array(c, 'b', b, 3, 4); 31 | call dbms_sql.bind_array(c, 'c', ca); 32 | raise notice 'inserted rows %d', dbms_sql.execute(c); 33 | end; 34 | $$; 35 | 36 | 37 | do $$ 38 | declare 39 | c int; 40 | a int[]; 41 | b varchar[]; 42 | ca numeric[]; 43 | begin 44 | c := dbms_sql.open_cursor(); 45 | call dbms_sql.parse(c, 'select i, ''Ahoj'' || i, i + 0.003 from generate_series(1, 35) g(i)'); 46 | call dbms_sql.define_array(c, 1, a, 10, 1); 47 | call dbms_sql.define_array(c, 2, b, 10, 1); 48 | call dbms_sql.define_array(c, 3, ca, 10, 1); 49 | 50 | perform dbms_sql.execute(c); 51 | while dbms_sql.fetch_rows(c) > 0 52 | loop 53 | call dbms_sql.column_value(c, 1, a); 54 | call dbms_sql.column_value(c, 2, b); 55 | call dbms_sql.column_value(c, 3, ca); 56 | raise notice 'a = %', a; 57 | raise notice 'b = %', b; 58 | raise notice 'c = %', ca; 59 | end loop; 60 | call dbms_sql.close_cursor(c); 61 | end; 62 | $$; 63 | 64 | There is function `dbms_sql.describe_columns_f`, that is like procedure `dbms_sql.describe_columns`. 65 | Attention, the type ids are related to PostgreSQL type system. The values are not converted to Oracle's 66 | numbers 67 | 68 | do $$ 69 | declare 70 | c int; 71 | r record; 72 | d dbms_sql.desc_rec; 73 | begin 74 | c := dbms_sql.open_cursor(); 75 | call dbms_sql.parse(c, 'select * from pg_class'); 76 | r := dbms_sql.describe_columns(c); 77 | raise notice '%', r.col_cnt; 78 | 79 | foreach d in array r.desc_t 80 | loop 81 | raise notice '% %', d.col_name, d.col_type::regtype; 82 | end loop; 83 | 84 | call dbms_sql.close_cursor(c); 85 | end; 86 | $$; 87 | 88 | do $$ 89 | declare 90 | c int; 91 | n int; 92 | d dbms_sql.desc_rec; 93 | da dbms_sql.desc_rec[]; 94 | begin 95 | c := dbms_sql.open_cursor(); 96 | call dbms_sql.parse(c, 'select * from pg_class'); 97 | call dbms_sql.describe_columns(c, n, da); 98 | raise notice '%', n; 99 | 100 | foreach d in array da 101 | loop 102 | raise notice '% %', d.col_name, d.col_type::regtype; 103 | end loop; 104 | 105 | call dbms_sql.close_cursor(c); 106 | end; 107 | $$; 108 | 109 | ## Dependency 110 | 111 | When you plan to use dbms_sql extension together with Orafce, then you have to remove line 112 | with `CREATE DOMAIN varchar2 AS text;` statement from install sql script. 113 | 114 | ## ToDo 115 | -------------------------------------------------------------------------------- /dbms_sql--1.0.sql: -------------------------------------------------------------------------------- 1 | /* dbms_sql.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION dbms_sql" to load this file. \quit 5 | CREATE SCHEMA dbms_sql; 6 | 7 | /* 8 | * temp solution, at the end varchar2 from orafce will be used 9 | */ 10 | CREATE DOMAIN varchar2 AS text; -- should be removed, if you use Orafce 11 | 12 | CREATE FUNCTION dbms_sql.is_open(c int) RETURNS bool AS 'MODULE_PATHNAME', 'dbms_sql_is_open' LANGUAGE c; 13 | CREATE FUNCTION dbms_sql.open_cursor() RETURNS int AS 'MODULE_PATHNAME', 'dbms_sql_open_cursor' LANGUAGE c; 14 | CREATE PROCEDURE dbms_sql.close_cursor(c int) AS 'MODULE_PATHNAME', 'dbms_sql_close_cursor' LANGUAGE c; 15 | CREATE PROCEDURE dbms_sql.debug_cursor(c int) AS 'MODULE_PATHNAME', 'dbms_sql_debug_cursor' LANGUAGE c; 16 | CREATE PROCEDURE dbms_sql.parse(c int, stmt varchar2) AS 'MODULE_PATHNAME', 'dbms_sql_parse' LANGUAGE c; 17 | CREATE PROCEDURE dbms_sql.bind_variable(c int, name varchar2, value "any") AS 'MODULE_PATHNAME', 'dbms_sql_bind_variable' LANGUAGE c; 18 | CREATE FUNCTION dbms_sql.bind_variable_f(c int, name varchar2, value "any") RETURNS void AS 'MODULE_PATHNAME', 'dbms_sql_bind_variable_f' LANGUAGE c; 19 | CREATE PROCEDURE dbms_sql.bind_array(c int, name varchar2, value anyarray) AS 'MODULE_PATHNAME', 'dbms_sql_bind_array_3' LANGUAGE c; 20 | CREATE PROCEDURE dbms_sql.bind_array(c int, name varchar2, value anyarray, index1 int, index2 int) AS 'MODULE_PATHNAME', 'dbms_sql_bind_array_5' LANGUAGE c; 21 | CREATE PROCEDURE dbms_sql.define_column(c int, col int, value "any", column_size int DEFAULT -1) AS 'MODULE_PATHNAME', 'dbms_sql_define_column' LANGUAGE c; 22 | CREATE PROCEDURE dbms_sql.define_array(c int, col int, value "anyarray", cnt int, lower_bnd int) AS 'MODULE_PATHNAME', 'dbms_sql_define_array' LANGUAGE c; 23 | CREATE FUNCTION dbms_sql.execute(c int) RETURNS bigint AS 'MODULE_PATHNAME', 'dbms_sql_execute' LANGUAGE c; 24 | CREATE FUNCTION dbms_sql.fetch_rows(c int) RETURNS int AS 'MODULE_PATHNAME', 'dbms_sql_fetch_rows' LANGUAGE c; 25 | CREATE FUNCTION dbms_sql.execute_and_fetch(c int, exact bool DEFAULT false) RETURNS int AS 'MODULE_PATHNAME', 'dbms_sql_execute_and_fetch' LANGUAGE c; 26 | CREATE FUNCTION dbms_sql.last_row_count() RETURNS int AS 'MODULE_PATHNAME', 'dbms_sql_last_row_count' LANGUAGE c; 27 | CREATE PROCEDURE dbms_sql.column_value(c int, pos int, INOUT value anyelement) AS 'MODULE_PATHNAME', 'dbms_sql_column_value' LANGUAGE c; 28 | CREATE FUNCTION dbms_sql.column_value_f(c int, pos int, value anyelement) RETURNS anyelement AS 'MODULE_PATHNAME', 'dbms_sql_column_value_f' LANGUAGE c; 29 | 30 | CREATE TYPE dbms_sql.desc_rec AS ( 31 | col_type int, 32 | col_max_len int, 33 | col_name text, 34 | col_name_len int, 35 | col_schema text, 36 | col_schema_len int, 37 | col_precision int, 38 | col_scale int, 39 | col_charsetid int, 40 | col_charsetform int, 41 | col_null_ok boolean, 42 | col_type_name text, 43 | col_type_name_len int); 44 | 45 | CREATE FUNCTION dbms_sql.describe_columns_f(c int, OUT col_cnt int, OUT desc_t dbms_sql.desc_rec[]) AS 'MODULE_PATHNAME', 'dbms_sql_describe_columns_f' LANGUAGE c; 46 | CREATE PROCEDURE dbms_sql.describe_columns(c int, INOUT col_cnt int, INOUT desc_t dbms_sql.desc_rec[]) AS 'MODULE_PATHNAME', 'dbms_sql_describe_columns_f' LANGUAGE c; 47 | 48 | -------------------------------------------------------------------------------- /dbms_sql.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "fmgr.h" 3 | #include "funcapi.h" 4 | 5 | #if PG_VERSION_NUM < 120000 6 | 7 | #include "access/htup_details.h" 8 | 9 | #endif 10 | 11 | #include "access/tupconvert.h" 12 | #include "catalog/pg_type_d.h" 13 | #include "catalog/pg_type.h" 14 | #include "executor/spi.h" 15 | #include "lib/stringinfo.h" 16 | #include "nodes/pg_list.h" 17 | #include "parser/parse_coerce.h" 18 | #include "parser/scansup.h" 19 | #include "utils/array.h" 20 | #include "utils/builtins.h" 21 | #include "utils/datum.h" 22 | #include "utils/elog.h" 23 | #include "utils/lsyscache.h" 24 | #include "utils/syscache.h" 25 | #include "utils/memutils.h" 26 | #include "utils/typcache.h" 27 | #include "executor/spi_priv.h" 28 | 29 | PG_MODULE_MAGIC; 30 | 31 | #define MAX_CURSORS 100 32 | 33 | /* 34 | * bind variable data 35 | */ 36 | typedef struct 37 | { 38 | char *refname; 39 | int position; 40 | 41 | Datum value; 42 | 43 | Oid typoid; 44 | bool typbyval; 45 | int16 typlen; 46 | 47 | bool isnull; 48 | int varno; /* number of assigned placeholder of parsed query */ 49 | bool is_array; /* true, when a value is assigned via bind_array */ 50 | Oid typelemid; /* Oid of element of a array */ 51 | bool typelembyval; 52 | int16 typelemlen; 53 | int index1; 54 | int index2; 55 | } VariableData; 56 | 57 | /* 58 | * Query result column definition 59 | */ 60 | typedef struct 61 | { 62 | int position; 63 | 64 | Oid typoid; 65 | bool typbyval; 66 | int16 typlen; 67 | int32 typmod; 68 | bool typisstr; 69 | Oid typarrayoid; /* oid of requested array output value */ 70 | int rowcount; /* maximal rows of requested array */ 71 | int index1; /* output array should be rewrited from this index */ 72 | } ColumnData; 73 | 74 | /* 75 | * It is used for transformation result data to form 76 | * generated by column_value procedure or column 77 | * value function. 78 | */ 79 | typedef struct 80 | { 81 | bool isvalid; /* true, when this cast can be used */ 82 | bool without_cast; /* true, when cast is not necessary */ 83 | Oid targettypid; /* used for domains */ 84 | Oid array_targettypid; /* used for array domains */ 85 | int32 targettypmod; /* used for strings */ 86 | bool typbyval; /* used for copy result to outer memory context */ 87 | int16 typlen; /* used for copy result to outer memory context */ 88 | bool is_array; 89 | 90 | Oid funcoid; 91 | Oid funcoid_typmod; 92 | CoercionPathType path; 93 | CoercionPathType path_typmod; 94 | FmgrInfo finfo; 95 | FmgrInfo finfo_typmod; 96 | FmgrInfo finfo_out; 97 | FmgrInfo finfo_in; 98 | Oid typIOParam; 99 | } CastCacheData; 100 | 101 | /* 102 | * dbms_sql cursor definition 103 | */ 104 | typedef struct 105 | { 106 | int16 cid; 107 | char *parsed_query; 108 | char *original_query; 109 | int nvariables; 110 | int max_colpos; 111 | List *variables; 112 | List *columns; 113 | char cursorname[32]; 114 | Portal portal; /* one shot (execute) plan */ 115 | SPIPlanPtr plan; 116 | MemoryContext cursor_cxt; 117 | MemoryContext cursor_xact_cxt; 118 | MemoryContext tuples_cxt; 119 | MemoryContext result_cxt; /* short life memory context */ 120 | HeapTuple tuples[1000]; 121 | TupleDesc coltupdesc; 122 | TupleDesc tupdesc; 123 | CastCacheData *casts; 124 | int processed; 125 | int nread; 126 | int start_read; 127 | bool assigned; 128 | bool executed; 129 | Bitmapset *array_columns; /* set of array columns */ 130 | int batch_rows; /* how much rows should be fetched to fill target arrays */ 131 | } CursorData; 132 | 133 | typedef enum 134 | { 135 | TOKEN_SPACES, 136 | TOKEN_COMMENT, 137 | TOKEN_NUMBER, 138 | TOKEN_BIND_VAR, 139 | TOKEN_STR, 140 | TOKEN_EXT_STR, 141 | TOKEN_DOLAR_STR, 142 | TOKEN_IDENTIF, 143 | TOKEN_QIDENTIF, 144 | TOKEN_DOUBLE_COLON, 145 | TOKEN_OTHER, 146 | TOKEN_NONE 147 | } TokenType; 148 | 149 | static MemoryContext persist_cxt; 150 | static CursorData cursors[MAX_CURSORS]; 151 | 152 | static char *next_token(char *str, char **start, size_t *len, TokenType *typ, char **sep, size_t *seplen); 153 | 154 | PGDLLEXPORT Datum dbms_sql_is_open(PG_FUNCTION_ARGS); 155 | PGDLLEXPORT Datum dbms_sql_open_cursor(PG_FUNCTION_ARGS); 156 | PGDLLEXPORT Datum dbms_sql_close_cursor(PG_FUNCTION_ARGS); 157 | PGDLLEXPORT Datum dbms_sql_parse(PG_FUNCTION_ARGS); 158 | PGDLLEXPORT Datum dbms_sql_bind_variable(PG_FUNCTION_ARGS); 159 | PGDLLEXPORT Datum dbms_sql_bind_variable_f(PG_FUNCTION_ARGS); 160 | PGDLLEXPORT Datum dbms_sql_bind_array_3(PG_FUNCTION_ARGS); 161 | PGDLLEXPORT Datum dbms_sql_bind_array_5(PG_FUNCTION_ARGS); 162 | PGDLLEXPORT Datum dbms_sql_define_column(PG_FUNCTION_ARGS); 163 | PGDLLEXPORT Datum dbms_sql_define_array(PG_FUNCTION_ARGS); 164 | PGDLLEXPORT Datum dbms_sql_execute(PG_FUNCTION_ARGS); 165 | PGDLLEXPORT Datum dbms_sql_fetch_rows(PG_FUNCTION_ARGS); 166 | PGDLLEXPORT Datum dbms_sql_execute_and_fetch(PG_FUNCTION_ARGS); 167 | PGDLLEXPORT Datum dbms_sql_column_value(PG_FUNCTION_ARGS); 168 | PGDLLEXPORT Datum dbms_sql_column_value_f(PG_FUNCTION_ARGS); 169 | PGDLLEXPORT Datum dbms_sql_last_row_count(PG_FUNCTION_ARGS); 170 | PGDLLEXPORT Datum dbms_sql_describe_columns(PG_FUNCTION_ARGS); 171 | PGDLLEXPORT Datum dbms_sql_describe_columns_f(PG_FUNCTION_ARGS); 172 | PGDLLEXPORT Datum dbms_sql_debug_cursor(PG_FUNCTION_ARGS); 173 | 174 | PG_FUNCTION_INFO_V1(dbms_sql_is_open); 175 | PG_FUNCTION_INFO_V1(dbms_sql_open_cursor); 176 | PG_FUNCTION_INFO_V1(dbms_sql_close_cursor); 177 | PG_FUNCTION_INFO_V1(dbms_sql_parse); 178 | PG_FUNCTION_INFO_V1(dbms_sql_bind_variable); 179 | PG_FUNCTION_INFO_V1(dbms_sql_bind_variable_f); 180 | PG_FUNCTION_INFO_V1(dbms_sql_bind_array_3); 181 | PG_FUNCTION_INFO_V1(dbms_sql_bind_array_5); 182 | PG_FUNCTION_INFO_V1(dbms_sql_define_column); 183 | PG_FUNCTION_INFO_V1(dbms_sql_define_array); 184 | PG_FUNCTION_INFO_V1(dbms_sql_execute); 185 | PG_FUNCTION_INFO_V1(dbms_sql_fetch_rows); 186 | PG_FUNCTION_INFO_V1(dbms_sql_execute_and_fetch); 187 | PG_FUNCTION_INFO_V1(dbms_sql_column_value); 188 | PG_FUNCTION_INFO_V1(dbms_sql_column_value_f); 189 | PG_FUNCTION_INFO_V1(dbms_sql_last_row_count); 190 | PG_FUNCTION_INFO_V1(dbms_sql_describe_columns); 191 | PG_FUNCTION_INFO_V1(dbms_sql_describe_columns_f); 192 | PG_FUNCTION_INFO_V1(dbms_sql_debug_cursor); 193 | 194 | 195 | void _PG_init(void); 196 | 197 | static int last_row_count = 0; 198 | 199 | void 200 | _PG_init(void) 201 | { 202 | memset(cursors, 0, sizeof(cursors)); 203 | 204 | persist_cxt = AllocSetContextCreate(NULL, 205 | "dbms_sql persist context", 206 | ALLOCSET_DEFAULT_SIZES); 207 | } 208 | 209 | static void 210 | open_cursor(CursorData *c, int cid) 211 | { 212 | c->cid = cid; 213 | 214 | c->cursor_cxt = AllocSetContextCreate(persist_cxt, 215 | "dbms_sql cursor context", 216 | ALLOCSET_DEFAULT_SIZES); 217 | c->assigned = true; 218 | } 219 | 220 | /* 221 | * FUNCTION dbms_sql.open_cursor() RETURNS int 222 | */ 223 | Datum 224 | dbms_sql_open_cursor(PG_FUNCTION_ARGS) 225 | { 226 | int i; 227 | 228 | (void) fcinfo; 229 | 230 | /* find and initialize first free slot */ 231 | for (i = 0; i < MAX_CURSORS; i++) 232 | { 233 | if (!cursors[i].assigned) 234 | { 235 | open_cursor(&cursors[i], i); 236 | 237 | return i; 238 | } 239 | } 240 | 241 | ereport(ERROR, 242 | (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), 243 | errmsg("too many opened cursors"), 244 | errdetail("There is not free slot for new dbms_sql's cursor."), 245 | errhint("You should to close unused cursors"))); 246 | } 247 | 248 | static CursorData * 249 | get_cursor(FunctionCallInfo fcinfo, bool should_be_assigned) 250 | { 251 | CursorData *cursor; 252 | int cid; 253 | 254 | if (PG_ARGISNULL(0)) 255 | ereport(ERROR, 256 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 257 | errmsg("cursor id is NULL"))); 258 | 259 | cid = PG_GETARG_INT32(0); 260 | if (cid < 0 && cid >= MAX_CURSORS) 261 | ereport(ERROR, 262 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 263 | errmsg("value of cursor id is out of range"))); 264 | 265 | cursor = &cursors[cid]; 266 | if (!cursor->assigned && should_be_assigned) 267 | ereport(ERROR, 268 | (errcode(ERRCODE_UNDEFINED_CURSOR), 269 | errmsg("cursor is not valid"))); 270 | 271 | return cursor; 272 | } 273 | 274 | /* 275 | * CREATE FUNCTION dbms_sql.is_open(c int) RETURNS bool; 276 | */ 277 | Datum 278 | dbms_sql_is_open(PG_FUNCTION_ARGS) 279 | { 280 | CursorData *c; 281 | 282 | c = get_cursor(fcinfo, false); 283 | 284 | PG_RETURN_BOOL(c->assigned); 285 | } 286 | 287 | /* 288 | * Release all sources assigned to cursor 289 | */ 290 | static void 291 | close_cursor(CursorData *c) 292 | { 293 | if (c->executed && c->portal) 294 | SPI_cursor_close(c->portal); 295 | 296 | /* release all assigned memory */ 297 | if (c->cursor_cxt) 298 | MemoryContextDelete(c->cursor_cxt); 299 | 300 | if (c->cursor_xact_cxt) 301 | MemoryContextDelete(c->cursor_xact_cxt); 302 | 303 | if (c->plan) 304 | SPI_freeplan(c->plan); 305 | 306 | memset(c, 0, sizeof(CursorData)); 307 | } 308 | 309 | /* 310 | * PROCEDURE dbms_sql.close_cursor(c int) 311 | */ 312 | Datum 313 | dbms_sql_close_cursor(PG_FUNCTION_ARGS) 314 | { 315 | CursorData *c; 316 | 317 | c = get_cursor(fcinfo, false); 318 | 319 | close_cursor(c); 320 | 321 | return (Datum) 0; 322 | } 323 | 324 | /* 325 | * Print state of cursor - just for debug purposes 326 | */ 327 | Datum 328 | dbms_sql_debug_cursor(PG_FUNCTION_ARGS) 329 | { 330 | CursorData *c; 331 | ListCell *lc; 332 | 333 | c = get_cursor(fcinfo, false); 334 | 335 | if (c->assigned) 336 | { 337 | if (c->original_query) 338 | elog(NOTICE, "orig query: \"%s\"", c->original_query); 339 | 340 | if (c->parsed_query) 341 | elog(NOTICE, "parsed query: \"%s\"", c->parsed_query); 342 | 343 | } 344 | else 345 | elog(NOTICE, "cursor is not assigned"); 346 | 347 | foreach(lc, c->variables) 348 | { 349 | VariableData *var = (VariableData *) lfirst(lc); 350 | 351 | if (var->typoid != InvalidOid) 352 | { 353 | Oid typOutput; 354 | bool isVarlena; 355 | char *str; 356 | 357 | getTypeOutputInfo(var->typoid, &typOutput, &isVarlena); 358 | str = OidOutputFunctionCall(typOutput, var->value); 359 | 360 | elog(NOTICE, "variable \"%s\" is assigned to \"%s\"", var->refname, str); 361 | } 362 | else 363 | elog(NOTICE, "variable \"%s\" is not assigned", var->refname); 364 | } 365 | 366 | foreach(lc, c->columns) 367 | { 368 | ColumnData *col = (ColumnData *) lfirst(lc); 369 | 370 | elog(NOTICE, "column definition for position %d is %s", 371 | col->position, 372 | format_type_with_typemod(col->typoid, col->typmod)); 373 | } 374 | 375 | return (Datum) 0; 376 | } 377 | 378 | /* 379 | * Search a variable in cursor's variable list 380 | */ 381 | static VariableData * 382 | get_var(CursorData *c, char *refname, int position, bool append) 383 | { 384 | ListCell *lc; 385 | VariableData *nvar; 386 | MemoryContext oldcxt; 387 | 388 | foreach(lc, c->variables) 389 | { 390 | VariableData *var = (VariableData *) lfirst(lc); 391 | 392 | if (strcmp(var->refname, refname) == 0) 393 | return var; 394 | } 395 | 396 | if (append) 397 | { 398 | oldcxt = MemoryContextSwitchTo(c->cursor_cxt); 399 | nvar = palloc0(sizeof(VariableData)); 400 | 401 | nvar->refname = pstrdup(refname); 402 | nvar->varno = c->nvariables + 1; 403 | nvar->position = position; 404 | 405 | c->variables = lappend(c->variables, nvar); 406 | c->nvariables += 1; 407 | 408 | MemoryContextSwitchTo(oldcxt); 409 | 410 | return nvar; 411 | } 412 | else 413 | ereport(ERROR, 414 | (errcode(ERRCODE_UNDEFINED_PARAMETER), 415 | errmsg("variable \"%s\" doesn't exists", refname))); 416 | } 417 | 418 | /* 419 | * PROCEDURE dbms_sql.parse(c int, stmt varchar) 420 | */ 421 | Datum 422 | dbms_sql_parse(PG_FUNCTION_ARGS) 423 | { 424 | char *query, 425 | *ptr; 426 | char *start; 427 | size_t len; 428 | TokenType typ; 429 | StringInfoData sinfo; 430 | CursorData *c; 431 | MemoryContext oldcxt; 432 | 433 | c = get_cursor(fcinfo, true); 434 | 435 | if (PG_ARGISNULL(1)) 436 | ereport(ERROR, 437 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 438 | errmsg("parsed query string is NULL"))); 439 | 440 | if (c->parsed_query) 441 | { 442 | int cid = c->cid; 443 | 444 | close_cursor(c); 445 | open_cursor(c, cid); 446 | } 447 | 448 | query = text_to_cstring(PG_GETARG_TEXT_P(1)); 449 | ptr = query; 450 | 451 | initStringInfo(&sinfo); 452 | 453 | while (ptr) 454 | { 455 | char *startsep; 456 | char *next_ptr; 457 | size_t seplen; 458 | 459 | next_ptr = next_token(ptr, &start, &len, &typ, &startsep, &seplen); 460 | if (next_ptr) 461 | { 462 | if (typ == TOKEN_DOLAR_STR) 463 | { 464 | appendStringInfo(&sinfo, "%.*s", (int) seplen, startsep); 465 | appendStringInfo(&sinfo, "%.*s", (int) len, start); 466 | appendStringInfo(&sinfo, "%.*s", (int) seplen, startsep); 467 | } 468 | else if (typ == TOKEN_BIND_VAR) 469 | { 470 | char *name = downcase_identifier(start, len, false, true); 471 | VariableData *var = get_var(c, name, ptr - query, true); 472 | 473 | appendStringInfo(&sinfo, "$%d", var->varno); 474 | 475 | pfree(name); 476 | } 477 | else if (typ == TOKEN_EXT_STR) 478 | { 479 | appendStringInfo(&sinfo, "e\'%.*s\'", (int) len, start); 480 | } 481 | else if (typ == TOKEN_STR) 482 | { 483 | appendStringInfo(&sinfo, "\'%.*s\'", (int) len, start); 484 | } 485 | else if (typ == TOKEN_QIDENTIF) 486 | { 487 | appendStringInfo(&sinfo, "\"%.*s\"", (int) len, start); 488 | } 489 | else if (typ != TOKEN_NONE) 490 | { 491 | appendStringInfo(&sinfo, "%.*s", (int) len, start); 492 | } 493 | } 494 | 495 | ptr = next_ptr; 496 | } 497 | 498 | /* save result to persist context */ 499 | oldcxt = MemoryContextSwitchTo(c->cursor_cxt); 500 | c->original_query = pstrdup(query); 501 | c->parsed_query = pstrdup(sinfo.data); 502 | 503 | MemoryContextSwitchTo(oldcxt); 504 | 505 | pfree(query); 506 | pfree(sinfo.data); 507 | 508 | return (Datum) 0; 509 | } 510 | 511 | /* 512 | * Calling procedure can be slow, so there is a function alternative 513 | */ 514 | static Datum 515 | bind_variable(PG_FUNCTION_ARGS) 516 | { 517 | CursorData *c; 518 | VariableData *var; 519 | char *varname, *varname_downcase; 520 | Oid valtype; 521 | bool is_unknown = false; 522 | 523 | c = get_cursor(fcinfo, true); 524 | 525 | if (PG_ARGISNULL(1)) 526 | ereport(ERROR, 527 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 528 | errmsg("name of bind variable is NULL"))); 529 | 530 | varname = text_to_cstring(PG_GETARG_TEXT_P(1)); 531 | if (*varname == ':') 532 | varname += 1; 533 | 534 | varname_downcase = downcase_identifier(varname, strlen(varname), false, true); 535 | var = get_var(c, varname_downcase, -1, false); 536 | 537 | valtype = get_fn_expr_argtype(fcinfo->flinfo, 2); 538 | if (valtype == RECORDOID) 539 | ereport(ERROR, 540 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 541 | errmsg("cannot to bind a value of record type"))); 542 | 543 | valtype = getBaseType(valtype); 544 | if (valtype == UNKNOWNOID) 545 | { 546 | is_unknown = true; 547 | valtype = TEXTOID; 548 | } 549 | 550 | if (var->typoid != InvalidOid) 551 | { 552 | if (!var->typbyval) 553 | pfree(DatumGetPointer(var->value)); 554 | 555 | var->isnull = true; 556 | } 557 | 558 | var->typoid = valtype; 559 | 560 | if (!PG_ARGISNULL(2)) 561 | { 562 | MemoryContext oldcxt; 563 | 564 | get_typlenbyval(var->typoid, &var->typlen, &var->typbyval); 565 | 566 | oldcxt = MemoryContextSwitchTo(c->cursor_cxt); 567 | 568 | if (is_unknown) 569 | var->value = CStringGetTextDatum(DatumGetPointer(PG_GETARG_DATUM(2))); 570 | else 571 | var->value = datumCopy(PG_GETARG_DATUM(2), var->typbyval, var->typlen); 572 | 573 | var->isnull = false; 574 | 575 | MemoryContextSwitchTo(oldcxt); 576 | } 577 | else 578 | var->isnull = true; 579 | 580 | return (Datum) 0; 581 | } 582 | 583 | /* 584 | * CREATE PROCEDURE dbms_sql.bind_variable(c int, name varchar2, value "any"); 585 | */ 586 | Datum 587 | dbms_sql_bind_variable(PG_FUNCTION_ARGS) 588 | { 589 | return bind_variable(fcinfo); 590 | } 591 | 592 | /* 593 | * CREATE FUNCTION dbms_sql.bind_variable_f(c int, name varchar2, value "any") RETURNS void; 594 | */ 595 | Datum 596 | dbms_sql_bind_variable_f(PG_FUNCTION_ARGS) 597 | { 598 | return bind_variable(fcinfo); 599 | } 600 | 601 | static void 602 | bind_array(FunctionCallInfo fcinfo, int index1, int index2) 603 | { 604 | CursorData *c; 605 | VariableData *var; 606 | char *varname, *varname_downcase; 607 | Oid valtype; 608 | Oid elementtype; 609 | bool is_unknown = false; 610 | 611 | c = get_cursor(fcinfo, true); 612 | 613 | if (PG_ARGISNULL(1)) 614 | ereport(ERROR, 615 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 616 | errmsg("name of bind variable is NULL"))); 617 | 618 | varname = text_to_cstring(PG_GETARG_TEXT_P(1)); 619 | if (*varname == ':') 620 | varname += 1; 621 | 622 | varname_downcase = downcase_identifier(varname, strlen(varname), false, true); 623 | var = get_var(c, varname_downcase, -1, false); 624 | 625 | valtype = get_fn_expr_argtype(fcinfo->flinfo, 2); 626 | if (valtype == RECORDOID) 627 | ereport(ERROR, 628 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 629 | errmsg("cannot to bind a value of record type"))); 630 | 631 | valtype = getBaseType(valtype); 632 | elementtype = get_element_type(valtype); 633 | 634 | if (!OidIsValid(elementtype)) 635 | ereport(ERROR, 636 | (errcode(ERRCODE_DATATYPE_MISMATCH), 637 | errmsg("value is not a array"))); 638 | 639 | var->is_array = true; 640 | var->typoid = valtype; 641 | var->typelemid = elementtype; 642 | 643 | get_typlenbyval(elementtype, &var->typelemlen, &var->typelembyval); 644 | 645 | if (!PG_ARGISNULL(2)) 646 | { 647 | MemoryContext oldcxt; 648 | 649 | get_typlenbyval(var->typoid, &var->typlen, &var->typbyval); 650 | 651 | oldcxt = MemoryContextSwitchTo(c->cursor_cxt); 652 | 653 | if (is_unknown) 654 | var->value = CStringGetTextDatum(DatumGetPointer(PG_GETARG_DATUM(2))); 655 | else 656 | var->value = datumCopy(PG_GETARG_DATUM(2), var->typbyval, var->typlen); 657 | 658 | var->isnull = false; 659 | 660 | MemoryContextSwitchTo(oldcxt); 661 | } 662 | else 663 | var->isnull = true; 664 | 665 | var->index1 = index1; 666 | var->index2 = index2; 667 | } 668 | 669 | /* 670 | * CREATE PROCEDURE dbms_sql.bind_array(c int, name varchar2, value anyarray); 671 | */ 672 | Datum 673 | dbms_sql_bind_array_3(PG_FUNCTION_ARGS) 674 | { 675 | bind_array(fcinfo, -1, -1); 676 | 677 | return (Datum) 0; 678 | } 679 | 680 | /* 681 | * CREATE PROCEDURE dbms_sql.bind_array(c int, name varchar2, value anyarray, index1 int, index2 int); 682 | */ 683 | Datum 684 | dbms_sql_bind_array_5(PG_FUNCTION_ARGS) 685 | { 686 | int index1, index2; 687 | 688 | if (PG_ARGISNULL(3) || PG_ARGISNULL(4)) 689 | ereport(ERROR, 690 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 691 | errmsg("index is NULL"))); 692 | 693 | index1 = PG_GETARG_INT32(3); 694 | index2 = PG_GETARG_INT32(4); 695 | 696 | if (index1 < 0 || index2 < 0) 697 | ereport(ERROR, 698 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 699 | errmsg("index is below zero"))); 700 | 701 | if (index1 > index2) 702 | ereport(ERROR, 703 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 704 | errmsg("index1 is greater than index2"))); 705 | 706 | bind_array(fcinfo, index1, index2); 707 | 708 | return (Datum) 0; 709 | } 710 | 711 | static ColumnData * 712 | get_col(CursorData *c, int position, bool append) 713 | { 714 | ListCell *lc; 715 | ColumnData *ncol; 716 | MemoryContext oldcxt; 717 | 718 | foreach(lc, c->columns) 719 | { 720 | ColumnData *col = (ColumnData *) lfirst(lc); 721 | 722 | if (col->position == position) 723 | return col; 724 | } 725 | 726 | if (append) 727 | { 728 | oldcxt = MemoryContextSwitchTo(c->cursor_cxt); 729 | ncol = palloc0(sizeof(ColumnData)); 730 | 731 | ncol->position = position; 732 | if (c->max_colpos < position) 733 | c->max_colpos = position; 734 | 735 | c->columns = lappend(c->columns, ncol); 736 | 737 | MemoryContextSwitchTo(oldcxt); 738 | 739 | return ncol; 740 | } 741 | else 742 | ereport(ERROR, 743 | (errcode(ERRCODE_UNDEFINED_COLUMN), 744 | errmsg("column no %d is not defined", position))); 745 | } 746 | 747 | /* 748 | * CREATE PROCEDURE dbms_sql.define_column(c int, col int, value "any", column_size int DEFAULT -1); 749 | */ 750 | Datum 751 | dbms_sql_define_column(PG_FUNCTION_ARGS) 752 | { 753 | CursorData *c; 754 | ColumnData *col; 755 | Oid valtype; 756 | Oid basetype; 757 | int position; 758 | int colsize; 759 | TYPCATEGORY category; 760 | bool ispreferred; 761 | 762 | c = get_cursor(fcinfo, true); 763 | 764 | if (PG_ARGISNULL(1)) 765 | ereport(ERROR, 766 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 767 | errmsg("column position (number) is NULL"))); 768 | 769 | position = PG_GETARG_INT32(1); 770 | col = get_col(c, position, true); 771 | 772 | valtype = get_fn_expr_argtype(fcinfo->flinfo, 2); 773 | if (valtype == RECORDOID) 774 | ereport(ERROR, 775 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 776 | errmsg("cannot to define a column of record type"))); 777 | 778 | if (valtype == UNKNOWNOID) 779 | valtype = TEXTOID; 780 | 781 | basetype = getBaseType(valtype); 782 | 783 | if (col->typoid != InvalidOid) 784 | ereport(ERROR, 785 | (errcode(ERRCODE_DUPLICATE_COLUMN), 786 | errmsg("column is defined already"))); 787 | 788 | col->typoid = valtype; 789 | 790 | if (PG_ARGISNULL(3)) 791 | ereport(ERROR, 792 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 793 | errmsg("column_size is NULL"))); 794 | 795 | colsize = PG_GETARG_INT32(3); 796 | 797 | get_type_category_preferred(basetype, &category, &ispreferred); 798 | col->typisstr = category == TYPCATEGORY_STRING; 799 | col->typmod = (col->typisstr && colsize != -1) ? colsize + 4 : -1; 800 | 801 | get_typlenbyval(basetype, &col->typlen, &col->typbyval); 802 | 803 | return (Datum) 0; 804 | } 805 | 806 | /* 807 | * CREATE PROCEDURE dbms_sql.define_array(c int, col int, value "anyarray", rowcount int, index1 int); 808 | */ 809 | Datum 810 | dbms_sql_define_array(PG_FUNCTION_ARGS) 811 | { 812 | CursorData *c; 813 | ColumnData *col; 814 | Oid valtype; 815 | Oid basetype; 816 | int position; 817 | int rowcount; 818 | int index1; 819 | Oid elementtype; 820 | TYPCATEGORY category; 821 | bool ispreferred; 822 | 823 | c = get_cursor(fcinfo, true); 824 | 825 | if (PG_ARGISNULL(1)) 826 | ereport(ERROR, 827 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 828 | errmsg("column position (number) is NULL"))); 829 | 830 | position = PG_GETARG_INT32(1); 831 | col = get_col(c, position, true); 832 | 833 | valtype = get_fn_expr_argtype(fcinfo->flinfo, 2); 834 | if (valtype == RECORDOID) 835 | ereport(ERROR, 836 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 837 | errmsg("cannot to define a column of record type"))); 838 | 839 | get_type_category_preferred(valtype, &category, &ispreferred); 840 | if (category != TYPCATEGORY_ARRAY) 841 | elog(ERROR, "defined value is not array"); 842 | 843 | col->typarrayoid = valtype; 844 | 845 | basetype = getBaseType(valtype); 846 | elementtype = get_element_type(basetype); 847 | 848 | if (!OidIsValid(elementtype)) 849 | ereport(ERROR, 850 | (errcode(ERRCODE_DATATYPE_MISMATCH), 851 | errmsg("column is not a array"))); 852 | 853 | if (col->typoid != InvalidOid) 854 | ereport(ERROR, 855 | (errcode(ERRCODE_DUPLICATE_COLUMN), 856 | errmsg("column is defined already"))); 857 | 858 | col->typoid = elementtype; 859 | 860 | if (PG_ARGISNULL(3)) 861 | ereport(ERROR, 862 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 863 | errmsg("cnt is NULL"))); 864 | 865 | rowcount = PG_GETARG_INT32(3); 866 | if (rowcount <= 0) 867 | ereport(ERROR, 868 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 869 | errmsg("cnt is less or equal to zero"))); 870 | 871 | col->rowcount = rowcount; 872 | 873 | if (PG_ARGISNULL(4)) 874 | ereport(ERROR, 875 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 876 | errmsg("lower_bnd is NULL"))); 877 | 878 | index1 = PG_GETARG_INT32(4); 879 | if (index1 < 1) 880 | ereport(ERROR, 881 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 882 | errmsg("lower_bnd is less than one"))); 883 | 884 | if (index1 != 1) 885 | ereport(ERROR, 886 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 887 | errmsg("lower_bnd can be only only \"1\""))); 888 | 889 | col->index1 = index1; 890 | 891 | get_typlenbyval(col->typoid, &col->typlen, &col->typbyval); 892 | 893 | return (Datum) 0; 894 | } 895 | 896 | static void 897 | cursor_xact_cxt_deletion_callback(void *arg) 898 | { 899 | CursorData *cur = (CursorData *) arg; 900 | 901 | cur->cursor_xact_cxt = NULL; 902 | cur->tuples_cxt = NULL; 903 | 904 | cur->processed = 0; 905 | cur->nread = 0; 906 | cur->executed = false; 907 | cur->tupdesc = NULL; 908 | cur->coltupdesc = NULL; 909 | cur->casts = NULL; 910 | cur->array_columns = NULL; 911 | } 912 | 913 | static long 914 | execute(CursorData *c) 915 | { 916 | last_row_count = 0; 917 | 918 | /* clean space with saved result */ 919 | if (!c->cursor_xact_cxt) 920 | { 921 | MemoryContextCallback *mcb; 922 | MemoryContext oldcxt; 923 | 924 | c->cursor_xact_cxt = AllocSetContextCreate(TopTransactionContext, 925 | "dbms_sql transaction context", 926 | ALLOCSET_DEFAULT_SIZES); 927 | 928 | oldcxt = MemoryContextSwitchTo(c->cursor_xact_cxt); 929 | mcb = palloc0(sizeof(MemoryContextCallback)); 930 | 931 | mcb->func = cursor_xact_cxt_deletion_callback; 932 | mcb->arg = c; 933 | 934 | MemoryContextRegisterResetCallback(c->cursor_xact_cxt, mcb); 935 | 936 | MemoryContextSwitchTo(oldcxt); 937 | } 938 | else 939 | { 940 | MemoryContext save_cxt = c->cursor_xact_cxt; 941 | 942 | MemoryContextReset(c->cursor_xact_cxt); 943 | c->cursor_xact_cxt = save_cxt; 944 | 945 | c->casts = NULL; 946 | c->tupdesc = NULL; 947 | c->tuples_cxt = NULL; 948 | } 949 | 950 | c->result_cxt = AllocSetContextCreate(c->cursor_xact_cxt, 951 | "dbms_sql short life context", 952 | ALLOCSET_DEFAULT_SIZES); 953 | 954 | /* 955 | * When column definitions are available, build final query 956 | * and open cursor for fetching. When column definitions are 957 | * missing, then the statement can be called with high frequency 958 | * etc INSERT, UPDATE, so use cached plan. 959 | */ 960 | if (c->columns) 961 | { 962 | Datum *values; 963 | Oid *types; 964 | char *nulls; 965 | ListCell *lc; 966 | int i; 967 | MemoryContext oldcxt; 968 | int batch_rows = -1; 969 | 970 | oldcxt = MemoryContextSwitchTo(c->cursor_xact_cxt); 971 | 972 | /* prepare query arguments */ 973 | values = palloc(sizeof(Datum) * c->nvariables); 974 | types = palloc(sizeof(Oid) * c->nvariables); 975 | nulls = palloc(sizeof(char) * c->nvariables); 976 | 977 | i = 0; 978 | foreach(lc, c->variables) 979 | { 980 | VariableData *var = (VariableData *) lfirst(lc); 981 | 982 | if (var->is_array) 983 | ereport(ERROR, 984 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 985 | errmsg("a array (bulk) variable can be used only when no column is defined"))); 986 | 987 | if (!var->isnull) 988 | { 989 | /* copy a value to xact memory context, to be independent on a outside */ 990 | values[i] = datumCopy(var->value, var->typbyval, var->typlen); 991 | nulls[i] = ' '; 992 | } 993 | else 994 | nulls[i] = 'n'; 995 | 996 | if (var->typoid == InvalidOid) 997 | ereport(ERROR, 998 | (errcode(ERRCODE_UNDEFINED_PARAMETER), 999 | errmsg("variable \"%s\" has not a value", var->refname))); 1000 | 1001 | types[i] = var->typoid; 1002 | i += 1; 1003 | } 1004 | 1005 | /* prepare or refresh target tuple descriptor, used for final tupconversion */ 1006 | if (c->tupdesc) 1007 | FreeTupleDesc(c->tupdesc); 1008 | 1009 | #if PG_VERSION_NUM >= 120000 1010 | 1011 | c->coltupdesc = CreateTemplateTupleDesc(c->max_colpos); 1012 | 1013 | #else 1014 | 1015 | c->coltupdesc = CreateTemplateTupleDesc(c->max_colpos, false); 1016 | 1017 | #endif 1018 | 1019 | /* prepare current result column tupdesc */ 1020 | for (i = 1; i <= c->max_colpos; i++) 1021 | { 1022 | ColumnData *col = get_col(c, i, false); 1023 | char genname[32]; 1024 | 1025 | snprintf(genname, 32, "col%d", i); 1026 | 1027 | if (col->typarrayoid) 1028 | { 1029 | if (batch_rows != -1) 1030 | batch_rows = batch_rows > col->rowcount ? col->rowcount : batch_rows; 1031 | else 1032 | batch_rows = col->rowcount; 1033 | 1034 | c->array_columns = bms_add_member(c->array_columns, i); 1035 | } 1036 | else 1037 | { 1038 | /* in this case we cannot do batch of rows */ 1039 | batch_rows = 1; 1040 | } 1041 | 1042 | TupleDescInitEntry(c->coltupdesc, (AttrNumber) i, genname, col->typoid, col->typmod, 0); 1043 | } 1044 | 1045 | c->batch_rows = batch_rows; 1046 | c->casts = palloc0(sizeof(CastCacheData) * c->coltupdesc->natts); 1047 | 1048 | MemoryContextSwitchTo(oldcxt); 1049 | 1050 | snprintf(c->cursorname, sizeof(c->cursorname), "__orafce_dbms_sql_cursor_%d", c->cid); 1051 | 1052 | if (SPI_connect() != SPI_OK_CONNECT) 1053 | elog(ERROR, "SPI_connact failed"); 1054 | 1055 | c->portal = SPI_cursor_open_with_args(c->cursorname, 1056 | c->parsed_query, 1057 | c->nvariables, 1058 | types, 1059 | values, 1060 | nulls, 1061 | false, 1062 | 0); 1063 | 1064 | /* internal error */ 1065 | if (c->portal == NULL) 1066 | elog(ERROR, 1067 | "could not open cursor for query \"%s\": %s", 1068 | c->parsed_query, 1069 | SPI_result_code_string(SPI_result)); 1070 | 1071 | SPI_finish(); 1072 | 1073 | /* Describe portal and prepare cast cache */ 1074 | if (c->portal->tupDesc) 1075 | { 1076 | int natts = 0; 1077 | TupleDesc tupdesc = c->portal->tupDesc; 1078 | 1079 | for (i = 0; i < tupdesc->natts; i++) 1080 | { 1081 | Form_pg_attribute att = TupleDescAttr(tupdesc, i); 1082 | 1083 | if (att->attisdropped) 1084 | continue; 1085 | 1086 | natts += 1; 1087 | } 1088 | 1089 | if (natts != c->coltupdesc->natts) 1090 | ereport(ERROR, 1091 | (errcode(ERRCODE_DATA_EXCEPTION), 1092 | errmsg("number of defined columns is different than number of query's columns"))); 1093 | } 1094 | 1095 | c->executed = true; 1096 | } 1097 | else 1098 | { 1099 | MemoryContext oldcxt; 1100 | Datum *values; 1101 | char *nulls; 1102 | ArrayIterator *iterators; 1103 | bool has_iterator = false; 1104 | bool has_value = true; 1105 | int max_index1 = -1; 1106 | int min_index2 = -1; 1107 | int max_rows = -1; 1108 | long result = 0; 1109 | ListCell *lc; 1110 | int i; 1111 | 1112 | if (SPI_connect() != SPI_OK_CONNECT) 1113 | elog(ERROR, "SPI_connact failed"); 1114 | 1115 | /* prepare, or reuse cached plan */ 1116 | if (!c->plan) 1117 | { 1118 | Oid *types = NULL; 1119 | SPIPlanPtr plan; 1120 | 1121 | types = palloc(sizeof(Oid) * c->nvariables); 1122 | 1123 | i = 0; 1124 | foreach(lc, c->variables) 1125 | { 1126 | VariableData *var = (VariableData *) lfirst(lc); 1127 | 1128 | if (var->typoid == InvalidOid) 1129 | ereport(ERROR, 1130 | (errcode(ERRCODE_UNDEFINED_PARAMETER), 1131 | errmsg("variable \"%s\" has not a value", var->refname))); 1132 | 1133 | types[i++] = var->is_array ? var->typelemid : var->typoid; 1134 | } 1135 | 1136 | plan = SPI_prepare(c->parsed_query, c->nvariables, types); 1137 | 1138 | if (!plan) 1139 | /* internal error */ 1140 | elog(ERROR, "cannot to prepare plan"); 1141 | 1142 | if (types) 1143 | pfree(types); 1144 | 1145 | SPI_keepplan(plan); 1146 | 1147 | c->plan = plan; 1148 | } 1149 | 1150 | oldcxt = MemoryContextSwitchTo(c->result_cxt); 1151 | 1152 | /* prepare query arguments */ 1153 | values = palloc(sizeof(Datum) * c->nvariables); 1154 | nulls = palloc(sizeof(char) * c->nvariables); 1155 | iterators = palloc(sizeof(ArrayIterator *) * c->nvariables); 1156 | 1157 | has_value = true; 1158 | 1159 | i = 0; 1160 | foreach(lc, c->variables) 1161 | { 1162 | VariableData *var = (VariableData *) lfirst(lc); 1163 | 1164 | if (var->is_array) 1165 | { 1166 | if (!var->isnull) 1167 | { 1168 | iterators[i] = array_create_iterator(DatumGetArrayTypeP(var->value), 1169 | 0, 1170 | NULL); 1171 | 1172 | /* search do lowest common denominator */ 1173 | if (var->index1 != -1) 1174 | { 1175 | if (max_index1 != -1) 1176 | { 1177 | max_index1 = max_index1 < var->index1 ? var->index1 : max_index1; 1178 | min_index2 = min_index2 > var->index2 ? var->index2 : min_index2; 1179 | } 1180 | else 1181 | { 1182 | max_index1 = var->index1; 1183 | min_index2 = var->index2; 1184 | } 1185 | } 1186 | 1187 | has_iterator = true; 1188 | 1189 | } 1190 | else 1191 | { 1192 | /* cannot to read data from NULL array */ 1193 | has_value = false; 1194 | break; 1195 | } 1196 | } 1197 | else 1198 | { 1199 | values[i] = var->value; 1200 | nulls[i] = var->isnull ? 'n' : ' '; 1201 | } 1202 | 1203 | i += 1; 1204 | } 1205 | 1206 | if (has_iterator) 1207 | { 1208 | if (has_value) 1209 | { 1210 | if (max_index1 != -1) 1211 | { 1212 | max_rows = min_index2 - max_index1 + 1; 1213 | has_value = max_rows > 0; 1214 | 1215 | if (has_value && max_index1 > 1) 1216 | { 1217 | i = 0; 1218 | foreach(lc, c->variables) 1219 | { 1220 | VariableData *var = (VariableData *) lfirst(lc); 1221 | 1222 | if (var->is_array) 1223 | { 1224 | int j; 1225 | 1226 | Assert(iterators[i]); 1227 | 1228 | for (j = 1; j < max_index1; j++) 1229 | { 1230 | Datum value; 1231 | bool isnull; 1232 | 1233 | has_value = array_iterate(iterators[i], &value, &isnull); 1234 | if (!has_value) 1235 | break; 1236 | } 1237 | 1238 | if (!has_value) 1239 | break; 1240 | } 1241 | 1242 | i += 1; 1243 | } 1244 | } 1245 | } 1246 | } 1247 | 1248 | while (has_value && (max_rows == -1 || max_rows > 0)) 1249 | { 1250 | int rc; 1251 | 1252 | i = 0; 1253 | foreach(lc, c->variables) 1254 | { 1255 | VariableData *var = (VariableData *) lfirst(lc); 1256 | 1257 | if (var->is_array) 1258 | { 1259 | Datum value; 1260 | bool isnull; 1261 | 1262 | has_value = array_iterate(iterators[i], &value, &isnull); 1263 | if (!has_value) 1264 | break; 1265 | 1266 | values[i] = value; 1267 | nulls[i] = isnull ? 'n' : ' '; 1268 | } 1269 | 1270 | i += 1; 1271 | } 1272 | if (!has_value) 1273 | break; 1274 | 1275 | rc = SPI_execute_plan(c->plan, values, nulls, false, 0); 1276 | if (rc < 0) 1277 | /* internal error */ 1278 | elog(ERROR, "cannot to execute a query"); 1279 | 1280 | result += SPI_processed; 1281 | 1282 | if (max_rows > 0) 1283 | max_rows -= 1; 1284 | } 1285 | 1286 | MemoryContextReset(c->result_cxt); 1287 | } 1288 | else 1289 | { 1290 | int rc; 1291 | 1292 | rc = SPI_execute_plan(c->plan, values, nulls, false, 0); 1293 | if (rc < 0) 1294 | /* internal error */ 1295 | elog(ERROR, "cannot to execute a query"); 1296 | 1297 | result = SPI_processed; 1298 | } 1299 | 1300 | SPI_finish(); 1301 | 1302 | MemoryContextSwitchTo(oldcxt); 1303 | 1304 | return result; 1305 | } 1306 | 1307 | return 0L; 1308 | } 1309 | 1310 | /* 1311 | * CREATE FUNCTION dbms_sql.execute(c int) RETURNS bigint; 1312 | */ 1313 | Datum 1314 | dbms_sql_execute(PG_FUNCTION_ARGS) 1315 | { 1316 | CursorData *c; 1317 | 1318 | c = get_cursor(fcinfo, true); 1319 | 1320 | PG_RETURN_INT64(execute(c)); 1321 | } 1322 | 1323 | static int 1324 | fetch_rows(CursorData *c, bool exact) 1325 | { 1326 | int can_read_rows; 1327 | 1328 | if (!c->executed) 1329 | ereport(ERROR, 1330 | (errcode(ERRCODE_INVALID_CURSOR_STATE), 1331 | errmsg("cursor is not executed"))); 1332 | 1333 | if (!c->portal) 1334 | ereport(ERROR, 1335 | (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), 1336 | errmsg("cursor has not portal"))); 1337 | 1338 | if (c->nread == c->processed) 1339 | { 1340 | MemoryContext oldcxt; 1341 | uint64 i; 1342 | int batch_rows; 1343 | 1344 | if (!exact) 1345 | { 1346 | if (c->array_columns) 1347 | batch_rows = (1000 / c->batch_rows) * c->batch_rows; 1348 | else 1349 | batch_rows = 1000; 1350 | } 1351 | else 1352 | batch_rows = 2; 1353 | 1354 | /* create or reset context for tuples */ 1355 | if (!c->tuples_cxt) 1356 | c->tuples_cxt = AllocSetContextCreate(c->cursor_xact_cxt, 1357 | "dbms_sql tuples context", 1358 | ALLOCSET_DEFAULT_SIZES); 1359 | else 1360 | MemoryContextReset(c->tuples_cxt); 1361 | 1362 | if (SPI_connect() != SPI_OK_CONNECT) 1363 | elog(ERROR, "SPI_connact failed"); 1364 | 1365 | /* try to fetch data from cursor */ 1366 | SPI_cursor_fetch(c->portal, true, batch_rows); 1367 | 1368 | if (SPI_tuptable == NULL) 1369 | elog(ERROR, "cannot fetch data"); 1370 | 1371 | if (exact && SPI_processed > 1) 1372 | ereport(ERROR, 1373 | (errcode(ERRCODE_TOO_MANY_ROWS), 1374 | errmsg("too many rows"), 1375 | errdetail("In exact mode only one row is expected"))); 1376 | 1377 | if (exact && SPI_processed == 0) 1378 | ereport(ERROR, 1379 | (errcode(ERRCODE_NO_DATA_FOUND), 1380 | errmsg("no data found"), 1381 | errdetail("In exact mode only one row is expected"))); 1382 | 1383 | oldcxt = MemoryContextSwitchTo(c->tuples_cxt); 1384 | 1385 | c->tupdesc = CreateTupleDescCopy(SPI_tuptable->tupdesc); 1386 | 1387 | for (i = 0; i < SPI_processed; i++) 1388 | c->tuples[i] = heap_copytuple(SPI_tuptable->vals[i]); 1389 | 1390 | MemoryContextSwitchTo(oldcxt); 1391 | 1392 | c->processed = SPI_processed; 1393 | c->nread = 0; 1394 | 1395 | SPI_finish(); 1396 | } 1397 | 1398 | if (c->processed - c->nread >= c->batch_rows) 1399 | can_read_rows = c->batch_rows; 1400 | else 1401 | can_read_rows = c->processed - c->nread; 1402 | 1403 | c->start_read = c->nread; 1404 | c->nread += can_read_rows; 1405 | 1406 | last_row_count = can_read_rows; 1407 | 1408 | return can_read_rows; 1409 | } 1410 | 1411 | /* 1412 | * CREATE FUNCTION dbms_sql.fetch_rows(c int) RETURNS int; 1413 | */ 1414 | Datum 1415 | dbms_sql_fetch_rows(PG_FUNCTION_ARGS) 1416 | { 1417 | CursorData *c; 1418 | 1419 | c = get_cursor(fcinfo, true); 1420 | 1421 | PG_RETURN_INT32(fetch_rows(c, false)); 1422 | } 1423 | 1424 | /* 1425 | * CREATE FUNCTION dbms_sql.execute_and_fetch(c int, exact bool DEFAULT false) RETURNS int; 1426 | */ 1427 | Datum 1428 | dbms_sql_execute_and_fetch(PG_FUNCTION_ARGS) 1429 | { 1430 | CursorData *c; 1431 | bool exact; 1432 | 1433 | c = get_cursor(fcinfo, true); 1434 | 1435 | if (PG_ARGISNULL(1)) 1436 | ereport(ERROR, 1437 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 1438 | errmsg("exact option is NULL"))); 1439 | 1440 | exact = PG_GETARG_BOOL(1); 1441 | 1442 | execute(c); 1443 | 1444 | PG_RETURN_INT32(fetch_rows(c, exact)); 1445 | } 1446 | 1447 | /* 1448 | * CREATE FUNCTION dbms_sql.last_row_count() RETURNS int; 1449 | */ 1450 | Datum 1451 | dbms_sql_last_row_count(PG_FUNCTION_ARGS) 1452 | { 1453 | (void) fcinfo; 1454 | 1455 | PG_RETURN_INT32(last_row_count); 1456 | } 1457 | 1458 | /* 1459 | * Initialize cast case entry. 1460 | */ 1461 | static void 1462 | init_cast_cache_entry(CastCacheData *ccast, 1463 | Oid targettypid, 1464 | int32 targettypmod, 1465 | Oid sourcetypid) 1466 | { 1467 | Oid funcoid; 1468 | Oid basetypid; 1469 | 1470 | basetypid = getBaseType(targettypid); 1471 | 1472 | if (targettypid != basetypid) 1473 | ccast->targettypid = targettypid; 1474 | else 1475 | ccast->targettypid = InvalidOid; 1476 | 1477 | ccast->targettypmod = targettypmod; 1478 | 1479 | if (sourcetypid == targettypid) 1480 | ccast->without_cast = targettypmod == -1; 1481 | else 1482 | ccast->without_cast = false; 1483 | 1484 | if (!ccast->without_cast) 1485 | { 1486 | ccast->path = find_coercion_pathway(basetypid, 1487 | sourcetypid, 1488 | COERCION_ASSIGNMENT, 1489 | &funcoid); 1490 | 1491 | if (ccast->path == COERCION_PATH_NONE) 1492 | ereport(ERROR, 1493 | (errcode(ERRCODE_CANNOT_COERCE), 1494 | errmsg("cannot to find cast from source type \"%s\" to target type \"%s\"", 1495 | format_type_be(sourcetypid), 1496 | format_type_be(basetypid)))); 1497 | 1498 | if (ccast->path == COERCION_PATH_FUNC) 1499 | { 1500 | fmgr_info(funcoid, &ccast->finfo); 1501 | } 1502 | else if (ccast->path == COERCION_PATH_COERCEVIAIO) 1503 | { 1504 | bool typisvarlena; 1505 | 1506 | getTypeOutputInfo(sourcetypid, &funcoid, &typisvarlena); 1507 | fmgr_info(funcoid, &ccast->finfo_out); 1508 | 1509 | getTypeInputInfo(targettypid, &funcoid, &ccast->typIOParam); 1510 | fmgr_info(funcoid, &ccast->finfo_in); 1511 | } 1512 | 1513 | if (targettypmod != -1) 1514 | { 1515 | ccast->path_typmod = find_typmod_coercion_function(targettypid, 1516 | &funcoid); 1517 | if (ccast->path_typmod == COERCION_PATH_FUNC) 1518 | fmgr_info(funcoid, &ccast->finfo_typmod); 1519 | } 1520 | } 1521 | 1522 | ccast->isvalid = true; 1523 | } 1524 | 1525 | /* 1526 | * Apply cast rules to a value 1527 | */ 1528 | static Datum 1529 | cast_value(CastCacheData *ccast, Datum value, bool isnull) 1530 | { 1531 | if (!isnull && !ccast->without_cast) 1532 | { 1533 | if (ccast->path == COERCION_PATH_FUNC) 1534 | value = FunctionCall1(&ccast->finfo, value); 1535 | else if (ccast->path == COERCION_PATH_RELABELTYPE) 1536 | value = value; 1537 | else if (ccast->path == COERCION_PATH_COERCEVIAIO) 1538 | { 1539 | char *str; 1540 | 1541 | str = OutputFunctionCall(&ccast->finfo_out, value); 1542 | value = InputFunctionCall(&ccast->finfo_in, 1543 | str, 1544 | ccast->typIOParam, 1545 | ccast->targettypmod); 1546 | } 1547 | else 1548 | ereport(ERROR, 1549 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 1550 | errmsg("unsupported cast path yet %d", ccast->path))); 1551 | 1552 | if (ccast->targettypmod != -1 && ccast->path_typmod == COERCION_PATH_FUNC) 1553 | value = FunctionCall3(&ccast->finfo_typmod, 1554 | value, 1555 | Int32GetDatum(ccast->targettypmod), 1556 | BoolGetDatum(true)); 1557 | } 1558 | 1559 | if (ccast->targettypid != InvalidOid) 1560 | domain_check(value, isnull, ccast->targettypid, NULL, NULL); 1561 | 1562 | return value; 1563 | } 1564 | 1565 | /* 1566 | * CALL statement is relatily slow in PLpgSQL - due repated parsing, planning. 1567 | * So I wrote two variant of this routine. When spi_transfer is true, then 1568 | * the value is copyied to SPI outer memory context. 1569 | */ 1570 | static Datum 1571 | column_value(CursorData *c, int pos, Oid targetTypeId, bool *isnull, bool spi_transfer) 1572 | { 1573 | Datum value; 1574 | int32 columnTypeMode; 1575 | Oid columnTypeId; 1576 | CastCacheData *ccast; 1577 | 1578 | if (!c->executed) 1579 | ereport(ERROR, 1580 | (errcode(ERRCODE_INVALID_CURSOR_STATE), 1581 | errmsg("cursor is not executed"))); 1582 | 1583 | if (!c->tupdesc) 1584 | ereport(ERROR, 1585 | (errcode(ERRCODE_INVALID_CURSOR_STATE), 1586 | errmsg("cursor is not fetched"))); 1587 | 1588 | if (!c->coltupdesc) 1589 | ereport(ERROR, 1590 | (errcode(ERRCODE_UNDEFINED_COLUMN), 1591 | errmsg("no column is defined"))); 1592 | 1593 | if (pos < 1 && pos > c->coltupdesc->natts) 1594 | ereport(ERROR, 1595 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 1596 | errmsg("column position is of of range [1, %d]", 1597 | c->coltupdesc->natts))); 1598 | 1599 | columnTypeId = (TupleDescAttr(c->coltupdesc, pos - 1))->atttypid; 1600 | columnTypeMode = (TupleDescAttr(c->coltupdesc, pos - 1))->atttypmod; 1601 | 1602 | Assert(c->casts); 1603 | ccast = &c->casts[pos - 1]; 1604 | 1605 | if (!ccast->isvalid) 1606 | { 1607 | Oid basetype = getBaseType(targetTypeId); 1608 | 1609 | init_cast_cache_entry(ccast, 1610 | columnTypeId, 1611 | columnTypeMode, 1612 | SPI_gettypeid(c->tupdesc, pos)); 1613 | 1614 | ccast->is_array = bms_is_member(pos, c->array_columns); 1615 | 1616 | if (ccast->is_array) 1617 | { 1618 | ccast->array_targettypid = basetype != targetTypeId ? targetTypeId : InvalidOid; 1619 | 1620 | if (get_array_type(getBaseType(columnTypeId)) != basetype) 1621 | ereport(ERROR, 1622 | (errcode(ERRCODE_DATATYPE_MISMATCH), 1623 | errmsg("unexpected target type \"%s\" (expected type \"%s\")", 1624 | format_type_be(basetype), 1625 | format_type_be(get_array_type(getBaseType(columnTypeId)))))); 1626 | } 1627 | else 1628 | ccast->array_targettypid = InvalidOid; 1629 | 1630 | get_typlenbyval(basetype, &ccast->typlen, &ccast->typbyval); 1631 | } 1632 | 1633 | if (ccast->is_array) 1634 | { 1635 | ArrayBuildState *abs; 1636 | int idx; 1637 | int i; 1638 | 1639 | abs = initArrayResult(columnTypeId, CurrentMemoryContext, false); 1640 | 1641 | idx = c->start_read; 1642 | 1643 | for (i = 0; i < c->batch_rows; i++) 1644 | { 1645 | if (idx < c->processed) 1646 | { 1647 | value = SPI_getbinval(c->tuples[idx], c->tupdesc, pos, isnull); 1648 | value = cast_value(ccast, value, *isnull); 1649 | 1650 | abs = accumArrayResult(abs, 1651 | value, 1652 | *isnull, 1653 | columnTypeId, 1654 | CurrentMemoryContext); 1655 | 1656 | idx += 1; 1657 | } 1658 | } 1659 | 1660 | value = makeArrayResult(abs, CurrentMemoryContext); 1661 | 1662 | if (ccast->array_targettypid != InvalidOid) 1663 | domain_check(value, isnull, ccast->array_targettypid, NULL, NULL); 1664 | } 1665 | else 1666 | { 1667 | /* Maybe it can be solved by uncached slower cast */ 1668 | if (targetTypeId != columnTypeId) 1669 | ereport(ERROR, 1670 | (errcode(ERRCODE_DATATYPE_MISMATCH), 1671 | errmsg("unexpected target type \"%s\" (expected type \"%s\")", 1672 | format_type_be(targetTypeId), 1673 | format_type_be(columnTypeId)))); 1674 | 1675 | value = SPI_getbinval(c->tuples[c->start_read], c->tupdesc, pos, isnull); 1676 | 1677 | value = cast_value(ccast, value, *isnull); 1678 | } 1679 | 1680 | if (spi_transfer) 1681 | value = SPI_datumTransfer(value, ccast->typbyval, ccast->typlen); 1682 | 1683 | return value; 1684 | } 1685 | 1686 | /* 1687 | * CREATE PROCEDURE dbms_sql.column_value(c int, pos int, INOUT value "any"); 1688 | * Note - CALL statement is slow from PLpgSQL block (against function execution). 1689 | * This is reason why this routine is in function form too. 1690 | */ 1691 | Datum 1692 | dbms_sql_column_value(PG_FUNCTION_ARGS) 1693 | { 1694 | CursorData *c; 1695 | Datum value; 1696 | Datum result; 1697 | int pos; 1698 | bool isnull; 1699 | Oid targetTypeId; 1700 | Oid resultTypeId; 1701 | TupleDesc resulttupdesc; 1702 | HeapTuple resulttuple; 1703 | MemoryContext oldcxt; 1704 | 1705 | if (SPI_connect() != SPI_OK_CONNECT) 1706 | elog(ERROR, "SPI_connact failed"); 1707 | 1708 | c = get_cursor(fcinfo, true); 1709 | 1710 | if (PG_ARGISNULL(1)) 1711 | ereport(ERROR, 1712 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 1713 | errmsg("column position (number) is NULL"))); 1714 | 1715 | pos = PG_GETARG_INT32(1); 1716 | 1717 | oldcxt = MemoryContextSwitchTo(c->result_cxt); 1718 | 1719 | /* 1720 | * Setting of OUT field is little bit more complex, because although 1721 | * there is only one output field, the result should be compisite type. 1722 | */ 1723 | if (get_call_result_type(fcinfo, &resultTypeId, &resulttupdesc) == TYPEFUNC_COMPOSITE) 1724 | { 1725 | /* check target types */ 1726 | if (resulttupdesc->natts != 1) 1727 | /* internal error, should not to be */ 1728 | elog(ERROR, "unexpected number of result composite fields"); 1729 | 1730 | targetTypeId = get_fn_expr_argtype(fcinfo->flinfo, 2); 1731 | Assert((TupleDescAttr(resulttupdesc, 0))->atttypid == targetTypeId); 1732 | } 1733 | else 1734 | /* internal error, should not to be */ 1735 | elog(ERROR, "unexpected function result type"); 1736 | 1737 | value = column_value(c, pos, targetTypeId, &isnull, false); 1738 | 1739 | resulttuple = heap_form_tuple(resulttupdesc, &value, &isnull); 1740 | result = PointerGetDatum(SPI_returntuple(resulttuple, CreateTupleDescCopy(resulttupdesc))); 1741 | 1742 | SPI_finish(); 1743 | 1744 | MemoryContextSwitchTo(oldcxt); 1745 | MemoryContextReset(c->result_cxt); 1746 | 1747 | PG_RETURN_DATUM(result); 1748 | } 1749 | 1750 | /* 1751 | * CREATE FUNCTION dbms_sql.column_value(c int, pos int, value anyelement) RETURNS anyelement; 1752 | * Note - CALL statement is slow from PLpgSQL block (against function execution). 1753 | * This is reason why this routine is in function form too. 1754 | */ 1755 | Datum 1756 | dbms_sql_column_value_f(PG_FUNCTION_ARGS) 1757 | { 1758 | CursorData *c; 1759 | Datum value; 1760 | int pos; 1761 | bool isnull; 1762 | Oid targetTypeId; 1763 | MemoryContext oldcxt; 1764 | 1765 | if (SPI_connect() != SPI_OK_CONNECT) 1766 | elog(ERROR, "SPI_connact failed"); 1767 | 1768 | c = get_cursor(fcinfo, true); 1769 | 1770 | if (PG_ARGISNULL(1)) 1771 | ereport(ERROR, 1772 | (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 1773 | errmsg("column position (number) is NULL"))); 1774 | 1775 | pos = PG_GETARG_INT32(1); 1776 | 1777 | oldcxt = MemoryContextSwitchTo(c->result_cxt); 1778 | 1779 | targetTypeId = get_fn_expr_argtype(fcinfo->flinfo, 2); 1780 | 1781 | value = column_value(c, pos, targetTypeId, &isnull, true); 1782 | 1783 | SPI_finish(); 1784 | 1785 | MemoryContextSwitchTo(oldcxt); 1786 | 1787 | PG_RETURN_DATUM(value); 1788 | } 1789 | 1790 | /****************************************************************** 1791 | * Simple parser - just for replacement of bind variables by 1792 | * PostgreSQL $ param placeholders. 1793 | * 1794 | ****************************************************************** 1795 | */ 1796 | 1797 | /* 1798 | * It doesn't work for multibyte encodings, but same implementation 1799 | * is in Postgres too. 1800 | */ 1801 | static bool 1802 | is_identif(unsigned char c) 1803 | { 1804 | if (c >= 'a' && c <= 'z') 1805 | return true; 1806 | else if (c >= 'A' && c <= 'Z') 1807 | return true; 1808 | else if (c >= 0200) 1809 | return true; 1810 | else 1811 | return false; 1812 | } 1813 | 1814 | /* 1815 | * simple parser to detect :identif symbols in query 1816 | */ 1817 | static char * 1818 | next_token(char *str, char **start, size_t *len, TokenType *typ, char **sep, size_t *seplen) 1819 | { 1820 | if (*str == '\0') 1821 | { 1822 | *typ = TOKEN_NONE; 1823 | return NULL; 1824 | } 1825 | 1826 | /* reduce spaces */ 1827 | if (*str == ' ') 1828 | { 1829 | *start = str++; 1830 | while (*str == ' ') 1831 | str++; 1832 | 1833 | *typ = TOKEN_SPACES; *len = 1; 1834 | return str; 1835 | } 1836 | 1837 | /* Postgres's dolar strings */ 1838 | if (*str == '$' && (str[1] == '$' || is_identif(str[1]) || str[1] == '_')) 1839 | { 1840 | char *aux = str + 1; 1841 | char *endstr; 1842 | bool is_valid = false; 1843 | char *buffer; 1844 | 1845 | /* try to find end of separator */ 1846 | while (*aux) 1847 | { 1848 | if (*aux == '$') 1849 | { 1850 | is_valid = true; 1851 | aux++; 1852 | break; 1853 | } 1854 | else if (is_identif(*aux) || 1855 | isdigit(*aux) || 1856 | *aux == '_') 1857 | { 1858 | aux++; 1859 | } 1860 | else 1861 | break; 1862 | } 1863 | 1864 | if (!is_valid) 1865 | { 1866 | *typ = TOKEN_OTHER; *len = 1; 1867 | *start = str; 1868 | return str + 1; 1869 | } 1870 | 1871 | /* now it looks like correct $ separator */ 1872 | *start = aux; *sep = str; *seplen = aux - str; *typ = TOKEN_DOLAR_STR; 1873 | 1874 | /* try to find second instance */ 1875 | buffer = palloc(*seplen + 1); 1876 | strncpy(buffer, *sep, *seplen); 1877 | buffer[*seplen] = '\0'; 1878 | 1879 | endstr = strstr(aux, buffer); 1880 | if (endstr) 1881 | { 1882 | *len = endstr - *start; 1883 | return endstr + *seplen; 1884 | } 1885 | else 1886 | { 1887 | while (*aux) 1888 | aux++; 1889 | *len = aux - *start; 1890 | return aux; 1891 | } 1892 | 1893 | return aux; 1894 | } 1895 | 1896 | /* Pair comments */ 1897 | if (*str == '/' && str[1] == '*') 1898 | { 1899 | *start = str; str += 2; 1900 | while (*str) 1901 | { 1902 | if (*str == '*' && str[1] == '/') 1903 | { 1904 | str += 2; 1905 | break; 1906 | } 1907 | str++; 1908 | } 1909 | *typ = TOKEN_COMMENT; *len = str - *start; 1910 | return str; 1911 | } 1912 | 1913 | /* Number */ 1914 | if (isdigit(*str) || (*str == '.' && isdigit(str[1]))) 1915 | { 1916 | bool point = *str == '.'; 1917 | 1918 | *start = str++; 1919 | while (*str) 1920 | { 1921 | if (isdigit(*str)) 1922 | str++; 1923 | else if (*str == '.' && !point) 1924 | { 1925 | str++; point = true; 1926 | } 1927 | else 1928 | break; 1929 | } 1930 | *typ = TOKEN_NUMBER; *len = str - *start; 1931 | return str; 1932 | } 1933 | 1934 | /* Double colon :: */ 1935 | if (*str == ':' && str[1] == ':') 1936 | { 1937 | *start = str; *typ = TOKEN_DOUBLE_COLON; *len = 2; 1938 | return str + 2; 1939 | } 1940 | 1941 | /* Bind variable placeholder */ 1942 | if (*str == ':' && 1943 | (is_identif(str[1]) || str[1] == '_')) 1944 | { 1945 | *start = &str[1]; str += 2; 1946 | while (*str) 1947 | { 1948 | if (is_identif(*str) || 1949 | isdigit(*str) || 1950 | *str == '_') 1951 | str++; 1952 | else 1953 | break; 1954 | } 1955 | *typ = TOKEN_BIND_VAR; *len = str - *start; 1956 | return str; 1957 | } 1958 | 1959 | /* Extended string literal */ 1960 | if ((*str == 'e' || *str == 'E') && str[1] == '\'') 1961 | { 1962 | *start = &str[2]; str += 2; 1963 | while (*str) 1964 | { 1965 | if (*str == '\'') 1966 | { 1967 | *typ = TOKEN_EXT_STR; *len = str - *start; 1968 | return str + 1; 1969 | } 1970 | if (*str == '\\' && str[1] == '\'') 1971 | str += 2; 1972 | else if (*str == '\\' && str[1] == '\\') 1973 | str += 2; 1974 | else 1975 | str += 1; 1976 | } 1977 | 1978 | *typ = TOKEN_EXT_STR; *len = str - *start; 1979 | return str; 1980 | } 1981 | 1982 | /* String literal */ 1983 | if (*str == '\'') 1984 | { 1985 | *start = &str[1]; str += 1; 1986 | while (*str) 1987 | { 1988 | if (*str == '\'') 1989 | { 1990 | if (str[1] != '\'') 1991 | { 1992 | *typ = TOKEN_STR; *len = str - *start; 1993 | return str + 1; 1994 | } 1995 | str += 2; 1996 | } 1997 | else 1998 | str += 1; 1999 | } 2000 | *typ = TOKEN_STR; *len = str - *start; 2001 | return str; 2002 | } 2003 | 2004 | /* Quoted identifier */ 2005 | if (*str == '"') 2006 | { 2007 | *start = &str[1]; str += 1; 2008 | while (*str) 2009 | { 2010 | if (*str == '"') 2011 | { 2012 | if (str[1] != '"') 2013 | { 2014 | *typ = TOKEN_QIDENTIF; *len = str - *start; 2015 | return str + 1; 2016 | } 2017 | str += 2; 2018 | } 2019 | else 2020 | str += 1; 2021 | } 2022 | *typ = TOKEN_QIDENTIF; *len = str - *start; 2023 | return str; 2024 | } 2025 | 2026 | /* Identifiers */ 2027 | if (is_identif(*str) || *str == '_') 2028 | { 2029 | *start = str++; 2030 | while (*str) 2031 | { 2032 | if (is_identif(*str) || 2033 | isdigit(*str) || 2034 | *str == '_') 2035 | str++; 2036 | else 2037 | break; 2038 | } 2039 | *typ = TOKEN_IDENTIF; *len = str - *start; 2040 | return str; 2041 | } 2042 | 2043 | /* Others */ 2044 | *typ = TOKEN_OTHER; *start = str; *len = 1; 2045 | return str + 1; 2046 | } 2047 | 2048 | /* 2049 | * CREATE PROCEDURE dbms_sql.describe_columns(c int, OUT col_cnt int, OUT desc_t dbms_sql.desc_rec[]) 2050 | * 2051 | * Returns an array of column's descriptions. Attention, the typid are related to PostgreSQL type 2052 | * system. 2053 | */ 2054 | Datum 2055 | dbms_sql_describe_columns(PG_FUNCTION_ARGS) 2056 | { 2057 | CursorData *c; 2058 | Datum values[13]; 2059 | bool nulls[13]; 2060 | TupleDesc tupdesc; 2061 | TupleDesc desc_rec_tupdesc; 2062 | TupleDesc cursor_tupdesc; 2063 | HeapTuple tuple; 2064 | Oid arraytypid; 2065 | Oid desc_rec_typid; 2066 | Oid *types = NULL; 2067 | ArrayBuildState *abuilder; 2068 | SPIPlanPtr plan; 2069 | CachedPlanSource *plansource = NULL; 2070 | int ncolumns = 0; 2071 | int rc; 2072 | int i = 0; 2073 | bool nonatomic; 2074 | MemoryContext callercxt = CurrentMemoryContext; 2075 | 2076 | if (get_call_result_type(fcinfo, NULL, &tupdesc) != TYPEFUNC_COMPOSITE) 2077 | elog(ERROR, "return type must be a row type"); 2078 | 2079 | arraytypid = TupleDescAttr(tupdesc, 1)->atttypid; 2080 | desc_rec_typid = get_element_type(arraytypid); 2081 | 2082 | if (!OidIsValid(desc_rec_typid)) 2083 | elog(ERROR, "second output field must be an array"); 2084 | 2085 | desc_rec_tupdesc = lookup_rowtype_tupdesc_copy(desc_rec_typid, -1); 2086 | 2087 | abuilder = initArrayResult(desc_rec_typid, callercxt, true); 2088 | 2089 | c = get_cursor(fcinfo, true); 2090 | 2091 | if (c->variables) 2092 | { 2093 | ListCell *lc; 2094 | 2095 | types = palloc(sizeof(Oid) * c->nvariables); 2096 | i = 0; 2097 | 2098 | foreach(lc, c->variables) 2099 | { 2100 | VariableData *var = (VariableData *) lfirst(lc); 2101 | 2102 | if (var->typoid == InvalidOid) 2103 | ereport(ERROR, 2104 | (errcode(ERRCODE_UNDEFINED_PARAMETER), 2105 | errmsg("variable \"%s\" has not a value", var->refname))); 2106 | 2107 | types[i++] = var->is_array ? var->typelemid : var->typoid; 2108 | } 2109 | } 2110 | 2111 | /* 2112 | * Connect to SPI manager 2113 | */ 2114 | nonatomic = fcinfo->context && 2115 | IsA(fcinfo->context, CallContext) && 2116 | !castNode(CallContext, fcinfo->context)->atomic; 2117 | 2118 | if ((rc = SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0)) != SPI_OK_CONNECT) 2119 | elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc)); 2120 | 2121 | plan = SPI_prepare(c->parsed_query, c->nvariables, types); 2122 | if (!plan || plan->magic != _SPI_PLAN_MAGIC) 2123 | elog(ERROR, "plan is not valid"); 2124 | 2125 | if (list_length(plan->plancache_list) != 1) 2126 | elog(ERROR, "plan is not single execution plany"); 2127 | 2128 | plansource = (CachedPlanSource *) linitial(plan->plancache_list); 2129 | cursor_tupdesc = plansource->resultDesc; 2130 | 2131 | ncolumns = cursor_tupdesc->natts; 2132 | 2133 | for (i = 0; i < ncolumns; i++) 2134 | { 2135 | HeapTuple tp; 2136 | Form_pg_type typtup; 2137 | text *txt; 2138 | 2139 | Form_pg_attribute attr = TupleDescAttr(cursor_tupdesc, i); 2140 | 2141 | /* 2142 | * 0. col_type BINARY_INTEGER := 0, 2143 | * 1. col_max_len BINARY_INTEGER := 0, 2144 | * 2. col_name VARCHAR2(32) := '', 2145 | * 3. col_name_len BINARY_INTEGER := 0, 2146 | * 4. col_schema_name VARCHAR2(32) := '', 2147 | * 5. col_schema_name_len BINARY_INTEGER := 0, 2148 | * 6. col_precision BINARY_INTEGER := 0, 2149 | * 7. col_scale BINARY_INTEGER := 0, 2150 | * 8. col_charsetid BINARY_INTEGER := 0, 2151 | * 9. col_charsetform BINARY_INTEGER := 0, 2152 | * 10. col_null_ok BOOLEAN := TRUE 2153 | * 11. col_type_name varchar2 := '', 2154 | * 12. col_type_name_len BINARY_INTEGER := 0 ); 2155 | */ 2156 | 2157 | values[0] = Int32GetDatum(attr->atttypid); 2158 | 2159 | tp = SearchSysCache1(TYPEOID, ObjectIdGetDatum(attr->atttypid)); 2160 | if (!HeapTupleIsValid(tp)) 2161 | elog(ERROR, "cache lookup failed for type %u", attr->atttypid); 2162 | 2163 | typtup = (Form_pg_type) GETSTRUCT(tp); 2164 | 2165 | values[1] = Int32GetDatum(0); 2166 | values[6] = Int32GetDatum(0); 2167 | values[7] = Int32GetDatum(0); 2168 | 2169 | if (attr->attlen != -1) 2170 | values[1] = Int32GetDatum(attr->attlen); 2171 | else if (typtup->typcategory == 'S' && attr->atttypmod > VARHDRSZ) 2172 | values[1] = Int32GetDatum(attr->atttypmod - VARHDRSZ); 2173 | else if (attr->atttypid == NUMERICOID && attr->atttypmod > VARHDRSZ) 2174 | { 2175 | values[6] = Int32GetDatum(((attr->atttypmod - VARHDRSZ) >> 16) & 0xffff); 2176 | values[7] = Int32GetDatum((((attr->atttypmod - VARHDRSZ) & 0x7ff) ^ 1024) - 1024); 2177 | } 2178 | 2179 | txt = cstring_to_text(NameStr(attr->attname)); 2180 | values[2] = PointerGetDatum(txt); 2181 | values[3] = DirectFunctionCall1(textlen, PointerGetDatum(txt)); 2182 | 2183 | txt = cstring_to_text(get_namespace_name(typtup->typnamespace)); 2184 | values[4] = PointerGetDatum(txt); 2185 | values[5] = DirectFunctionCall1(textlen, PointerGetDatum(txt)); 2186 | 2187 | values[8] = Int32GetDatum(0); 2188 | values[9] = Int32GetDatum(0); 2189 | 2190 | values[10] = BoolGetDatum(true); 2191 | 2192 | if (attr->attnotnull) 2193 | values[10] = BoolGetDatum(false); 2194 | else if (typtup->typnotnull) 2195 | values[10] = BoolGetDatum(false); 2196 | 2197 | txt = cstring_to_text(NameStr(typtup->typname)); 2198 | values[11] = PointerGetDatum(txt); 2199 | values[12] = DirectFunctionCall1(textlen, PointerGetDatum(txt)); 2200 | 2201 | memset(nulls, 0, sizeof(nulls)); 2202 | 2203 | tuple = heap_form_tuple(desc_rec_tupdesc, values, nulls); 2204 | 2205 | abuilder = accumArrayResult(abuilder, 2206 | HeapTupleGetDatum(tuple), 2207 | false, 2208 | desc_rec_typid, 2209 | CurrentMemoryContext); 2210 | 2211 | ReleaseSysCache(tp); 2212 | } 2213 | 2214 | SPI_freeplan(plan); 2215 | 2216 | if ((rc = SPI_finish()) != SPI_OK_FINISH) 2217 | elog(ERROR, "SPI_finish failed: %s", SPI_result_code_string(rc)); 2218 | 2219 | MemoryContextSwitchTo(callercxt); 2220 | 2221 | memset(values, 0, sizeof(values)); 2222 | memset(nulls, 0, sizeof(nulls)); 2223 | 2224 | values[0] = Int32GetDatum(ncolumns); 2225 | nulls[0] = false; 2226 | 2227 | values[1] = makeArrayResult(abuilder, callercxt); 2228 | nulls[1] = false; 2229 | 2230 | tuple = heap_form_tuple(tupdesc, values, nulls); 2231 | 2232 | PG_RETURN_DATUM(HeapTupleGetDatum(tuple)); 2233 | } 2234 | 2235 | Datum 2236 | dbms_sql_describe_columns_f(PG_FUNCTION_ARGS) 2237 | { 2238 | return dbms_sql_describe_columns(fcinfo); 2239 | } 2240 | -------------------------------------------------------------------------------- /dbms_sql.control: -------------------------------------------------------------------------------- 1 | comment = 'Functions and operators that emulate dbms_sql package''s API' 2 | default_version = '1.0' 3 | module_pathname = '$libdir/dbms_sql' 4 | relocatable = false 5 | -------------------------------------------------------------------------------- /expected/dbms_sql.out: -------------------------------------------------------------------------------- 1 | do $$ 2 | declare 3 | c int; 4 | strval varchar; 5 | intval int; 6 | nrows int default 30; 7 | begin 8 | c := dbms_sql.open_cursor(); 9 | call dbms_sql.parse(c, 'select ''ahoj'' || i, i from generate_series(1, :nrows) g(i)'); 10 | call dbms_sql.bind_variable(c, 'nrows', nrows); 11 | call dbms_sql.define_column(c, 1, strval); 12 | call dbms_sql.define_column(c, 2, intval); 13 | perform dbms_sql.execute(c); 14 | while dbms_sql.fetch_rows(c) > 0 15 | loop 16 | call dbms_sql.column_value(c, 1, strval); 17 | call dbms_sql.column_value(c, 2, intval); 18 | raise notice 'c1: %, c2: %', strval, intval; 19 | end loop; 20 | call dbms_sql.close_cursor(c); 21 | end; 22 | $$; 23 | NOTICE: c1: ahoj1, c2: 1 24 | NOTICE: c1: ahoj2, c2: 2 25 | NOTICE: c1: ahoj3, c2: 3 26 | NOTICE: c1: ahoj4, c2: 4 27 | NOTICE: c1: ahoj5, c2: 5 28 | NOTICE: c1: ahoj6, c2: 6 29 | NOTICE: c1: ahoj7, c2: 7 30 | NOTICE: c1: ahoj8, c2: 8 31 | NOTICE: c1: ahoj9, c2: 9 32 | NOTICE: c1: ahoj10, c2: 10 33 | NOTICE: c1: ahoj11, c2: 11 34 | NOTICE: c1: ahoj12, c2: 12 35 | NOTICE: c1: ahoj13, c2: 13 36 | NOTICE: c1: ahoj14, c2: 14 37 | NOTICE: c1: ahoj15, c2: 15 38 | NOTICE: c1: ahoj16, c2: 16 39 | NOTICE: c1: ahoj17, c2: 17 40 | NOTICE: c1: ahoj18, c2: 18 41 | NOTICE: c1: ahoj19, c2: 19 42 | NOTICE: c1: ahoj20, c2: 20 43 | NOTICE: c1: ahoj21, c2: 21 44 | NOTICE: c1: ahoj22, c2: 22 45 | NOTICE: c1: ahoj23, c2: 23 46 | NOTICE: c1: ahoj24, c2: 24 47 | NOTICE: c1: ahoj25, c2: 25 48 | NOTICE: c1: ahoj26, c2: 26 49 | NOTICE: c1: ahoj27, c2: 27 50 | NOTICE: c1: ahoj28, c2: 28 51 | NOTICE: c1: ahoj29, c2: 29 52 | NOTICE: c1: ahoj30, c2: 30 53 | do $$ 54 | declare 55 | c int; 56 | strval varchar; 57 | intval int; 58 | nrows int default 30; 59 | begin 60 | c := dbms_sql.open_cursor(); 61 | call dbms_sql.parse(c, 'select ''ahoj'' || i, i from generate_series(1, :nrows) g(i)'); 62 | call dbms_sql.bind_variable(c, 'nrows', nrows); 63 | call dbms_sql.define_column(c, 1, strval); 64 | call dbms_sql.define_column(c, 2, intval); 65 | perform dbms_sql.execute(c); 66 | while dbms_sql.fetch_rows(c) > 0 67 | loop 68 | strval := dbms_sql.column_value_f(c, 1, strval); 69 | intval := dbms_sql.column_value_f(c, 2, intval); 70 | raise notice 'c1: %, c2: %', strval, intval; 71 | end loop; 72 | call dbms_sql.close_cursor(c); 73 | end; 74 | $$; 75 | NOTICE: c1: ahoj1, c2: 1 76 | NOTICE: c1: ahoj2, c2: 2 77 | NOTICE: c1: ahoj3, c2: 3 78 | NOTICE: c1: ahoj4, c2: 4 79 | NOTICE: c1: ahoj5, c2: 5 80 | NOTICE: c1: ahoj6, c2: 6 81 | NOTICE: c1: ahoj7, c2: 7 82 | NOTICE: c1: ahoj8, c2: 8 83 | NOTICE: c1: ahoj9, c2: 9 84 | NOTICE: c1: ahoj10, c2: 10 85 | NOTICE: c1: ahoj11, c2: 11 86 | NOTICE: c1: ahoj12, c2: 12 87 | NOTICE: c1: ahoj13, c2: 13 88 | NOTICE: c1: ahoj14, c2: 14 89 | NOTICE: c1: ahoj15, c2: 15 90 | NOTICE: c1: ahoj16, c2: 16 91 | NOTICE: c1: ahoj17, c2: 17 92 | NOTICE: c1: ahoj18, c2: 18 93 | NOTICE: c1: ahoj19, c2: 19 94 | NOTICE: c1: ahoj20, c2: 20 95 | NOTICE: c1: ahoj21, c2: 21 96 | NOTICE: c1: ahoj22, c2: 22 97 | NOTICE: c1: ahoj23, c2: 23 98 | NOTICE: c1: ahoj24, c2: 24 99 | NOTICE: c1: ahoj25, c2: 25 100 | NOTICE: c1: ahoj26, c2: 26 101 | NOTICE: c1: ahoj27, c2: 27 102 | NOTICE: c1: ahoj28, c2: 28 103 | NOTICE: c1: ahoj29, c2: 29 104 | NOTICE: c1: ahoj30, c2: 30 105 | create table foo(a int, b varchar, c numeric); 106 | do $$ 107 | declare c int; 108 | begin 109 | c := dbms_sql.open_cursor(); 110 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 111 | for i in 1..100 112 | loop 113 | call dbms_sql.bind_variable(c, 'a', i); 114 | call dbms_sql.bind_variable(c, 'b', 'Ahoj ' || i); 115 | call dbms_sql.bind_variable(c, 'c', i + 0.033); 116 | perform dbms_sql.execute(c); 117 | end loop; 118 | end; 119 | $$; 120 | select * from foo; 121 | a | b | c 122 | -----+----------+--------- 123 | 1 | Ahoj 1 | 1.033 124 | 2 | Ahoj 2 | 2.033 125 | 3 | Ahoj 3 | 3.033 126 | 4 | Ahoj 4 | 4.033 127 | 5 | Ahoj 5 | 5.033 128 | 6 | Ahoj 6 | 6.033 129 | 7 | Ahoj 7 | 7.033 130 | 8 | Ahoj 8 | 8.033 131 | 9 | Ahoj 9 | 9.033 132 | 10 | Ahoj 10 | 10.033 133 | 11 | Ahoj 11 | 11.033 134 | 12 | Ahoj 12 | 12.033 135 | 13 | Ahoj 13 | 13.033 136 | 14 | Ahoj 14 | 14.033 137 | 15 | Ahoj 15 | 15.033 138 | 16 | Ahoj 16 | 16.033 139 | 17 | Ahoj 17 | 17.033 140 | 18 | Ahoj 18 | 18.033 141 | 19 | Ahoj 19 | 19.033 142 | 20 | Ahoj 20 | 20.033 143 | 21 | Ahoj 21 | 21.033 144 | 22 | Ahoj 22 | 22.033 145 | 23 | Ahoj 23 | 23.033 146 | 24 | Ahoj 24 | 24.033 147 | 25 | Ahoj 25 | 25.033 148 | 26 | Ahoj 26 | 26.033 149 | 27 | Ahoj 27 | 27.033 150 | 28 | Ahoj 28 | 28.033 151 | 29 | Ahoj 29 | 29.033 152 | 30 | Ahoj 30 | 30.033 153 | 31 | Ahoj 31 | 31.033 154 | 32 | Ahoj 32 | 32.033 155 | 33 | Ahoj 33 | 33.033 156 | 34 | Ahoj 34 | 34.033 157 | 35 | Ahoj 35 | 35.033 158 | 36 | Ahoj 36 | 36.033 159 | 37 | Ahoj 37 | 37.033 160 | 38 | Ahoj 38 | 38.033 161 | 39 | Ahoj 39 | 39.033 162 | 40 | Ahoj 40 | 40.033 163 | 41 | Ahoj 41 | 41.033 164 | 42 | Ahoj 42 | 42.033 165 | 43 | Ahoj 43 | 43.033 166 | 44 | Ahoj 44 | 44.033 167 | 45 | Ahoj 45 | 45.033 168 | 46 | Ahoj 46 | 46.033 169 | 47 | Ahoj 47 | 47.033 170 | 48 | Ahoj 48 | 48.033 171 | 49 | Ahoj 49 | 49.033 172 | 50 | Ahoj 50 | 50.033 173 | 51 | Ahoj 51 | 51.033 174 | 52 | Ahoj 52 | 52.033 175 | 53 | Ahoj 53 | 53.033 176 | 54 | Ahoj 54 | 54.033 177 | 55 | Ahoj 55 | 55.033 178 | 56 | Ahoj 56 | 56.033 179 | 57 | Ahoj 57 | 57.033 180 | 58 | Ahoj 58 | 58.033 181 | 59 | Ahoj 59 | 59.033 182 | 60 | Ahoj 60 | 60.033 183 | 61 | Ahoj 61 | 61.033 184 | 62 | Ahoj 62 | 62.033 185 | 63 | Ahoj 63 | 63.033 186 | 64 | Ahoj 64 | 64.033 187 | 65 | Ahoj 65 | 65.033 188 | 66 | Ahoj 66 | 66.033 189 | 67 | Ahoj 67 | 67.033 190 | 68 | Ahoj 68 | 68.033 191 | 69 | Ahoj 69 | 69.033 192 | 70 | Ahoj 70 | 70.033 193 | 71 | Ahoj 71 | 71.033 194 | 72 | Ahoj 72 | 72.033 195 | 73 | Ahoj 73 | 73.033 196 | 74 | Ahoj 74 | 74.033 197 | 75 | Ahoj 75 | 75.033 198 | 76 | Ahoj 76 | 76.033 199 | 77 | Ahoj 77 | 77.033 200 | 78 | Ahoj 78 | 78.033 201 | 79 | Ahoj 79 | 79.033 202 | 80 | Ahoj 80 | 80.033 203 | 81 | Ahoj 81 | 81.033 204 | 82 | Ahoj 82 | 82.033 205 | 83 | Ahoj 83 | 83.033 206 | 84 | Ahoj 84 | 84.033 207 | 85 | Ahoj 85 | 85.033 208 | 86 | Ahoj 86 | 86.033 209 | 87 | Ahoj 87 | 87.033 210 | 88 | Ahoj 88 | 88.033 211 | 89 | Ahoj 89 | 89.033 212 | 90 | Ahoj 90 | 90.033 213 | 91 | Ahoj 91 | 91.033 214 | 92 | Ahoj 92 | 92.033 215 | 93 | Ahoj 93 | 93.033 216 | 94 | Ahoj 94 | 94.033 217 | 95 | Ahoj 95 | 95.033 218 | 96 | Ahoj 96 | 96.033 219 | 97 | Ahoj 97 | 97.033 220 | 98 | Ahoj 98 | 98.033 221 | 99 | Ahoj 99 | 99.033 222 | 100 | Ahoj 100 | 100.033 223 | (100 rows) 224 | 225 | truncate foo; 226 | do $$ 227 | declare c int; 228 | begin 229 | c := dbms_sql.open_cursor(); 230 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 231 | for i in 1..100 232 | loop 233 | perform dbms_sql.bind_variable_f(c, 'a', i); 234 | perform dbms_sql.bind_variable_f(c, 'b', 'Ahoj ' || i); 235 | perform dbms_sql.bind_variable_f(c, 'c', i + 0.033); 236 | perform dbms_sql.execute(c); 237 | end loop; 238 | end; 239 | $$; 240 | select * from foo; 241 | a | b | c 242 | -----+----------+--------- 243 | 1 | Ahoj 1 | 1.033 244 | 2 | Ahoj 2 | 2.033 245 | 3 | Ahoj 3 | 3.033 246 | 4 | Ahoj 4 | 4.033 247 | 5 | Ahoj 5 | 5.033 248 | 6 | Ahoj 6 | 6.033 249 | 7 | Ahoj 7 | 7.033 250 | 8 | Ahoj 8 | 8.033 251 | 9 | Ahoj 9 | 9.033 252 | 10 | Ahoj 10 | 10.033 253 | 11 | Ahoj 11 | 11.033 254 | 12 | Ahoj 12 | 12.033 255 | 13 | Ahoj 13 | 13.033 256 | 14 | Ahoj 14 | 14.033 257 | 15 | Ahoj 15 | 15.033 258 | 16 | Ahoj 16 | 16.033 259 | 17 | Ahoj 17 | 17.033 260 | 18 | Ahoj 18 | 18.033 261 | 19 | Ahoj 19 | 19.033 262 | 20 | Ahoj 20 | 20.033 263 | 21 | Ahoj 21 | 21.033 264 | 22 | Ahoj 22 | 22.033 265 | 23 | Ahoj 23 | 23.033 266 | 24 | Ahoj 24 | 24.033 267 | 25 | Ahoj 25 | 25.033 268 | 26 | Ahoj 26 | 26.033 269 | 27 | Ahoj 27 | 27.033 270 | 28 | Ahoj 28 | 28.033 271 | 29 | Ahoj 29 | 29.033 272 | 30 | Ahoj 30 | 30.033 273 | 31 | Ahoj 31 | 31.033 274 | 32 | Ahoj 32 | 32.033 275 | 33 | Ahoj 33 | 33.033 276 | 34 | Ahoj 34 | 34.033 277 | 35 | Ahoj 35 | 35.033 278 | 36 | Ahoj 36 | 36.033 279 | 37 | Ahoj 37 | 37.033 280 | 38 | Ahoj 38 | 38.033 281 | 39 | Ahoj 39 | 39.033 282 | 40 | Ahoj 40 | 40.033 283 | 41 | Ahoj 41 | 41.033 284 | 42 | Ahoj 42 | 42.033 285 | 43 | Ahoj 43 | 43.033 286 | 44 | Ahoj 44 | 44.033 287 | 45 | Ahoj 45 | 45.033 288 | 46 | Ahoj 46 | 46.033 289 | 47 | Ahoj 47 | 47.033 290 | 48 | Ahoj 48 | 48.033 291 | 49 | Ahoj 49 | 49.033 292 | 50 | Ahoj 50 | 50.033 293 | 51 | Ahoj 51 | 51.033 294 | 52 | Ahoj 52 | 52.033 295 | 53 | Ahoj 53 | 53.033 296 | 54 | Ahoj 54 | 54.033 297 | 55 | Ahoj 55 | 55.033 298 | 56 | Ahoj 56 | 56.033 299 | 57 | Ahoj 57 | 57.033 300 | 58 | Ahoj 58 | 58.033 301 | 59 | Ahoj 59 | 59.033 302 | 60 | Ahoj 60 | 60.033 303 | 61 | Ahoj 61 | 61.033 304 | 62 | Ahoj 62 | 62.033 305 | 63 | Ahoj 63 | 63.033 306 | 64 | Ahoj 64 | 64.033 307 | 65 | Ahoj 65 | 65.033 308 | 66 | Ahoj 66 | 66.033 309 | 67 | Ahoj 67 | 67.033 310 | 68 | Ahoj 68 | 68.033 311 | 69 | Ahoj 69 | 69.033 312 | 70 | Ahoj 70 | 70.033 313 | 71 | Ahoj 71 | 71.033 314 | 72 | Ahoj 72 | 72.033 315 | 73 | Ahoj 73 | 73.033 316 | 74 | Ahoj 74 | 74.033 317 | 75 | Ahoj 75 | 75.033 318 | 76 | Ahoj 76 | 76.033 319 | 77 | Ahoj 77 | 77.033 320 | 78 | Ahoj 78 | 78.033 321 | 79 | Ahoj 79 | 79.033 322 | 80 | Ahoj 80 | 80.033 323 | 81 | Ahoj 81 | 81.033 324 | 82 | Ahoj 82 | 82.033 325 | 83 | Ahoj 83 | 83.033 326 | 84 | Ahoj 84 | 84.033 327 | 85 | Ahoj 85 | 85.033 328 | 86 | Ahoj 86 | 86.033 329 | 87 | Ahoj 87 | 87.033 330 | 88 | Ahoj 88 | 88.033 331 | 89 | Ahoj 89 | 89.033 332 | 90 | Ahoj 90 | 90.033 333 | 91 | Ahoj 91 | 91.033 334 | 92 | Ahoj 92 | 92.033 335 | 93 | Ahoj 93 | 93.033 336 | 94 | Ahoj 94 | 94.033 337 | 95 | Ahoj 95 | 95.033 338 | 96 | Ahoj 96 | 96.033 339 | 97 | Ahoj 97 | 97.033 340 | 98 | Ahoj 98 | 98.033 341 | 99 | Ahoj 99 | 99.033 342 | 100 | Ahoj 100 | 100.033 343 | (100 rows) 344 | 345 | truncate foo; 346 | do $$ 347 | declare 348 | c int; 349 | a int[]; 350 | b varchar[]; 351 | ca numeric[]; 352 | begin 353 | c := dbms_sql.open_cursor(); 354 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 355 | a := ARRAY[1, 2, 3, 4, 5]; 356 | b := ARRAY['Ahoj', 'Nazdar', 'Bazar']; 357 | ca := ARRAY[3.14, 2.22, 3.8, 4]; 358 | 359 | call dbms_sql.bind_array(c, 'a', a); 360 | call dbms_sql.bind_array(c, 'b', b); 361 | call dbms_sql.bind_array(c, 'c', ca); 362 | raise notice 'inserted rows %d', dbms_sql.execute(c); 363 | end; 364 | $$; 365 | NOTICE: inserted rows 3d 366 | select * from foo; 367 | a | b | c 368 | ---+--------+------ 369 | 1 | Ahoj | 3.14 370 | 2 | Nazdar | 2.22 371 | 3 | Bazar | 3.8 372 | (3 rows) 373 | 374 | truncate foo; 375 | do $$ 376 | declare 377 | c int; 378 | a int[]; 379 | b varchar[]; 380 | ca numeric[]; 381 | begin 382 | c := dbms_sql.open_cursor(); 383 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 384 | a := ARRAY[1, 2, 3, 4, 5]; 385 | b := ARRAY['Ahoj', 'Nazdar', 'Bazar']; 386 | ca := ARRAY[3.14, 2.22, 3.8, 4]; 387 | 388 | call dbms_sql.bind_array(c, 'a', a, 2, 3); 389 | call dbms_sql.bind_array(c, 'b', b, 3, 4); 390 | call dbms_sql.bind_array(c, 'c', ca); 391 | raise notice 'inserted rows %d', dbms_sql.execute(c); 392 | end; 393 | $$; 394 | NOTICE: inserted rows 1d 395 | select * from foo; 396 | a | b | c 397 | ---+-------+----- 398 | 3 | Bazar | 3.8 399 | (1 row) 400 | 401 | truncate foo; 402 | do $$ 403 | declare 404 | c int; 405 | a int[]; 406 | b varchar[]; 407 | ca numeric[]; 408 | begin 409 | c := dbms_sql.open_cursor(); 410 | call dbms_sql.parse(c, 'select i, ''Ahoj'' || i, i + 0.003 from generate_series(1, 35) g(i)'); 411 | call dbms_sql.define_array(c, 1, a, 10, 1); 412 | call dbms_sql.define_array(c, 2, b, 10, 1); 413 | call dbms_sql.define_array(c, 3, ca, 10, 1); 414 | 415 | perform dbms_sql.execute(c); 416 | while dbms_sql.fetch_rows(c) > 0 417 | loop 418 | call dbms_sql.column_value(c, 1, a); 419 | call dbms_sql.column_value(c, 2, b); 420 | call dbms_sql.column_value(c, 3, ca); 421 | raise notice 'a = %', a; 422 | raise notice 'b = %', b; 423 | raise notice 'c = %', ca; 424 | end loop; 425 | call dbms_sql.close_cursor(c); 426 | end; 427 | $$; 428 | NOTICE: a = {1,2,3,4,5,6,7,8,9,10} 429 | NOTICE: b = {Ahoj1,Ahoj2,Ahoj3,Ahoj4,Ahoj5,Ahoj6,Ahoj7,Ahoj8,Ahoj9,Ahoj10} 430 | NOTICE: c = {1.003,2.003,3.003,4.003,5.003,6.003,7.003,8.003,9.003,10.003} 431 | NOTICE: a = {11,12,13,14,15,16,17,18,19,20} 432 | NOTICE: b = {Ahoj11,Ahoj12,Ahoj13,Ahoj14,Ahoj15,Ahoj16,Ahoj17,Ahoj18,Ahoj19,Ahoj20} 433 | NOTICE: c = {11.003,12.003,13.003,14.003,15.003,16.003,17.003,18.003,19.003,20.003} 434 | NOTICE: a = {21,22,23,24,25,26,27,28,29,30} 435 | NOTICE: b = {Ahoj21,Ahoj22,Ahoj23,Ahoj24,Ahoj25,Ahoj26,Ahoj27,Ahoj28,Ahoj29,Ahoj30} 436 | NOTICE: c = {21.003,22.003,23.003,24.003,25.003,26.003,27.003,28.003,29.003,30.003} 437 | NOTICE: a = {31,32,33,34,35} 438 | NOTICE: b = {Ahoj31,Ahoj32,Ahoj33,Ahoj34,Ahoj35} 439 | NOTICE: c = {31.003,32.003,33.003,34.003,35.003} 440 | -------------------------------------------------------------------------------- /expected/init.out: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | -------------------------------------------------------------------------------- /sql/dbms_sql.sql: -------------------------------------------------------------------------------- 1 | do $$ 2 | declare 3 | c int; 4 | strval varchar; 5 | intval int; 6 | nrows int default 30; 7 | begin 8 | c := dbms_sql.open_cursor(); 9 | call dbms_sql.parse(c, 'select ''ahoj'' || i, i from generate_series(1, :nrows) g(i)'); 10 | call dbms_sql.bind_variable(c, 'nrows', nrows); 11 | call dbms_sql.define_column(c, 1, strval); 12 | call dbms_sql.define_column(c, 2, intval); 13 | perform dbms_sql.execute(c); 14 | while dbms_sql.fetch_rows(c) > 0 15 | loop 16 | call dbms_sql.column_value(c, 1, strval); 17 | call dbms_sql.column_value(c, 2, intval); 18 | raise notice 'c1: %, c2: %', strval, intval; 19 | end loop; 20 | call dbms_sql.close_cursor(c); 21 | end; 22 | $$; 23 | 24 | do $$ 25 | declare 26 | c int; 27 | strval varchar; 28 | intval int; 29 | nrows int default 30; 30 | begin 31 | c := dbms_sql.open_cursor(); 32 | call dbms_sql.parse(c, 'select ''ahoj'' || i, i from generate_series(1, :nrows) g(i)'); 33 | call dbms_sql.bind_variable(c, 'nrows', nrows); 34 | call dbms_sql.define_column(c, 1, strval); 35 | call dbms_sql.define_column(c, 2, intval); 36 | perform dbms_sql.execute(c); 37 | while dbms_sql.fetch_rows(c) > 0 38 | loop 39 | strval := dbms_sql.column_value_f(c, 1, strval); 40 | intval := dbms_sql.column_value_f(c, 2, intval); 41 | raise notice 'c1: %, c2: %', strval, intval; 42 | end loop; 43 | call dbms_sql.close_cursor(c); 44 | end; 45 | $$; 46 | 47 | create table foo(a int, b varchar, c numeric); 48 | 49 | do $$ 50 | declare c int; 51 | begin 52 | c := dbms_sql.open_cursor(); 53 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 54 | for i in 1..100 55 | loop 56 | call dbms_sql.bind_variable(c, 'a', i); 57 | call dbms_sql.bind_variable(c, 'b', 'Ahoj ' || i); 58 | call dbms_sql.bind_variable(c, 'c', i + 0.033); 59 | perform dbms_sql.execute(c); 60 | end loop; 61 | end; 62 | $$; 63 | 64 | select * from foo; 65 | truncate foo; 66 | 67 | do $$ 68 | declare c int; 69 | begin 70 | c := dbms_sql.open_cursor(); 71 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 72 | for i in 1..100 73 | loop 74 | perform dbms_sql.bind_variable_f(c, 'a', i); 75 | perform dbms_sql.bind_variable_f(c, 'b', 'Ahoj ' || i); 76 | perform dbms_sql.bind_variable_f(c, 'c', i + 0.033); 77 | perform dbms_sql.execute(c); 78 | end loop; 79 | end; 80 | $$; 81 | 82 | select * from foo; 83 | truncate foo; 84 | 85 | 86 | do $$ 87 | declare 88 | c int; 89 | a int[]; 90 | b varchar[]; 91 | ca numeric[]; 92 | begin 93 | c := dbms_sql.open_cursor(); 94 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 95 | a := ARRAY[1, 2, 3, 4, 5]; 96 | b := ARRAY['Ahoj', 'Nazdar', 'Bazar']; 97 | ca := ARRAY[3.14, 2.22, 3.8, 4]; 98 | 99 | call dbms_sql.bind_array(c, 'a', a); 100 | call dbms_sql.bind_array(c, 'b', b); 101 | call dbms_sql.bind_array(c, 'c', ca); 102 | raise notice 'inserted rows %d', dbms_sql.execute(c); 103 | end; 104 | $$; 105 | 106 | select * from foo; 107 | truncate foo; 108 | 109 | do $$ 110 | declare 111 | c int; 112 | a int[]; 113 | b varchar[]; 114 | ca numeric[]; 115 | begin 116 | c := dbms_sql.open_cursor(); 117 | call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)'); 118 | a := ARRAY[1, 2, 3, 4, 5]; 119 | b := ARRAY['Ahoj', 'Nazdar', 'Bazar']; 120 | ca := ARRAY[3.14, 2.22, 3.8, 4]; 121 | 122 | call dbms_sql.bind_array(c, 'a', a, 2, 3); 123 | call dbms_sql.bind_array(c, 'b', b, 3, 4); 124 | call dbms_sql.bind_array(c, 'c', ca); 125 | raise notice 'inserted rows %d', dbms_sql.execute(c); 126 | end; 127 | $$; 128 | 129 | select * from foo; 130 | truncate foo; 131 | 132 | do $$ 133 | declare 134 | c int; 135 | a int[]; 136 | b varchar[]; 137 | ca numeric[]; 138 | begin 139 | c := dbms_sql.open_cursor(); 140 | call dbms_sql.parse(c, 'select i, ''Ahoj'' || i, i + 0.003 from generate_series(1, 35) g(i)'); 141 | call dbms_sql.define_array(c, 1, a, 10, 1); 142 | call dbms_sql.define_array(c, 2, b, 10, 1); 143 | call dbms_sql.define_array(c, 3, ca, 10, 1); 144 | 145 | perform dbms_sql.execute(c); 146 | while dbms_sql.fetch_rows(c) > 0 147 | loop 148 | call dbms_sql.column_value(c, 1, a); 149 | call dbms_sql.column_value(c, 2, b); 150 | call dbms_sql.column_value(c, 3, ca); 151 | raise notice 'a = %', a; 152 | raise notice 'b = %', b; 153 | raise notice 'c = %', ca; 154 | end loop; 155 | call dbms_sql.close_cursor(c); 156 | end; 157 | $$; 158 | -------------------------------------------------------------------------------- /sql/init.sql: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | set client_min_messages TO error; 3 | CREATE EXTENSION IF NOT EXISTS dbms_sql; 4 | set client_min_messages TO default; --------------------------------------------------------------------------------