├── Changes ├── META.json ├── Makefile ├── README.md ├── doc └── hostname.md ├── hostname.control ├── sql ├── hostname--unpackaged--1.0.0.sql ├── hostname.sql └── uninstall_hostname.sql ├── src └── hostname.c └── test ├── expected └── base.out ├── pgtap-core.sql └── sql └── base.sql /Changes: -------------------------------------------------------------------------------- 1 | Revision history for PostgreSQL extension hostname. 2 | 3 | 1.0.4 2025-04-29T18:18:16Z 4 | - Removed the `$libdir/` prefix from the `module_pathname` directive, 5 | so that the module can be installed and found in any directory listed 6 | in `dynamic_library_path`. 7 | - The version of the extension itself remains 1.0.0. 8 | - Supports PostgreSQL 9.0–18. 9 | 10 | 1.0.3 2023-09-10T16:34:04Z 11 | - Fixed build failure on Postgres 16 12 | 13 | 1.0.2 2018-11-10T20:17:35Z 14 | - Fixed test failure on Postgres 11. 15 | 16 | 1.0.1 2014-01-04T00:22:52Z 17 | - Fixed the Makefile to recognize the `PG_CONFIG` environment variable. 18 | - Fixed the Makefile to confirm to pgsql-hackers recommendations. 19 | - Changed the Makefile to read the distribution name and version from 20 | META.json. 21 | - Documented that `` is required. 22 | - Fixed an installation issue on PostgreSQL 9.3.2. 23 | 24 | 1.0.0 2013-04-24T00:20:51Z 25 | - Initial version. 26 | - Based on https://wiki.postgresql.org/wiki/Pg_gethostname 27 | - With many thanks to Sean Chittenden for C implementation advice and 28 | constructive criticism. 29 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "hostname", 3 | "abstract": "Get the server host name", 4 | "description": "Provides a function that returns the host name of the database server.", 5 | "version": "1.0.4", 6 | "maintainer": "David E. Wheeler ", 7 | "license": "postgresql", 8 | "provides": { 9 | "hostname": { 10 | "abstract": "Get the server host name", 11 | "file": "sql/hostname.sql", 12 | "docfile": "doc/hostname.mmd", 13 | "version": "1.0.0" 14 | } 15 | }, 16 | "prereqs": { 17 | "runtime": { 18 | "requires": { 19 | "PostgreSQL": "9.0.0" 20 | } 21 | } 22 | }, 23 | "resources": { 24 | "bugtracker": { 25 | "web": "http://github.com/theory/pg-hostname/issues/" 26 | }, 27 | "repository": { 28 | "url": "git://github.com/theory/pg-hostname.git", 29 | "web": "http://github.com/theory/pg-hostname/", 30 | "type": "git" 31 | } 32 | }, 33 | "generated_by": "David E. Wheeler", 34 | "meta-spec": { 35 | "version": "1.0.0", 36 | "url": "http://pgxn.org/meta/spec.txt" 37 | }, 38 | "tags": [ 39 | "hostname", 40 | "host", 41 | "gethostbyname" 42 | ] 43 | } 44 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = $(shell grep -m 1 '"name":' META.json | \ 2 | sed -e 's/[[:space:]]*"name":[[:space:]]*"\([^"]*\)",/\1/') 3 | EXTVERSION = $(shell grep -m 1 '[[:space:]]\{8\}"version":' META.json | \ 4 | sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') 5 | DISTVERSION = $(shell grep -m 1 '[[:space:]]\{3\}"version":' META.json | \ 6 | sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') 7 | 8 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 9 | DOCS = $(wildcard doc/*.md) 10 | TESTS = $(wildcard test/sql/*.sql) 11 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 12 | REGRESS_OPTS = --inputdir=test 13 | MODULES = $(patsubst %.c,%,$(wildcard src/*.c)) 14 | PG_CONFIG ?= pg_config 15 | PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes) 16 | 17 | ifeq ($(PG91),yes) 18 | DATA = $(wildcard sql/*--*.sql) 19 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql 20 | endif 21 | 22 | PGXS := $(shell $(PG_CONFIG) --pgxs) 23 | include $(PGXS) 24 | 25 | ifeq ($(PG91),yes) 26 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 27 | 28 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 29 | cp $< $@ 30 | endif 31 | 32 | dist: 33 | git archive --format zip --prefix=$(EXTENSION)-$(DISTVERSION)/ -o $(EXTENSION)-$(DISTVERSION).zip HEAD 34 | 35 | latest-changes.md: Changes 36 | perl -e 'while (<>) {last if /^(v?\Q${DISTVERSION}\E)/; } print "Changes for v${DISTVERSION}:\n"; while (<>) { last if /^\s*$$/; s/^\s+//; print }' Changes > $@ 37 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | hostname 1.0.4 2 | ============== 3 | 4 | [![PGXN version](https://badge.fury.io/pg/hostname.svg)](https://badge.fury.io/pg/hostname) 5 | [![Build Status](https://github.com/theory/pg-hostname/actions/workflows/ci.yml/badge.svg)](https://github.com/theory/pg-hostname/actions) 6 | 7 | This library contains a single PostgreSQL extension, `hostname`, which 8 | provides a function, `hostname()`, that returns the database server's host 9 | name: 10 | 11 | ```psql 12 | % SELECT hostname(); 13 | hostname 14 | ---------- 15 | myserver 16 | ``` 17 | 18 | To build hostname, just do this: 19 | 20 | ```sh 21 | make 22 | make installcheck 23 | make install 24 | ``` 25 | 26 | If you encounter an error such as: 27 | 28 | ``` 29 | "Makefile", line 8: Need an operator 30 | ``` 31 | 32 | You need to use GNU make, which may well be installed on your system as 33 | `gmake`: 34 | 35 | ```sh 36 | gmake 37 | gmake install 38 | gmake installcheck 39 | ``` 40 | 41 | If you encounter an error such as: 42 | 43 | ``` 44 | make: pg_config: Command not found 45 | ``` 46 | 47 | Be sure that you have `pg_config` installed and in your path. If you used a 48 | package management system such as RPM to install PostgreSQL, be sure that the 49 | `-devel` package is also installed. If necessary tell the build process where 50 | to find it: 51 | 52 | ```sh 53 | env PG_CONFIG=/path/to/pg_config make && make installcheck && make install 54 | ``` 55 | 56 | If you encounter an error such as: 57 | 58 | ``` 59 | ERROR: must be owner of database regression 60 | ``` 61 | 62 | You need to run the test suite using a super user, such as the default 63 | "postgres" super user: 64 | 65 | ```sh 66 | make installcheck PGUSER=postgres 67 | ``` 68 | 69 | To install the extension in a custom prefix on PostgreSQL 18 or later, pass 70 | the `prefix` argument to `install` (but no other `make` targets): 71 | 72 | ```sh 73 | make install prefix=/usr/local/extras 74 | ``` 75 | 76 | Then ensure that the prefix is included in the following [`postgresql.conf` 77 | parameters]: 78 | 79 | ```ini 80 | extension_control_path = '/usr/local/extras/postgresql/share:$system' 81 | dynamic_library_path = '/usr/local/extras/postgresql/lib:$libdir' 82 | ``` 83 | 84 | Once hostname is installed, you can add it to a database. If you're running 85 | PostgreSQL 9.1.0 or greater, it's a simple as connecting to a database as a 86 | super user and running: 87 | 88 | ```sql 89 | CREATE EXTENSION hostname; 90 | ``` 91 | 92 | If you've upgraded your cluster to PostgreSQL 9.1 and already had hostname 93 | installed, you can upgrade it to a properly packaged extension with: 94 | 95 | ```sql 96 | CREATE EXTENSION hostname FROM unpackaged; 97 | ``` 98 | 99 | For versions of PostgreSQL less than 9.1.0, you'll need to run the 100 | installation script: 101 | 102 | ```sh 103 | psql -d mydb -f /path/to/pgsql/share/contrib/hostname.sql 104 | ``` 105 | 106 | If you want to install hostname and all of its supporting objects into a 107 | specific schema, use the `PGOPTIONS` environment variable to specify the 108 | schema, like so: 109 | 110 | ```sh 111 | PGOPTIONS=--search_path=extensions psql -d mydb -f hostname.sql 112 | ``` 113 | 114 | Dependencies 115 | ----------- 116 | 117 | The `hostname` extension requires PostgreSQL 9.0 or higher and the POSIX API, 118 | ``. 119 | 120 | Copyright and License 121 | --------------------- 122 | 123 | Copyright (c) 2013-2025 David E. Wheeler. 124 | 125 | This module is free software; you can redistribute it and/or modify it under 126 | the [PostgreSQL License](http://www.opensource.org/licenses/postgresql). 127 | 128 | Permission to use, copy, modify, and distribute this software and its 129 | documentation for any purpose, without fee, and without a written agreement is 130 | hereby granted, provided that the above copyright notice and this paragraph 131 | and the following two paragraphs appear in all copies. 132 | 133 | In no event shall David E. Wheeler be liable to any party for direct, 134 | indirect, special, incidental, or consequential damages, including lost 135 | profits, arising out of the use of this software and its documentation, even 136 | if David E. Wheeler has been advised of the possibility of such damage. 137 | 138 | David E. Wheeler specifically disclaim any warranties, including, but not 139 | limited to, the implied warranties of merchantability and fitness for a 140 | particular purpose. The software provided hereunder is on an "as is" basis, 141 | and David E. Wheeler have no obligations to provide maintenance, support, 142 | updates, enhancements, or modifications. 143 | 144 | [`postgresql.conf` parameters]: https://www.postgresql.org/docs/devel/runtime-config-client.html#RUNTIME-CONFIG-CLIENT-OTHER 145 | -------------------------------------------------------------------------------- /doc/hostname.md: -------------------------------------------------------------------------------- 1 | hostname 1.0.0 2 | ============== 3 | 4 | Synopsis 5 | -------- 6 | 7 | ```sql 8 | CREATE EXTENSION hostname; 9 | 10 | SELECT hostname(); 11 | hostname 12 | -------------------- 13 | myhost.example.com 14 | ``` 15 | 16 | Description 17 | ----------- 18 | 19 | This library contains a single PostgreSQL function, `hostname()`, which 20 | returns the PostgreSQL server host name. The function uses `gethostname()` 21 | to get the host name. If it fails, `NULL` will be returned. If you need it 22 | not to return `NULL`, use `COALESCE()`: 23 | 24 | ```sql 25 | SELECT COALESCE(NULL, '[unknown]'); 26 | coalesce 27 | ----------- 28 | [unknown] 29 | ``` 30 | 31 | Author 32 | ------ 33 | 34 | [David E. Wheeler](http://www.justatheory.com/), based on code posted to the 35 | [PostgreSQL Wiki by "Brick"](https://wiki.postgresql.org/wiki/Pg_gethostname), 36 | and with many thanks to Sean Chittenden for C implementation advice and 37 | constructive criticism. 38 | 39 | Copyright and License 40 | --------------------- 41 | 42 | Copyright (c) 2013-2025 David E. Wheeler. 43 | 44 | This module is free software; you can redistribute it and/or modify it under 45 | the [PostgreSQL License](http://www.opensource.org/licenses/postgresql). 46 | 47 | Permission to use, copy, modify, and distribute this software and its 48 | documentation for any purpose, without fee, and without a written agreement is 49 | hereby granted, provided that the above copyright notice and this paragraph 50 | and the following two paragraphs appear in all copies. 51 | 52 | In no event shall David E. Wheeler be liable to any party for direct, 53 | indirect, special, incidental, or consequential damages, including lost 54 | profits, arising out of the use of this software and its documentation, even 55 | if David E. Wheeler has been advised of the possibility of such damage. 56 | 57 | David E. Wheeler specifically disclaim any warranties, including, but not 58 | limited to, the implied warranties of merchantability and fitness for a 59 | particular purpose. The software provided hereunder is on an "as is" basis, 60 | and David E. Wheeler have no obligations to provide maintenance, support, 61 | updates, enhancements, or modifications. 62 | -------------------------------------------------------------------------------- /hostname.control: -------------------------------------------------------------------------------- 1 | # hostname extension 2 | comment = 'Get the server host name' 3 | default_version = '1.0.0' 4 | module_pathname = 'hostname' 5 | relocatable = true 6 | -------------------------------------------------------------------------------- /sql/hostname--unpackaged--1.0.0.sql: -------------------------------------------------------------------------------- 1 | ALTER EXTENSION hostname ADD FUNCTION hostname(); 2 | -------------------------------------------------------------------------------- /sql/hostname.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION hostname( 2 | ) RETURNS TEXT AS 'hostname' LANGUAGE C IMMUTABLE STRICT; 3 | 4 | -------------------------------------------------------------------------------- /sql/uninstall_hostname.sql: -------------------------------------------------------------------------------- 1 | DROP FUNCTION hostname(); 2 | -------------------------------------------------------------------------------- /src/hostname.c: -------------------------------------------------------------------------------- 1 | /* 2 | A PostgreSQL function for getting the hostname. 3 | Based on https://wiki.postgresql.org/wiki/hostname 4 | With thanks to seanc on Freenode for improvements. 5 | */ 6 | 7 | #include "postgres.h" 8 | #include 9 | #include "fmgr.h" 10 | #if PG_VERSION_NUM >= 160000 11 | #include "varatt.h" 12 | #endif 13 | 14 | #ifdef PG_MODULE_MAGIC 15 | PG_MODULE_MAGIC; 16 | #endif 17 | 18 | PG_FUNCTION_INFO_V1( hostname ); 19 | 20 | Datum hostname( PG_FUNCTION_ARGS ); 21 | 22 | Datum hostname( PG_FUNCTION_ARGS ) 23 | { 24 | const int max_len = sysconf(_SC_HOST_NAME_MAX); 25 | size_t length = 0; 26 | char *server_hostname = NULL; 27 | text *t = NULL; 28 | 29 | /* Set up the buffer for the host name. */ 30 | server_hostname = palloc(max_len + 1); 31 | server_hostname[max_len] = '\0'; 32 | 33 | if ( gethostname( server_hostname, max_len ) != 0 ) 34 | { 35 | /* Just return null if we can't determine the host name. */ 36 | PG_RETURN_NULL(); 37 | } 38 | 39 | /* Return text. */ 40 | length = strlen( server_hostname ); 41 | t = (text *) palloc(VARHDRSZ + length ); 42 | SET_VARSIZE( t, VARHDRSZ + length ); 43 | memcpy( VARDATA(t), server_hostname, length ); 44 | 45 | PG_RETURN_TEXT_P( t ); 46 | } 47 | -------------------------------------------------------------------------------- /test/expected/base.out: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | ?column? 3 | ---------- 4 | t 5 | (1 row) 6 | 7 | -------------------------------------------------------------------------------- /test/pgtap-core.sql: -------------------------------------------------------------------------------- 1 | \set ECHO 0 2 | -- This file defines pgTAP Core, a portable collection of assertion 3 | -- functions for TAP-based unit testing on PostgreSQL 8.3 or higher. It is 4 | -- distributed under the revised FreeBSD license. The home page for the pgTAP 5 | -- project is: 6 | 7 | -- 8 | -- http://pgtap.org/ 9 | -- 10 | 11 | \pset format unaligned 12 | \pset tuples_only true 13 | \pset pager 14 | 15 | -- Revert all changes on failure. 16 | \set ON_ERROR_ROLLBACK 1 17 | \set ON_ERROR_STOP true 18 | 19 | CREATE OR REPLACE FUNCTION pg_version() 20 | RETURNS text AS 'SELECT current_setting(''server_version'')' 21 | LANGUAGE SQL IMMUTABLE; 22 | 23 | CREATE OR REPLACE FUNCTION pg_version_num() 24 | RETURNS integer AS $$ 25 | SELECT s.a[1]::int * 10000 26 | + COALESCE(substring(s.a[2] FROM '[[:digit:]]+')::int, 0) * 100 27 | + COALESCE(substring(s.a[3] FROM '[[:digit:]]+')::int, 0) 28 | FROM ( 29 | SELECT string_to_array(current_setting('server_version'), '.') AS a 30 | ) AS s; 31 | $$ LANGUAGE SQL IMMUTABLE; 32 | 33 | CREATE OR REPLACE FUNCTION pgtap_version() 34 | RETURNS NUMERIC AS 'SELECT 0.25;' 35 | LANGUAGE SQL IMMUTABLE; 36 | 37 | CREATE OR REPLACE FUNCTION plan( integer ) 38 | RETURNS TEXT AS $$ 39 | DECLARE 40 | rcount INTEGER; 41 | BEGIN 42 | BEGIN 43 | EXECUTE ' 44 | CREATE TEMP SEQUENCE __tcache___id_seq; 45 | CREATE TEMP TABLE __tcache__ ( 46 | id INTEGER NOT NULL DEFAULT nextval(''__tcache___id_seq''), 47 | label TEXT NOT NULL, 48 | value INTEGER NOT NULL, 49 | note TEXT NOT NULL DEFAULT '''' 50 | ); 51 | CREATE UNIQUE INDEX __tcache___key ON __tcache__(id); 52 | GRANT ALL ON TABLE __tcache__ TO PUBLIC; 53 | GRANT ALL ON TABLE __tcache___id_seq TO PUBLIC; 54 | 55 | CREATE TEMP SEQUENCE __tresults___numb_seq; 56 | CREATE TEMP TABLE __tresults__ ( 57 | numb INTEGER NOT NULL DEFAULT nextval(''__tresults___numb_seq''), 58 | ok BOOLEAN NOT NULL DEFAULT TRUE, 59 | aok BOOLEAN NOT NULL DEFAULT TRUE, 60 | descr TEXT NOT NULL DEFAULT '''', 61 | type TEXT NOT NULL DEFAULT '''', 62 | reason TEXT NOT NULL DEFAULT '''' 63 | ); 64 | CREATE UNIQUE INDEX __tresults___key ON __tresults__(numb); 65 | GRANT ALL ON TABLE __tresults__ TO PUBLIC; 66 | GRANT ALL ON TABLE __tresults___numb_seq TO PUBLIC; 67 | '; 68 | 69 | EXCEPTION WHEN duplicate_table THEN 70 | -- Raise an exception if there's already a plan. 71 | EXECUTE 'SELECT TRUE FROM __tcache__ WHERE label = ''plan'''; 72 | GET DIAGNOSTICS rcount = ROW_COUNT; 73 | IF rcount > 0 THEN 74 | RAISE EXCEPTION 'You tried to plan twice!'; 75 | END IF; 76 | END; 77 | 78 | -- Save the plan and return. 79 | PERFORM _set('plan', $1 ); 80 | RETURN '1..' || $1; 81 | END; 82 | $$ LANGUAGE plpgsql strict; 83 | 84 | CREATE OR REPLACE FUNCTION no_plan() 85 | RETURNS SETOF boolean AS $$ 86 | BEGIN 87 | PERFORM plan(0); 88 | RETURN; 89 | END; 90 | $$ LANGUAGE plpgsql strict; 91 | 92 | CREATE OR REPLACE FUNCTION _get ( text ) 93 | RETURNS integer AS $$ 94 | DECLARE 95 | ret integer; 96 | BEGIN 97 | EXECUTE 'SELECT value FROM __tcache__ WHERE label = ' || quote_literal($1) || ' LIMIT 1' INTO ret; 98 | RETURN ret; 99 | END; 100 | $$ LANGUAGE plpgsql strict; 101 | 102 | CREATE OR REPLACE FUNCTION _get_latest ( text ) 103 | RETURNS integer[] AS $$ 104 | DECLARE 105 | ret integer[]; 106 | BEGIN 107 | EXECUTE 'SELECT ARRAY[ id, value] FROM __tcache__ WHERE label = ' || 108 | quote_literal($1) || ' AND id = (SELECT MAX(id) FROM __tcache__ WHERE label = ' || 109 | quote_literal($1) || ') LIMIT 1' INTO ret; 110 | RETURN ret; 111 | END; 112 | $$ LANGUAGE plpgsql strict; 113 | 114 | CREATE OR REPLACE FUNCTION _get_latest ( text, integer ) 115 | RETURNS integer AS $$ 116 | DECLARE 117 | ret integer; 118 | BEGIN 119 | EXECUTE 'SELECT MAX(id) FROM __tcache__ WHERE label = ' || 120 | quote_literal($1) || ' AND value = ' || $2 INTO ret; 121 | RETURN ret; 122 | END; 123 | $$ LANGUAGE plpgsql strict; 124 | 125 | CREATE OR REPLACE FUNCTION _get_note ( text ) 126 | RETURNS text AS $$ 127 | DECLARE 128 | ret text; 129 | BEGIN 130 | EXECUTE 'SELECT note FROM __tcache__ WHERE label = ' || quote_literal($1) || ' LIMIT 1' INTO ret; 131 | RETURN ret; 132 | END; 133 | $$ LANGUAGE plpgsql strict; 134 | 135 | CREATE OR REPLACE FUNCTION _get_note ( integer ) 136 | RETURNS text AS $$ 137 | DECLARE 138 | ret text; 139 | BEGIN 140 | EXECUTE 'SELECT note FROM __tcache__ WHERE id = ' || $1 || ' LIMIT 1' INTO ret; 141 | RETURN ret; 142 | END; 143 | $$ LANGUAGE plpgsql strict; 144 | 145 | CREATE OR REPLACE FUNCTION _set ( text, integer, text ) 146 | RETURNS integer AS $$ 147 | DECLARE 148 | rcount integer; 149 | BEGIN 150 | EXECUTE 'UPDATE __tcache__ SET value = ' || $2 151 | || CASE WHEN $3 IS NULL THEN '' ELSE ', note = ' || quote_literal($3) END 152 | || ' WHERE label = ' || quote_literal($1); 153 | GET DIAGNOSTICS rcount = ROW_COUNT; 154 | IF rcount = 0 THEN 155 | RETURN _add( $1, $2, $3 ); 156 | END IF; 157 | RETURN $2; 158 | END; 159 | $$ LANGUAGE plpgsql; 160 | 161 | CREATE OR REPLACE FUNCTION _set ( text, integer ) 162 | RETURNS integer AS $$ 163 | SELECT _set($1, $2, '') 164 | $$ LANGUAGE SQL; 165 | 166 | CREATE OR REPLACE FUNCTION _set ( integer, integer ) 167 | RETURNS integer AS $$ 168 | BEGIN 169 | EXECUTE 'UPDATE __tcache__ SET value = ' || $2 170 | || ' WHERE id = ' || $1; 171 | RETURN $2; 172 | END; 173 | $$ LANGUAGE plpgsql; 174 | 175 | CREATE OR REPLACE FUNCTION _add ( text, integer, text ) 176 | RETURNS integer AS $$ 177 | BEGIN 178 | EXECUTE 'INSERT INTO __tcache__ (label, value, note) values (' || 179 | quote_literal($1) || ', ' || $2 || ', ' || quote_literal(COALESCE($3, '')) || ')'; 180 | RETURN $2; 181 | END; 182 | $$ LANGUAGE plpgsql; 183 | 184 | CREATE OR REPLACE FUNCTION _add ( text, integer ) 185 | RETURNS integer AS $$ 186 | SELECT _add($1, $2, '') 187 | $$ LANGUAGE SQL; 188 | 189 | CREATE OR REPLACE FUNCTION add_result ( bool, bool, text, text, text ) 190 | RETURNS integer AS $$ 191 | BEGIN 192 | EXECUTE 'INSERT INTO __tresults__ ( ok, aok, descr, type, reason ) 193 | VALUES( ' || $1 || ', ' 194 | || $2 || ', ' 195 | || quote_literal(COALESCE($3, '')) || ', ' 196 | || quote_literal($4) || ', ' 197 | || quote_literal($5) || ' )'; 198 | RETURN currval('__tresults___numb_seq'); 199 | END; 200 | $$ LANGUAGE plpgsql; 201 | 202 | CREATE OR REPLACE FUNCTION num_failed () 203 | RETURNS INTEGER AS $$ 204 | DECLARE 205 | ret integer; 206 | BEGIN 207 | EXECUTE 'SELECT COUNT(*)::INTEGER FROM __tresults__ WHERE ok = FALSE' INTO ret; 208 | RETURN ret; 209 | END; 210 | $$ LANGUAGE plpgsql strict; 211 | 212 | CREATE OR REPLACE FUNCTION _finish ( INTEGER, INTEGER, INTEGER) 213 | RETURNS SETOF TEXT AS $$ 214 | DECLARE 215 | curr_test ALIAS FOR $1; 216 | exp_tests INTEGER := $2; 217 | num_faild ALIAS FOR $3; 218 | plural CHAR; 219 | BEGIN 220 | plural := CASE exp_tests WHEN 1 THEN '' ELSE 's' END; 221 | 222 | IF curr_test IS NULL THEN 223 | RAISE EXCEPTION '# No tests run!'; 224 | END IF; 225 | 226 | IF exp_tests = 0 OR exp_tests IS NULL THEN 227 | -- No plan. Output one now. 228 | exp_tests = curr_test; 229 | RETURN NEXT '1..' || exp_tests; 230 | END IF; 231 | 232 | IF curr_test <> exp_tests THEN 233 | RETURN NEXT diag( 234 | 'Looks like you planned ' || exp_tests || ' test' || 235 | plural || ' but ran ' || curr_test 236 | ); 237 | ELSIF num_faild > 0 THEN 238 | RETURN NEXT diag( 239 | 'Looks like you failed ' || num_faild || ' test' || 240 | CASE num_faild WHEN 1 THEN '' ELSE 's' END 241 | || ' of ' || exp_tests 242 | ); 243 | ELSE 244 | 245 | END IF; 246 | RETURN; 247 | END; 248 | $$ LANGUAGE plpgsql; 249 | 250 | CREATE OR REPLACE FUNCTION finish () 251 | RETURNS SETOF TEXT AS $$ 252 | SELECT * FROM _finish( 253 | _get('curr_test'), 254 | _get('plan'), 255 | num_failed() 256 | ); 257 | $$ LANGUAGE sql; 258 | 259 | CREATE OR REPLACE FUNCTION diag ( msg text ) 260 | RETURNS TEXT AS $$ 261 | SELECT '# ' || replace( 262 | replace( 263 | replace( $1, E'\r\n', E'\n# ' ), 264 | E'\n', 265 | E'\n# ' 266 | ), 267 | E'\r', 268 | E'\n# ' 269 | ); 270 | $$ LANGUAGE sql strict; 271 | 272 | CREATE OR REPLACE FUNCTION diag ( msg anyelement ) 273 | RETURNS TEXT AS $$ 274 | SELECT diag($1::text); 275 | $$ LANGUAGE sql; 276 | 277 | CREATE OR REPLACE FUNCTION diag( VARIADIC text[] ) 278 | RETURNS TEXT AS $$ 279 | SELECT diag(array_to_string($1, '')); 280 | $$ LANGUAGE sql; 281 | 282 | CREATE OR REPLACE FUNCTION diag( VARIADIC anyarray ) 283 | RETURNS TEXT AS $$ 284 | SELECT diag(array_to_string($1, '')); 285 | $$ LANGUAGE sql; 286 | 287 | CREATE OR REPLACE FUNCTION ok ( boolean, text ) 288 | RETURNS TEXT AS $$ 289 | DECLARE 290 | aok ALIAS FOR $1; 291 | descr text := $2; 292 | test_num INTEGER; 293 | todo_why TEXT; 294 | ok BOOL; 295 | BEGIN 296 | todo_why := _todo(); 297 | ok := CASE 298 | WHEN aok = TRUE THEN aok 299 | WHEN todo_why IS NULL THEN COALESCE(aok, false) 300 | ELSE TRUE 301 | END; 302 | IF _get('plan') IS NULL THEN 303 | RAISE EXCEPTION 'You tried to run a test without a plan! Gotta have a plan'; 304 | END IF; 305 | 306 | test_num := add_result( 307 | ok, 308 | COALESCE(aok, false), 309 | descr, 310 | CASE WHEN todo_why IS NULL THEN '' ELSE 'todo' END, 311 | COALESCE(todo_why, '') 312 | ); 313 | 314 | RETURN (CASE aok WHEN TRUE THEN '' ELSE 'not ' END) 315 | || 'ok ' || _set( 'curr_test', test_num ) 316 | || CASE descr WHEN '' THEN '' ELSE COALESCE( ' - ' || substr(diag( descr ), 3), '' ) END 317 | || COALESCE( ' ' || diag( 'TODO ' || todo_why ), '') 318 | || CASE aok WHEN TRUE THEN '' ELSE E'\n' || 319 | diag('Failed ' || 320 | CASE WHEN todo_why IS NULL THEN '' ELSE '(TODO) ' END || 321 | 'test ' || test_num || 322 | CASE descr WHEN '' THEN '' ELSE COALESCE(': "' || descr || '"', '') END ) || 323 | CASE WHEN aok IS NULL THEN E'\n' || diag(' (test result was NULL)') ELSE '' END 324 | END; 325 | END; 326 | $$ LANGUAGE plpgsql; 327 | 328 | CREATE OR REPLACE FUNCTION ok ( boolean ) 329 | RETURNS TEXT AS $$ 330 | SELECT ok( $1, NULL ); 331 | $$ LANGUAGE SQL; 332 | 333 | CREATE OR REPLACE FUNCTION is (anyelement, anyelement, text) 334 | RETURNS TEXT AS $$ 335 | DECLARE 336 | result BOOLEAN; 337 | output TEXT; 338 | BEGIN 339 | -- Would prefer $1 IS NOT DISTINCT FROM, but that's not supported by 8.1. 340 | result := NOT $1 IS DISTINCT FROM $2; 341 | output := ok( result, $3 ); 342 | RETURN output || CASE result WHEN TRUE THEN '' ELSE E'\n' || diag( 343 | ' have: ' || CASE WHEN $1 IS NULL THEN 'NULL' ELSE $1::text END || 344 | E'\n want: ' || CASE WHEN $2 IS NULL THEN 'NULL' ELSE $2::text END 345 | ) END; 346 | END; 347 | $$ LANGUAGE plpgsql; 348 | 349 | CREATE OR REPLACE FUNCTION is (anyelement, anyelement) 350 | RETURNS TEXT AS $$ 351 | SELECT is( $1, $2, NULL); 352 | $$ LANGUAGE SQL; 353 | 354 | CREATE OR REPLACE FUNCTION isnt (anyelement, anyelement, text) 355 | RETURNS TEXT AS $$ 356 | DECLARE 357 | result BOOLEAN; 358 | output TEXT; 359 | BEGIN 360 | result := $1 IS DISTINCT FROM $2; 361 | output := ok( result, $3 ); 362 | RETURN output || CASE result WHEN TRUE THEN '' ELSE E'\n' || diag( 363 | ' have: ' || COALESCE( $1::text, 'NULL' ) || 364 | E'\n want: anything else' 365 | ) END; 366 | END; 367 | $$ LANGUAGE plpgsql; 368 | 369 | CREATE OR REPLACE FUNCTION isnt (anyelement, anyelement) 370 | RETURNS TEXT AS $$ 371 | SELECT isnt( $1, $2, NULL); 372 | $$ LANGUAGE SQL; 373 | 374 | CREATE OR REPLACE FUNCTION _alike ( BOOLEAN, ANYELEMENT, TEXT, TEXT ) 375 | RETURNS TEXT AS $$ 376 | DECLARE 377 | result ALIAS FOR $1; 378 | got ALIAS FOR $2; 379 | rx ALIAS FOR $3; 380 | descr ALIAS FOR $4; 381 | output TEXT; 382 | BEGIN 383 | output := ok( result, descr ); 384 | RETURN output || CASE result WHEN TRUE THEN '' ELSE E'\n' || diag( 385 | ' ' || COALESCE( quote_literal(got), 'NULL' ) || 386 | E'\n doesn''t match: ' || COALESCE( quote_literal(rx), 'NULL' ) 387 | ) END; 388 | END; 389 | $$ LANGUAGE plpgsql; 390 | 391 | CREATE OR REPLACE FUNCTION matches ( anyelement, text, text ) 392 | RETURNS TEXT AS $$ 393 | SELECT _alike( $1 ~ $2, $1, $2, $3 ); 394 | $$ LANGUAGE SQL; 395 | 396 | CREATE OR REPLACE FUNCTION matches ( anyelement, text ) 397 | RETURNS TEXT AS $$ 398 | SELECT _alike( $1 ~ $2, $1, $2, NULL ); 399 | $$ LANGUAGE SQL; 400 | 401 | CREATE OR REPLACE FUNCTION imatches ( anyelement, text, text ) 402 | RETURNS TEXT AS $$ 403 | SELECT _alike( $1 ~* $2, $1, $2, $3 ); 404 | $$ LANGUAGE SQL; 405 | 406 | CREATE OR REPLACE FUNCTION imatches ( anyelement, text ) 407 | RETURNS TEXT AS $$ 408 | SELECT _alike( $1 ~* $2, $1, $2, NULL ); 409 | $$ LANGUAGE SQL; 410 | 411 | CREATE OR REPLACE FUNCTION alike ( anyelement, text, text ) 412 | RETURNS TEXT AS $$ 413 | SELECT _alike( $1 ~~ $2, $1, $2, $3 ); 414 | $$ LANGUAGE SQL; 415 | 416 | CREATE OR REPLACE FUNCTION alike ( anyelement, text ) 417 | RETURNS TEXT AS $$ 418 | SELECT _alike( $1 ~~ $2, $1, $2, NULL ); 419 | $$ LANGUAGE SQL; 420 | 421 | CREATE OR REPLACE FUNCTION ialike ( anyelement, text, text ) 422 | RETURNS TEXT AS $$ 423 | SELECT _alike( $1 ~~* $2, $1, $2, $3 ); 424 | $$ LANGUAGE SQL; 425 | 426 | CREATE OR REPLACE FUNCTION ialike ( anyelement, text ) 427 | RETURNS TEXT AS $$ 428 | SELECT _alike( $1 ~~* $2, $1, $2, NULL ); 429 | $$ LANGUAGE SQL; 430 | 431 | CREATE OR REPLACE FUNCTION _unalike ( BOOLEAN, ANYELEMENT, TEXT, TEXT ) 432 | RETURNS TEXT AS $$ 433 | DECLARE 434 | result ALIAS FOR $1; 435 | got ALIAS FOR $2; 436 | rx ALIAS FOR $3; 437 | descr ALIAS FOR $4; 438 | output TEXT; 439 | BEGIN 440 | output := ok( result, descr ); 441 | RETURN output || CASE result WHEN TRUE THEN '' ELSE E'\n' || diag( 442 | ' ' || COALESCE( quote_literal(got), 'NULL' ) || 443 | E'\n matches: ' || COALESCE( quote_literal(rx), 'NULL' ) 444 | ) END; 445 | END; 446 | $$ LANGUAGE plpgsql; 447 | 448 | CREATE OR REPLACE FUNCTION doesnt_match ( anyelement, text, text ) 449 | RETURNS TEXT AS $$ 450 | SELECT _unalike( $1 !~ $2, $1, $2, $3 ); 451 | $$ LANGUAGE SQL; 452 | 453 | CREATE OR REPLACE FUNCTION doesnt_match ( anyelement, text ) 454 | RETURNS TEXT AS $$ 455 | SELECT _unalike( $1 !~ $2, $1, $2, NULL ); 456 | $$ LANGUAGE SQL; 457 | 458 | CREATE OR REPLACE FUNCTION doesnt_imatch ( anyelement, text, text ) 459 | RETURNS TEXT AS $$ 460 | SELECT _unalike( $1 !~* $2, $1, $2, $3 ); 461 | $$ LANGUAGE SQL; 462 | 463 | CREATE OR REPLACE FUNCTION doesnt_imatch ( anyelement, text ) 464 | RETURNS TEXT AS $$ 465 | SELECT _unalike( $1 !~* $2, $1, $2, NULL ); 466 | $$ LANGUAGE SQL; 467 | 468 | CREATE OR REPLACE FUNCTION unalike ( anyelement, text, text ) 469 | RETURNS TEXT AS $$ 470 | SELECT _unalike( $1 !~~ $2, $1, $2, $3 ); 471 | $$ LANGUAGE SQL; 472 | 473 | CREATE OR REPLACE FUNCTION unalike ( anyelement, text ) 474 | RETURNS TEXT AS $$ 475 | SELECT _unalike( $1 !~~ $2, $1, $2, NULL ); 476 | $$ LANGUAGE SQL; 477 | 478 | CREATE OR REPLACE FUNCTION unialike ( anyelement, text, text ) 479 | RETURNS TEXT AS $$ 480 | SELECT _unalike( $1 !~~* $2, $1, $2, $3 ); 481 | $$ LANGUAGE SQL; 482 | 483 | CREATE OR REPLACE FUNCTION unialike ( anyelement, text ) 484 | RETURNS TEXT AS $$ 485 | SELECT _unalike( $1 !~~* $2, $1, $2, NULL ); 486 | $$ LANGUAGE SQL; 487 | 488 | CREATE OR REPLACE FUNCTION cmp_ok (anyelement, text, anyelement, text) 489 | RETURNS TEXT AS $$ 490 | DECLARE 491 | have ALIAS FOR $1; 492 | op ALIAS FOR $2; 493 | want ALIAS FOR $3; 494 | descr ALIAS FOR $4; 495 | result BOOLEAN; 496 | output TEXT; 497 | BEGIN 498 | EXECUTE 'SELECT ' || 499 | COALESCE(quote_literal( have ), 'NULL') || '::' || pg_typeof(have) || ' ' 500 | || op || ' ' || 501 | COALESCE(quote_literal( want ), 'NULL') || '::' || pg_typeof(want) 502 | INTO result; 503 | output := ok( COALESCE(result, FALSE), descr ); 504 | RETURN output || CASE result WHEN TRUE THEN '' ELSE E'\n' || diag( 505 | ' ' || COALESCE( quote_literal(have), 'NULL' ) || 506 | E'\n ' || op || 507 | E'\n ' || COALESCE( quote_literal(want), 'NULL' ) 508 | ) END; 509 | END; 510 | $$ LANGUAGE plpgsql; 511 | 512 | CREATE OR REPLACE FUNCTION cmp_ok (anyelement, text, anyelement) 513 | RETURNS TEXT AS $$ 514 | SELECT cmp_ok( $1, $2, $3, NULL ); 515 | $$ LANGUAGE sql; 516 | 517 | CREATE OR REPLACE FUNCTION pass ( text ) 518 | RETURNS TEXT AS $$ 519 | SELECT ok( TRUE, $1 ); 520 | $$ LANGUAGE SQL; 521 | 522 | CREATE OR REPLACE FUNCTION pass () 523 | RETURNS TEXT AS $$ 524 | SELECT ok( TRUE, NULL ); 525 | $$ LANGUAGE SQL; 526 | 527 | CREATE OR REPLACE FUNCTION fail ( text ) 528 | RETURNS TEXT AS $$ 529 | SELECT ok( FALSE, $1 ); 530 | $$ LANGUAGE SQL; 531 | 532 | CREATE OR REPLACE FUNCTION fail () 533 | RETURNS TEXT AS $$ 534 | SELECT ok( FALSE, NULL ); 535 | $$ LANGUAGE SQL; 536 | 537 | CREATE OR REPLACE FUNCTION todo ( why text, how_many int ) 538 | RETURNS SETOF BOOLEAN AS $$ 539 | BEGIN 540 | PERFORM _add('todo', COALESCE(how_many, 1), COALESCE(why, '')); 541 | RETURN; 542 | END; 543 | $$ LANGUAGE plpgsql; 544 | 545 | CREATE OR REPLACE FUNCTION todo ( how_many int, why text ) 546 | RETURNS SETOF BOOLEAN AS $$ 547 | BEGIN 548 | PERFORM _add('todo', COALESCE(how_many, 1), COALESCE(why, '')); 549 | RETURN; 550 | END; 551 | $$ LANGUAGE plpgsql; 552 | 553 | CREATE OR REPLACE FUNCTION todo ( why text ) 554 | RETURNS SETOF BOOLEAN AS $$ 555 | BEGIN 556 | PERFORM _add('todo', 1, COALESCE(why, '')); 557 | RETURN; 558 | END; 559 | $$ LANGUAGE plpgsql; 560 | 561 | CREATE OR REPLACE FUNCTION todo ( how_many int ) 562 | RETURNS SETOF BOOLEAN AS $$ 563 | BEGIN 564 | PERFORM _add('todo', COALESCE(how_many, 1), ''); 565 | RETURN; 566 | END; 567 | $$ LANGUAGE plpgsql; 568 | 569 | CREATE OR REPLACE FUNCTION todo_start (text) 570 | RETURNS SETOF BOOLEAN AS $$ 571 | BEGIN 572 | PERFORM _add('todo', -1, COALESCE($1, '')); 573 | RETURN; 574 | END; 575 | $$ LANGUAGE plpgsql; 576 | 577 | CREATE OR REPLACE FUNCTION todo_start () 578 | RETURNS SETOF BOOLEAN AS $$ 579 | BEGIN 580 | PERFORM _add('todo', -1, ''); 581 | RETURN; 582 | END; 583 | $$ LANGUAGE plpgsql; 584 | 585 | CREATE OR REPLACE FUNCTION in_todo () 586 | RETURNS BOOLEAN AS $$ 587 | DECLARE 588 | todos integer; 589 | BEGIN 590 | todos := _get('todo'); 591 | RETURN CASE WHEN todos IS NULL THEN FALSE ELSE TRUE END; 592 | END; 593 | $$ LANGUAGE plpgsql; 594 | 595 | CREATE OR REPLACE FUNCTION todo_end () 596 | RETURNS SETOF BOOLEAN AS $$ 597 | DECLARE 598 | id integer; 599 | BEGIN 600 | id := _get_latest( 'todo', -1 ); 601 | IF id IS NULL THEN 602 | RAISE EXCEPTION 'todo_end() called without todo_start()'; 603 | END IF; 604 | EXECUTE 'DELETE FROM __tcache__ WHERE id = ' || id; 605 | RETURN; 606 | END; 607 | $$ LANGUAGE plpgsql; 608 | 609 | CREATE OR REPLACE FUNCTION _todo() 610 | RETURNS TEXT AS $$ 611 | DECLARE 612 | todos INT[]; 613 | note text; 614 | BEGIN 615 | -- Get the latest id and value, because todo() might have been called 616 | -- again before the todos ran out for the first call to todo(). This 617 | -- allows them to nest. 618 | todos := _get_latest('todo'); 619 | IF todos IS NULL THEN 620 | -- No todos. 621 | RETURN NULL; 622 | END IF; 623 | IF todos[2] = 0 THEN 624 | -- Todos depleted. Clean up. 625 | EXECUTE 'DELETE FROM __tcache__ WHERE id = ' || todos[1]; 626 | RETURN NULL; 627 | END IF; 628 | -- Decrement the count of counted todos and return the reason. 629 | IF todos[2] <> -1 THEN 630 | PERFORM _set(todos[1], todos[2] - 1); 631 | END IF; 632 | note := _get_note(todos[1]); 633 | 634 | IF todos[2] = 1 THEN 635 | -- This was the last todo, so delete the record. 636 | EXECUTE 'DELETE FROM __tcache__ WHERE id = ' || todos[1]; 637 | END IF; 638 | 639 | RETURN note; 640 | END; 641 | $$ LANGUAGE plpgsql; 642 | 643 | CREATE OR REPLACE FUNCTION skip ( why text, how_many int ) 644 | RETURNS TEXT AS $$ 645 | DECLARE 646 | output TEXT[]; 647 | BEGIN 648 | output := '{}'; 649 | FOR i IN 1..how_many LOOP 650 | output = array_append(output, ok( TRUE, 'SKIP: ' || COALESCE( why, '') ) ); 651 | END LOOP; 652 | RETURN array_to_string(output, E'\n'); 653 | END; 654 | $$ LANGUAGE plpgsql; 655 | 656 | CREATE OR REPLACE FUNCTION skip ( text ) 657 | RETURNS TEXT AS $$ 658 | SELECT ok( TRUE, 'SKIP: ' || $1 ); 659 | $$ LANGUAGE sql; 660 | 661 | CREATE OR REPLACE FUNCTION skip( int, text ) 662 | RETURNS TEXT AS 'SELECT skip($2, $1)' 663 | LANGUAGE sql; 664 | 665 | CREATE OR REPLACE FUNCTION skip( int ) 666 | RETURNS TEXT AS 'SELECT skip(NULL, $1)' 667 | LANGUAGE sql; 668 | 669 | CREATE OR REPLACE FUNCTION _query( TEXT ) 670 | RETURNS TEXT AS $$ 671 | SELECT CASE 672 | WHEN $1 LIKE '"%' OR $1 !~ '[[:space:]]' THEN 'EXECUTE ' || $1 673 | ELSE $1 674 | END; 675 | $$ LANGUAGE SQL; 676 | 677 | -- throws_ok ( sql, errcode, errmsg, description ) 678 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT, CHAR(5), TEXT, TEXT ) 679 | RETURNS TEXT AS $$ 680 | DECLARE 681 | query TEXT := _query($1); 682 | errcode ALIAS FOR $2; 683 | errmsg ALIAS FOR $3; 684 | desctext ALIAS FOR $4; 685 | descr TEXT; 686 | BEGIN 687 | descr := COALESCE( 688 | desctext, 689 | 'threw ' || errcode || ': ' || errmsg, 690 | 'threw ' || errcode, 691 | 'threw ' || errmsg, 692 | 'threw an exception' 693 | ); 694 | EXECUTE query; 695 | RETURN ok( FALSE, descr ) || E'\n' || diag( 696 | ' caught: no exception' || 697 | E'\n wanted: ' || COALESCE( errcode, 'an exception' ) 698 | ); 699 | EXCEPTION WHEN OTHERS THEN 700 | IF (errcode IS NULL OR SQLSTATE = errcode) 701 | AND ( errmsg IS NULL OR SQLERRM = errmsg) 702 | THEN 703 | -- The expected errcode and/or message was thrown. 704 | RETURN ok( TRUE, descr ); 705 | ELSE 706 | -- This was not the expected errcode or errmsg. 707 | RETURN ok( FALSE, descr ) || E'\n' || diag( 708 | ' caught: ' || SQLSTATE || ': ' || SQLERRM || 709 | E'\n wanted: ' || COALESCE( errcode, 'an exception' ) || 710 | COALESCE( ': ' || errmsg, '') 711 | ); 712 | END IF; 713 | END; 714 | $$ LANGUAGE plpgsql; 715 | 716 | -- throws_ok ( sql, errcode, errmsg ) 717 | -- throws_ok ( sql, errmsg, description ) 718 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT, TEXT, TEXT ) 719 | RETURNS TEXT AS $$ 720 | BEGIN 721 | IF octet_length($2) = 5 THEN 722 | RETURN throws_ok( $1, $2::char(5), $3, NULL ); 723 | ELSE 724 | RETURN throws_ok( $1, NULL, $2, $3 ); 725 | END IF; 726 | END; 727 | $$ LANGUAGE plpgsql; 728 | 729 | -- throws_ok ( query, errcode ) 730 | -- throws_ok ( query, errmsg ) 731 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT, TEXT ) 732 | RETURNS TEXT AS $$ 733 | BEGIN 734 | IF octet_length($2) = 5 THEN 735 | RETURN throws_ok( $1, $2::char(5), NULL, NULL ); 736 | ELSE 737 | RETURN throws_ok( $1, NULL, $2, NULL ); 738 | END IF; 739 | END; 740 | $$ LANGUAGE plpgsql; 741 | 742 | -- throws_ok ( sql ) 743 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT ) 744 | RETURNS TEXT AS $$ 745 | SELECT throws_ok( $1, NULL, NULL, NULL ); 746 | $$ LANGUAGE SQL; 747 | 748 | -- Magically cast integer error codes. 749 | -- throws_ok ( sql, errcode, errmsg, description ) 750 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT, int4, TEXT, TEXT ) 751 | RETURNS TEXT AS $$ 752 | SELECT throws_ok( $1, $2::char(5), $3, $4 ); 753 | $$ LANGUAGE SQL; 754 | 755 | -- throws_ok ( sql, errcode, errmsg ) 756 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT, int4, TEXT ) 757 | RETURNS TEXT AS $$ 758 | SELECT throws_ok( $1, $2::char(5), $3, NULL ); 759 | $$ LANGUAGE SQL; 760 | 761 | -- throws_ok ( sql, errcode ) 762 | CREATE OR REPLACE FUNCTION throws_ok ( TEXT, int4 ) 763 | RETURNS TEXT AS $$ 764 | SELECT throws_ok( $1, $2::char(5), NULL, NULL ); 765 | $$ LANGUAGE SQL; 766 | 767 | -- lives_ok( sql, description ) 768 | CREATE OR REPLACE FUNCTION lives_ok ( TEXT, TEXT ) 769 | RETURNS TEXT AS $$ 770 | DECLARE 771 | code TEXT := _query($1); 772 | descr ALIAS FOR $2; 773 | BEGIN 774 | EXECUTE code; 775 | RETURN ok( TRUE, descr ); 776 | EXCEPTION WHEN OTHERS THEN 777 | -- There should have been no exception. 778 | RETURN ok( FALSE, descr ) || E'\n' || diag( 779 | ' died: ' || SQLSTATE || ': ' || SQLERRM 780 | ); 781 | END; 782 | $$ LANGUAGE plpgsql; 783 | 784 | -- lives_ok( sql ) 785 | CREATE OR REPLACE FUNCTION lives_ok ( TEXT ) 786 | RETURNS TEXT AS $$ 787 | SELECT lives_ok( $1, NULL ); 788 | $$ LANGUAGE SQL; 789 | 790 | -- performs_ok ( sql, milliseconds, description ) 791 | CREATE OR REPLACE FUNCTION performs_ok ( TEXT, NUMERIC, TEXT ) 792 | RETURNS TEXT AS $$ 793 | DECLARE 794 | query TEXT := _query($1); 795 | max_time ALIAS FOR $2; 796 | descr ALIAS FOR $3; 797 | starts_at TEXT; 798 | act_time NUMERIC; 799 | BEGIN 800 | starts_at := timeofday(); 801 | EXECUTE query; 802 | act_time := extract( millisecond from timeofday()::timestamptz - starts_at::timestamptz); 803 | IF act_time < max_time THEN RETURN ok(TRUE, descr); END IF; 804 | RETURN ok( FALSE, descr ) || E'\n' || diag( 805 | ' runtime: ' || act_time || ' ms' || 806 | E'\n exceeds: ' || max_time || ' ms' 807 | ); 808 | END; 809 | $$ LANGUAGE plpgsql; 810 | 811 | -- performs_ok ( sql, milliseconds ) 812 | CREATE OR REPLACE FUNCTION performs_ok ( TEXT, NUMERIC ) 813 | RETURNS TEXT AS $$ 814 | SELECT performs_ok( 815 | $1, $2, 'Should run in less than ' || $2 || ' ms' 816 | ); 817 | $$ LANGUAGE sql; 818 | 819 | CREATE OR REPLACE FUNCTION display_type ( OID, INTEGER ) 820 | RETURNS TEXT AS $$ 821 | SELECT COALESCE(substring( 822 | pg_catalog.format_type($1, $2), 823 | '(("(?!")([^"]|"")+"|[^.]+)([(][^)]+[)])?)$' 824 | ), '') 825 | $$ LANGUAGE SQL; 826 | 827 | CREATE OR REPLACE FUNCTION display_type ( NAME, OID, INTEGER ) 828 | RETURNS TEXT AS $$ 829 | SELECT CASE WHEN $1 IS NULL THEN '' ELSE quote_ident($1) || '.' END 830 | || display_type($2, $3) 831 | $$ LANGUAGE SQL; 832 | 833 | CREATE OR REPLACE FUNCTION _ident_array_to_string( name[], text ) 834 | RETURNS text AS $$ 835 | SELECT array_to_string(ARRAY( 836 | SELECT quote_ident($1[i]) 837 | FROM generate_series(1, array_upper($1, 1)) s(i) 838 | ORDER BY i 839 | ), $2); 840 | $$ LANGUAGE SQL immutable; 841 | 842 | -- Borrowed from newsysviews: http://pgfoundry.org/projects/newsysviews/ 843 | CREATE OR REPLACE VIEW tap_funky 844 | AS SELECT p.oid AS oid, 845 | n.nspname AS schema, 846 | p.proname AS name, 847 | array_to_string(p.proargtypes::regtype[], ',') AS args, 848 | CASE p.proretset WHEN TRUE THEN 'setof ' ELSE '' END 849 | || p.prorettype::regtype AS returns, 850 | p.prolang AS langoid, 851 | p.proisstrict AS is_strict, 852 | p.proisagg AS is_agg, 853 | p.prosecdef AS is_definer, 854 | p.proretset AS returns_set, 855 | p.provolatile::char AS volatility, 856 | pg_catalog.pg_function_is_visible(p.oid) AS is_visible 857 | FROM pg_catalog.pg_proc p 858 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 859 | ; 860 | 861 | CREATE OR REPLACE FUNCTION _got_func ( NAME, NAME, NAME[] ) 862 | RETURNS BOOLEAN AS $$ 863 | SELECT EXISTS( 864 | SELECT TRUE 865 | FROM tap_funky 866 | WHERE schema = $1 867 | AND name = $2 868 | AND args = array_to_string($3, ',') 869 | ); 870 | $$ LANGUAGE SQL; 871 | 872 | CREATE OR REPLACE FUNCTION _got_func ( NAME, NAME ) 873 | RETURNS BOOLEAN AS $$ 874 | SELECT EXISTS( SELECT TRUE FROM tap_funky WHERE schema = $1 AND name = $2 ); 875 | $$ LANGUAGE SQL; 876 | 877 | CREATE OR REPLACE FUNCTION _got_func ( NAME, NAME[] ) 878 | RETURNS BOOLEAN AS $$ 879 | SELECT EXISTS( 880 | SELECT TRUE 881 | FROM tap_funky 882 | WHERE name = $1 883 | AND args = array_to_string($2, ',') 884 | AND is_visible 885 | ); 886 | $$ LANGUAGE SQL; 887 | 888 | CREATE OR REPLACE FUNCTION _got_func ( NAME ) 889 | RETURNS BOOLEAN AS $$ 890 | SELECT EXISTS( SELECT TRUE FROM tap_funky WHERE name = $1 AND is_visible); 891 | $$ LANGUAGE SQL; 892 | 893 | -- has_function( schema, function, args[], description ) 894 | CREATE OR REPLACE FUNCTION has_function ( NAME, NAME, NAME[], TEXT ) 895 | RETURNS TEXT AS $$ 896 | SELECT ok( _got_func($1, $2, $3), $4 ); 897 | $$ LANGUAGE SQL; 898 | 899 | -- has_function( schema, function, args[] ) 900 | CREATE OR REPLACE FUNCTION has_function( NAME, NAME, NAME[] ) 901 | RETURNS TEXT AS $$ 902 | SELECT ok( 903 | _got_func($1, $2, $3), 904 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 905 | array_to_string($3, ', ') || ') should exist' 906 | ); 907 | $$ LANGUAGE sql; 908 | 909 | -- has_function( schema, function, description ) 910 | CREATE OR REPLACE FUNCTION has_function ( NAME, NAME, TEXT ) 911 | RETURNS TEXT AS $$ 912 | SELECT ok( _got_func($1, $2), $3 ); 913 | $$ LANGUAGE SQL; 914 | 915 | -- has_function( schema, function ) 916 | CREATE OR REPLACE FUNCTION has_function( NAME, NAME ) 917 | RETURNS TEXT AS $$ 918 | SELECT ok( 919 | _got_func($1, $2), 920 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '() should exist' 921 | ); 922 | $$ LANGUAGE sql; 923 | 924 | -- has_function( function, args[], description ) 925 | CREATE OR REPLACE FUNCTION has_function ( NAME, NAME[], TEXT ) 926 | RETURNS TEXT AS $$ 927 | SELECT ok( _got_func($1, $2), $3 ); 928 | $$ LANGUAGE SQL; 929 | 930 | -- has_function( function, args[] ) 931 | CREATE OR REPLACE FUNCTION has_function( NAME, NAME[] ) 932 | RETURNS TEXT AS $$ 933 | SELECT ok( 934 | _got_func($1, $2), 935 | 'Function ' || quote_ident($1) || '(' || 936 | array_to_string($2, ', ') || ') should exist' 937 | ); 938 | $$ LANGUAGE sql; 939 | 940 | -- has_function( function, description ) 941 | CREATE OR REPLACE FUNCTION has_function( NAME, TEXT ) 942 | RETURNS TEXT AS $$ 943 | SELECT ok( _got_func($1), $2 ); 944 | $$ LANGUAGE sql; 945 | 946 | -- has_function( function ) 947 | CREATE OR REPLACE FUNCTION has_function( NAME ) 948 | RETURNS TEXT AS $$ 949 | SELECT ok( _got_func($1), 'Function ' || quote_ident($1) || '() should exist' ); 950 | $$ LANGUAGE sql; 951 | 952 | -- hasnt_function( schema, function, args[], description ) 953 | CREATE OR REPLACE FUNCTION hasnt_function ( NAME, NAME, NAME[], TEXT ) 954 | RETURNS TEXT AS $$ 955 | SELECT ok( NOT _got_func($1, $2, $3), $4 ); 956 | $$ LANGUAGE SQL; 957 | 958 | -- hasnt_function( schema, function, args[] ) 959 | CREATE OR REPLACE FUNCTION hasnt_function( NAME, NAME, NAME[] ) 960 | RETURNS TEXT AS $$ 961 | SELECT ok( 962 | NOT _got_func($1, $2, $3), 963 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 964 | array_to_string($3, ', ') || ') should not exist' 965 | ); 966 | $$ LANGUAGE sql; 967 | 968 | -- hasnt_function( schema, function, description ) 969 | CREATE OR REPLACE FUNCTION hasnt_function ( NAME, NAME, TEXT ) 970 | RETURNS TEXT AS $$ 971 | SELECT ok( NOT _got_func($1, $2), $3 ); 972 | $$ LANGUAGE SQL; 973 | 974 | -- hasnt_function( schema, function ) 975 | CREATE OR REPLACE FUNCTION hasnt_function( NAME, NAME ) 976 | RETURNS TEXT AS $$ 977 | SELECT ok( 978 | NOT _got_func($1, $2), 979 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '() should not exist' 980 | ); 981 | $$ LANGUAGE sql; 982 | 983 | -- hasnt_function( function, args[], description ) 984 | CREATE OR REPLACE FUNCTION hasnt_function ( NAME, NAME[], TEXT ) 985 | RETURNS TEXT AS $$ 986 | SELECT ok( NOT _got_func($1, $2), $3 ); 987 | $$ LANGUAGE SQL; 988 | 989 | -- hasnt_function( function, args[] ) 990 | CREATE OR REPLACE FUNCTION hasnt_function( NAME, NAME[] ) 991 | RETURNS TEXT AS $$ 992 | SELECT ok( 993 | NOT _got_func($1, $2), 994 | 'Function ' || quote_ident($1) || '(' || 995 | array_to_string($2, ', ') || ') should not exist' 996 | ); 997 | $$ LANGUAGE sql; 998 | 999 | -- hasnt_function( function, description ) 1000 | CREATE OR REPLACE FUNCTION hasnt_function( NAME, TEXT ) 1001 | RETURNS TEXT AS $$ 1002 | SELECT ok( NOT _got_func($1), $2 ); 1003 | $$ LANGUAGE sql; 1004 | 1005 | -- hasnt_function( function ) 1006 | CREATE OR REPLACE FUNCTION hasnt_function( NAME ) 1007 | RETURNS TEXT AS $$ 1008 | SELECT ok( NOT _got_func($1), 'Function ' || quote_ident($1) || '() should not exist' ); 1009 | $$ LANGUAGE sql; 1010 | 1011 | CREATE OR REPLACE FUNCTION _pg_sv_type_array( OID[] ) 1012 | RETURNS NAME[] AS $$ 1013 | SELECT ARRAY( 1014 | SELECT t.typname 1015 | FROM pg_catalog.pg_type t 1016 | JOIN generate_series(1, array_upper($1, 1)) s(i) ON t.oid = $1[i] 1017 | ORDER BY i 1018 | ) 1019 | $$ LANGUAGE SQL stable; 1020 | 1021 | -- can( schema, functions[], description ) 1022 | CREATE OR REPLACE FUNCTION can ( NAME, NAME[], TEXT ) 1023 | RETURNS TEXT AS $$ 1024 | DECLARE 1025 | missing text[]; 1026 | BEGIN 1027 | SELECT ARRAY( 1028 | SELECT quote_ident($2[i]) 1029 | FROM generate_series(1, array_upper($2, 1)) s(i) 1030 | LEFT JOIN tap_funky ON name = $2[i] AND schema = $1 1031 | WHERE oid IS NULL 1032 | GROUP BY $2[i], s.i 1033 | ORDER BY MIN(s.i) 1034 | ) INTO missing; 1035 | IF missing[1] IS NULL THEN 1036 | RETURN ok( true, $3 ); 1037 | END IF; 1038 | RETURN ok( false, $3 ) || E'\n' || diag( 1039 | ' ' || quote_ident($1) || '.' || 1040 | array_to_string( missing, E'() missing\n ' || quote_ident($1) || '.') || 1041 | '() missing' 1042 | ); 1043 | END; 1044 | $$ LANGUAGE plpgsql; 1045 | 1046 | -- can( schema, functions[] ) 1047 | CREATE OR REPLACE FUNCTION can ( NAME, NAME[] ) 1048 | RETURNS TEXT AS $$ 1049 | SELECT can( $1, $2, 'Schema ' || quote_ident($1) || ' can' ); 1050 | $$ LANGUAGE sql; 1051 | 1052 | -- can( functions[], description ) 1053 | CREATE OR REPLACE FUNCTION can ( NAME[], TEXT ) 1054 | RETURNS TEXT AS $$ 1055 | DECLARE 1056 | missing text[]; 1057 | BEGIN 1058 | SELECT ARRAY( 1059 | SELECT quote_ident($1[i]) 1060 | FROM generate_series(1, array_upper($1, 1)) s(i) 1061 | LEFT JOIN pg_catalog.pg_proc p 1062 | ON $1[i] = p.proname 1063 | AND pg_catalog.pg_function_is_visible(p.oid) 1064 | WHERE p.oid IS NULL 1065 | ORDER BY s.i 1066 | ) INTO missing; 1067 | IF missing[1] IS NULL THEN 1068 | RETURN ok( true, $2 ); 1069 | END IF; 1070 | RETURN ok( false, $2 ) || E'\n' || diag( 1071 | ' ' || 1072 | array_to_string( missing, E'() missing\n ') || 1073 | '() missing' 1074 | ); 1075 | END; 1076 | $$ LANGUAGE plpgsql; 1077 | 1078 | -- can( functions[] ) 1079 | CREATE OR REPLACE FUNCTION can ( NAME[] ) 1080 | RETURNS TEXT AS $$ 1081 | SELECT can( $1, 'Schema ' || _ident_array_to_string(current_schemas(true), ' or ') || ' can' ); 1082 | $$ LANGUAGE sql; 1083 | 1084 | CREATE OR REPLACE FUNCTION _has_type( NAME, NAME, CHAR[] ) 1085 | RETURNS BOOLEAN AS $$ 1086 | SELECT EXISTS( 1087 | SELECT true 1088 | FROM pg_catalog.pg_type t 1089 | JOIN pg_catalog.pg_namespace n ON t.typnamespace = n.oid 1090 | WHERE t.typisdefined 1091 | AND n.nspname = $1 1092 | AND t.typname = $2 1093 | AND t.typtype = ANY( COALESCE($3, ARRAY['b', 'c', 'd', 'p', 'e']) ) 1094 | ); 1095 | $$ LANGUAGE sql; 1096 | 1097 | CREATE OR REPLACE FUNCTION _has_type( NAME, CHAR[] ) 1098 | RETURNS BOOLEAN AS $$ 1099 | SELECT EXISTS( 1100 | SELECT true 1101 | FROM pg_catalog.pg_type t 1102 | WHERE t.typisdefined 1103 | AND pg_catalog.pg_type_is_visible(t.oid) 1104 | AND t.typname = $1 1105 | AND t.typtype = ANY( COALESCE($2, ARRAY['b', 'c', 'd', 'p', 'e']) ) 1106 | ); 1107 | $$ LANGUAGE sql; 1108 | 1109 | -- has_type( schema, type, description ) 1110 | CREATE OR REPLACE FUNCTION has_type( NAME, NAME, TEXT ) 1111 | RETURNS TEXT AS $$ 1112 | SELECT ok( _has_type( $1, $2, NULL ), $3 ); 1113 | $$ LANGUAGE sql; 1114 | 1115 | -- has_type( schema, type ) 1116 | CREATE OR REPLACE FUNCTION has_type( NAME, NAME ) 1117 | RETURNS TEXT AS $$ 1118 | SELECT has_type( $1, $2, 'Type ' || quote_ident($1) || '.' || quote_ident($2) || ' should exist' ); 1119 | $$ LANGUAGE sql; 1120 | 1121 | -- has_type( type, description ) 1122 | CREATE OR REPLACE FUNCTION has_type( NAME, TEXT ) 1123 | RETURNS TEXT AS $$ 1124 | SELECT ok( _has_type( $1, NULL ), $2 ); 1125 | $$ LANGUAGE sql; 1126 | 1127 | -- has_type( type ) 1128 | CREATE OR REPLACE FUNCTION has_type( NAME ) 1129 | RETURNS TEXT AS $$ 1130 | SELECT ok( _has_type( $1, NULL ), ('Type ' || quote_ident($1) || ' should exist')::text ); 1131 | $$ LANGUAGE sql; 1132 | 1133 | -- hasnt_type( schema, type, description ) 1134 | CREATE OR REPLACE FUNCTION hasnt_type( NAME, NAME, TEXT ) 1135 | RETURNS TEXT AS $$ 1136 | SELECT ok( NOT _has_type( $1, $2, NULL ), $3 ); 1137 | $$ LANGUAGE sql; 1138 | 1139 | -- hasnt_type( schema, type ) 1140 | CREATE OR REPLACE FUNCTION hasnt_type( NAME, NAME ) 1141 | RETURNS TEXT AS $$ 1142 | SELECT hasnt_type( $1, $2, 'Type ' || quote_ident($1) || '.' || quote_ident($2) || ' should not exist' ); 1143 | $$ LANGUAGE sql; 1144 | 1145 | -- hasnt_type( type, description ) 1146 | CREATE OR REPLACE FUNCTION hasnt_type( NAME, TEXT ) 1147 | RETURNS TEXT AS $$ 1148 | SELECT ok( NOT _has_type( $1, NULL ), $2 ); 1149 | $$ LANGUAGE sql; 1150 | 1151 | -- hasnt_type( type ) 1152 | CREATE OR REPLACE FUNCTION hasnt_type( NAME ) 1153 | RETURNS TEXT AS $$ 1154 | SELECT ok( NOT _has_type( $1, NULL ), ('Type ' || quote_ident($1) || ' should not exist')::text ); 1155 | $$ LANGUAGE sql; 1156 | 1157 | -- has_domain( schema, domain, description ) 1158 | CREATE OR REPLACE FUNCTION has_domain( NAME, NAME, TEXT ) 1159 | RETURNS TEXT AS $$ 1160 | SELECT ok( _has_type( $1, $2, ARRAY['d'] ), $3 ); 1161 | $$ LANGUAGE sql; 1162 | 1163 | -- has_domain( schema, domain ) 1164 | CREATE OR REPLACE FUNCTION has_domain( NAME, NAME ) 1165 | RETURNS TEXT AS $$ 1166 | SELECT has_domain( $1, $2, 'Domain ' || quote_ident($1) || '.' || quote_ident($2) || ' should exist' ); 1167 | $$ LANGUAGE sql; 1168 | 1169 | -- has_domain( domain, description ) 1170 | CREATE OR REPLACE FUNCTION has_domain( NAME, TEXT ) 1171 | RETURNS TEXT AS $$ 1172 | SELECT ok( _has_type( $1, ARRAY['d'] ), $2 ); 1173 | $$ LANGUAGE sql; 1174 | 1175 | -- has_domain( domain ) 1176 | CREATE OR REPLACE FUNCTION has_domain( NAME ) 1177 | RETURNS TEXT AS $$ 1178 | SELECT ok( _has_type( $1, ARRAY['d'] ), ('Domain ' || quote_ident($1) || ' should exist')::text ); 1179 | $$ LANGUAGE sql; 1180 | 1181 | -- hasnt_domain( schema, domain, description ) 1182 | CREATE OR REPLACE FUNCTION hasnt_domain( NAME, NAME, TEXT ) 1183 | RETURNS TEXT AS $$ 1184 | SELECT ok( NOT _has_type( $1, $2, ARRAY['d'] ), $3 ); 1185 | $$ LANGUAGE sql; 1186 | 1187 | -- hasnt_domain( schema, domain ) 1188 | CREATE OR REPLACE FUNCTION hasnt_domain( NAME, NAME ) 1189 | RETURNS TEXT AS $$ 1190 | SELECT hasnt_domain( $1, $2, 'Domain ' || quote_ident($1) || '.' || quote_ident($2) || ' should not exist' ); 1191 | $$ LANGUAGE sql; 1192 | 1193 | -- hasnt_domain( domain, description ) 1194 | CREATE OR REPLACE FUNCTION hasnt_domain( NAME, TEXT ) 1195 | RETURNS TEXT AS $$ 1196 | SELECT ok( NOT _has_type( $1, ARRAY['d'] ), $2 ); 1197 | $$ LANGUAGE sql; 1198 | 1199 | -- hasnt_domain( domain ) 1200 | CREATE OR REPLACE FUNCTION hasnt_domain( NAME ) 1201 | RETURNS TEXT AS $$ 1202 | SELECT ok( NOT _has_type( $1, ARRAY['d'] ), ('Domain ' || quote_ident($1) || ' should not exist')::text ); 1203 | $$ LANGUAGE sql; 1204 | 1205 | -- has_enum( schema, enum, description ) 1206 | CREATE OR REPLACE FUNCTION has_enum( NAME, NAME, TEXT ) 1207 | RETURNS TEXT AS $$ 1208 | SELECT ok( _has_type( $1, $2, ARRAY['e'] ), $3 ); 1209 | $$ LANGUAGE sql; 1210 | 1211 | -- has_enum( schema, enum ) 1212 | CREATE OR REPLACE FUNCTION has_enum( NAME, NAME ) 1213 | RETURNS TEXT AS $$ 1214 | SELECT has_enum( $1, $2, 'Enum ' || quote_ident($1) || '.' || quote_ident($2) || ' should exist' ); 1215 | $$ LANGUAGE sql; 1216 | 1217 | -- has_enum( enum, description ) 1218 | CREATE OR REPLACE FUNCTION has_enum( NAME, TEXT ) 1219 | RETURNS TEXT AS $$ 1220 | SELECT ok( _has_type( $1, ARRAY['e'] ), $2 ); 1221 | $$ LANGUAGE sql; 1222 | 1223 | -- has_enum( enum ) 1224 | CREATE OR REPLACE FUNCTION has_enum( NAME ) 1225 | RETURNS TEXT AS $$ 1226 | SELECT ok( _has_type( $1, ARRAY['e'] ), ('Enum ' || quote_ident($1) || ' should exist')::text ); 1227 | $$ LANGUAGE sql; 1228 | 1229 | -- hasnt_enum( schema, enum, description ) 1230 | CREATE OR REPLACE FUNCTION hasnt_enum( NAME, NAME, TEXT ) 1231 | RETURNS TEXT AS $$ 1232 | SELECT ok( NOT _has_type( $1, $2, ARRAY['e'] ), $3 ); 1233 | $$ LANGUAGE sql; 1234 | 1235 | -- hasnt_enum( schema, enum ) 1236 | CREATE OR REPLACE FUNCTION hasnt_enum( NAME, NAME ) 1237 | RETURNS TEXT AS $$ 1238 | SELECT hasnt_enum( $1, $2, 'Enum ' || quote_ident($1) || '.' || quote_ident($2) || ' should not exist' ); 1239 | $$ LANGUAGE sql; 1240 | 1241 | -- hasnt_enum( enum, description ) 1242 | CREATE OR REPLACE FUNCTION hasnt_enum( NAME, TEXT ) 1243 | RETURNS TEXT AS $$ 1244 | SELECT ok( NOT _has_type( $1, ARRAY['e'] ), $2 ); 1245 | $$ LANGUAGE sql; 1246 | 1247 | -- hasnt_enum( enum ) 1248 | CREATE OR REPLACE FUNCTION hasnt_enum( NAME ) 1249 | RETURNS TEXT AS $$ 1250 | SELECT ok( NOT _has_type( $1, ARRAY['e'] ), ('Enum ' || quote_ident($1) || ' should not exist')::text ); 1251 | $$ LANGUAGE sql; 1252 | 1253 | -- enum_has_labels( schema, enum, labels, description ) 1254 | CREATE OR REPLACE FUNCTION enum_has_labels( NAME, NAME, NAME[], TEXT ) 1255 | RETURNS TEXT AS $$ 1256 | SELECT is( 1257 | ARRAY( 1258 | SELECT e.enumlabel 1259 | FROM pg_catalog.pg_type t 1260 | JOIN pg_catalog.pg_enum e ON t.oid = e.enumtypid 1261 | JOIN pg_catalog.pg_namespace n ON t.typnamespace = n.oid 1262 | WHERE t.typisdefined 1263 | AND n.nspname = $1 1264 | AND t.typname = $2 1265 | AND t.typtype = 'e' 1266 | ORDER BY e.oid 1267 | ), 1268 | $3, 1269 | $4 1270 | ); 1271 | $$ LANGUAGE sql; 1272 | 1273 | -- enum_has_labels( schema, enum, labels ) 1274 | CREATE OR REPLACE FUNCTION enum_has_labels( NAME, NAME, NAME[] ) 1275 | RETURNS TEXT AS $$ 1276 | SELECT enum_has_labels( 1277 | $1, $2, $3, 1278 | 'Enum ' || quote_ident($1) || '.' || quote_ident($2) || ' should have labels (' || array_to_string( $3, ', ' ) || ')' 1279 | ); 1280 | $$ LANGUAGE sql; 1281 | 1282 | -- enum_has_labels( enum, labels, description ) 1283 | CREATE OR REPLACE FUNCTION enum_has_labels( NAME, NAME[], TEXT ) 1284 | RETURNS TEXT AS $$ 1285 | SELECT is( 1286 | ARRAY( 1287 | SELECT e.enumlabel 1288 | FROM pg_catalog.pg_type t 1289 | JOIN pg_catalog.pg_enum e ON t.oid = e.enumtypid 1290 | WHERE t.typisdefined 1291 | AND pg_catalog.pg_type_is_visible(t.oid) 1292 | AND t.typname = $1 1293 | AND t.typtype = 'e' 1294 | ORDER BY e.oid 1295 | ), 1296 | $2, 1297 | $3 1298 | ); 1299 | $$ LANGUAGE sql; 1300 | 1301 | -- enum_has_labels( enum, labels ) 1302 | CREATE OR REPLACE FUNCTION enum_has_labels( NAME, NAME[] ) 1303 | RETURNS TEXT AS $$ 1304 | SELECT enum_has_labels( 1305 | $1, $2, 1306 | 'Enum ' || quote_ident($1) || ' should have labels (' || array_to_string( $2, ', ' ) || ')' 1307 | ); 1308 | $$ LANGUAGE sql; 1309 | 1310 | CREATE OR REPLACE FUNCTION _cmp_types(oid, name) 1311 | RETURNS BOOLEAN AS $$ 1312 | DECLARE 1313 | dtype TEXT := display_type($1, NULL); 1314 | BEGIN 1315 | RETURN dtype = _quote_ident_like($2, dtype); 1316 | END; 1317 | $$ LANGUAGE plpgsql; 1318 | 1319 | CREATE OR REPLACE FUNCTION _cast_exists ( NAME, NAME, NAME, NAME ) 1320 | RETURNS BOOLEAN AS $$ 1321 | SELECT EXISTS ( 1322 | SELECT TRUE 1323 | FROM pg_catalog.pg_cast c 1324 | JOIN pg_catalog.pg_proc p ON c.castfunc = p.oid 1325 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 1326 | WHERE _cmp_types(castsource, $1) 1327 | AND _cmp_types(casttarget, $2) 1328 | AND n.nspname = $3 1329 | AND p.proname = $4 1330 | ); 1331 | $$ LANGUAGE SQL; 1332 | 1333 | CREATE OR REPLACE FUNCTION _cast_exists ( NAME, NAME, NAME ) 1334 | RETURNS BOOLEAN AS $$ 1335 | SELECT EXISTS ( 1336 | SELECT TRUE 1337 | FROM pg_catalog.pg_cast c 1338 | JOIN pg_catalog.pg_proc p ON c.castfunc = p.oid 1339 | WHERE _cmp_types(castsource, $1) 1340 | AND _cmp_types(casttarget, $2) 1341 | AND p.proname = $3 1342 | ); 1343 | $$ LANGUAGE SQL; 1344 | 1345 | CREATE OR REPLACE FUNCTION _cast_exists ( NAME, NAME ) 1346 | RETURNS BOOLEAN AS $$ 1347 | SELECT EXISTS ( 1348 | SELECT TRUE 1349 | FROM pg_catalog.pg_cast c 1350 | WHERE _cmp_types(castsource, $1) 1351 | AND _cmp_types(casttarget, $2) 1352 | ); 1353 | $$ LANGUAGE SQL; 1354 | 1355 | -- has_cast( source_type, target_type, schema, function, description ) 1356 | CREATE OR REPLACE FUNCTION has_cast ( NAME, NAME, NAME, NAME, TEXT ) 1357 | RETURNS TEXT AS $$ 1358 | SELECT ok( _cast_exists( $1, $2, $3, $4 ), $5 ); 1359 | $$ LANGUAGE SQL; 1360 | 1361 | -- has_cast( source_type, target_type, schema, function ) 1362 | CREATE OR REPLACE FUNCTION has_cast ( NAME, NAME, NAME, NAME ) 1363 | RETURNS TEXT AS $$ 1364 | SELECT ok( 1365 | _cast_exists( $1, $2, $3, $4 ), 1366 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1367 | || ') WITH FUNCTION ' || quote_ident($3) 1368 | || '.' || quote_ident($4) || '() should exist' 1369 | ); 1370 | $$ LANGUAGE SQL; 1371 | 1372 | -- has_cast( source_type, target_type, function, description ) 1373 | CREATE OR REPLACE FUNCTION has_cast ( NAME, NAME, NAME, TEXT ) 1374 | RETURNS TEXT AS $$ 1375 | SELECT ok( _cast_exists( $1, $2, $3 ), $4 ); 1376 | $$ LANGUAGE SQL; 1377 | 1378 | -- has_cast( source_type, target_type, function ) 1379 | CREATE OR REPLACE FUNCTION has_cast ( NAME, NAME, NAME ) 1380 | RETURNS TEXT AS $$ 1381 | SELECT ok( 1382 | _cast_exists( $1, $2, $3 ), 1383 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1384 | || ') WITH FUNCTION ' || quote_ident($3) || '() should exist' 1385 | ); 1386 | $$ LANGUAGE SQL; 1387 | 1388 | -- has_cast( source_type, target_type, description ) 1389 | CREATE OR REPLACE FUNCTION has_cast ( NAME, NAME, TEXT ) 1390 | RETURNS TEXT AS $$ 1391 | SELECT ok( _cast_exists( $1, $2 ), $3 ); 1392 | $$ LANGUAGE SQL; 1393 | 1394 | -- has_cast( source_type, target_type ) 1395 | CREATE OR REPLACE FUNCTION has_cast ( NAME, NAME ) 1396 | RETURNS TEXT AS $$ 1397 | SELECT ok( 1398 | _cast_exists( $1, $2 ), 1399 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1400 | || ') should exist' 1401 | ); 1402 | $$ LANGUAGE SQL; 1403 | 1404 | -- hasnt_cast( source_type, target_type, schema, function, description ) 1405 | CREATE OR REPLACE FUNCTION hasnt_cast ( NAME, NAME, NAME, NAME, TEXT ) 1406 | RETURNS TEXT AS $$ 1407 | SELECT ok( NOT _cast_exists( $1, $2, $3, $4 ), $5 ); 1408 | $$ LANGUAGE SQL; 1409 | 1410 | -- hasnt_cast( source_type, target_type, schema, function ) 1411 | CREATE OR REPLACE FUNCTION hasnt_cast ( NAME, NAME, NAME, NAME ) 1412 | RETURNS TEXT AS $$ 1413 | SELECT ok( 1414 | NOT _cast_exists( $1, $2, $3, $4 ), 1415 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1416 | || ') WITH FUNCTION ' || quote_ident($3) 1417 | || '.' || quote_ident($4) || '() should not exist' 1418 | ); 1419 | $$ LANGUAGE SQL; 1420 | 1421 | -- hasnt_cast( source_type, target_type, function, description ) 1422 | CREATE OR REPLACE FUNCTION hasnt_cast ( NAME, NAME, NAME, TEXT ) 1423 | RETURNS TEXT AS $$ 1424 | SELECT ok( NOT _cast_exists( $1, $2, $3 ), $4 ); 1425 | $$ LANGUAGE SQL; 1426 | 1427 | -- hasnt_cast( source_type, target_type, function ) 1428 | CREATE OR REPLACE FUNCTION hasnt_cast ( NAME, NAME, NAME ) 1429 | RETURNS TEXT AS $$ 1430 | SELECT ok( 1431 | NOT _cast_exists( $1, $2, $3 ), 1432 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1433 | || ') WITH FUNCTION ' || quote_ident($3) || '() should not exist' 1434 | ); 1435 | $$ LANGUAGE SQL; 1436 | 1437 | -- hasnt_cast( source_type, target_type, description ) 1438 | CREATE OR REPLACE FUNCTION hasnt_cast ( NAME, NAME, TEXT ) 1439 | RETURNS TEXT AS $$ 1440 | SELECT ok( NOT _cast_exists( $1, $2 ), $3 ); 1441 | $$ LANGUAGE SQL; 1442 | 1443 | -- hasnt_cast( source_type, target_type ) 1444 | CREATE OR REPLACE FUNCTION hasnt_cast ( NAME, NAME ) 1445 | RETURNS TEXT AS $$ 1446 | SELECT ok( 1447 | NOT _cast_exists( $1, $2 ), 1448 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1449 | || ') should not exist' 1450 | ); 1451 | $$ LANGUAGE SQL; 1452 | 1453 | CREATE OR REPLACE FUNCTION _expand_context( char ) 1454 | RETURNS text AS $$ 1455 | SELECT CASE $1 1456 | WHEN 'i' THEN 'implicit' 1457 | WHEN 'a' THEN 'assignment' 1458 | WHEN 'e' THEN 'explicit' 1459 | ELSE 'unknown' END 1460 | $$ LANGUAGE SQL IMMUTABLE; 1461 | 1462 | CREATE OR REPLACE FUNCTION _get_context( NAME, NAME ) 1463 | RETURNS "char" AS $$ 1464 | SELECT c.castcontext 1465 | FROM pg_catalog.pg_cast c 1466 | WHERE _cmp_types(castsource, $1) 1467 | AND _cmp_types(casttarget, $2) 1468 | $$ LANGUAGE SQL; 1469 | 1470 | -- cast_context_is( source_type, target_type, context, description ) 1471 | CREATE OR REPLACE FUNCTION cast_context_is( NAME, NAME, TEXT, TEXT ) 1472 | RETURNS TEXT AS $$ 1473 | DECLARE 1474 | want char = substring(LOWER($3) FROM 1 FOR 1); 1475 | have char := _get_context($1, $2); 1476 | BEGIN 1477 | IF have IS NOT NULL THEN 1478 | RETURN is( _expand_context(have), _expand_context(want), $4 ); 1479 | END IF; 1480 | 1481 | RETURN ok( false, $4 ) || E'\n' || diag( 1482 | ' Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1483 | || ') does not exist' 1484 | ); 1485 | END; 1486 | $$ LANGUAGE plpgsql; 1487 | 1488 | -- cast_context_is( source_type, target_type, context ) 1489 | CREATE OR REPLACE FUNCTION cast_context_is( NAME, NAME, TEXT ) 1490 | RETURNS TEXT AS $$ 1491 | SELECT cast_context_is( 1492 | $1, $2, $3, 1493 | 'Cast (' || quote_ident($1) || ' AS ' || quote_ident($2) 1494 | || ') context should be ' || _expand_context(substring(LOWER($3) FROM 1 FOR 1)) 1495 | ); 1496 | $$ LANGUAGE SQL; 1497 | 1498 | CREATE OR REPLACE FUNCTION _op_exists ( NAME, NAME, NAME, NAME, NAME ) 1499 | RETURNS BOOLEAN AS $$ 1500 | SELECT EXISTS ( 1501 | SELECT TRUE 1502 | FROM pg_catalog.pg_operator o 1503 | JOIN pg_catalog.pg_namespace n ON o.oprnamespace = n.oid 1504 | WHERE n.nspname = $2 1505 | AND o.oprname = $3 1506 | AND CASE o.oprkind WHEN 'l' THEN $1 IS NULL 1507 | ELSE _cmp_types(o.oprleft, $1) END 1508 | AND CASE o.oprkind WHEN 'r' THEN $4 IS NULL 1509 | ELSE _cmp_types(o.oprright, $4) END 1510 | AND _cmp_types(o.oprresult, $5) 1511 | ); 1512 | $$ LANGUAGE SQL; 1513 | 1514 | CREATE OR REPLACE FUNCTION _op_exists ( NAME, NAME, NAME, NAME ) 1515 | RETURNS BOOLEAN AS $$ 1516 | SELECT EXISTS ( 1517 | SELECT TRUE 1518 | FROM pg_catalog.pg_operator o 1519 | WHERE pg_catalog.pg_operator_is_visible(o.oid) 1520 | AND o.oprname = $2 1521 | AND CASE o.oprkind WHEN 'l' THEN $1 IS NULL 1522 | ELSE _cmp_types(o.oprleft, $1) END 1523 | AND CASE o.oprkind WHEN 'r' THEN $3 IS NULL 1524 | ELSE _cmp_types(o.oprright, $3) END 1525 | AND _cmp_types(o.oprresult, $4) 1526 | ); 1527 | $$ LANGUAGE SQL; 1528 | 1529 | CREATE OR REPLACE FUNCTION _op_exists ( NAME, NAME, NAME ) 1530 | RETURNS BOOLEAN AS $$ 1531 | SELECT EXISTS ( 1532 | SELECT TRUE 1533 | FROM pg_catalog.pg_operator o 1534 | WHERE pg_catalog.pg_operator_is_visible(o.oid) 1535 | AND o.oprname = $2 1536 | AND CASE o.oprkind WHEN 'l' THEN $1 IS NULL 1537 | ELSE _cmp_types(o.oprleft, $1) END 1538 | AND CASE o.oprkind WHEN 'r' THEN $3 IS NULL 1539 | ELSE _cmp_types(o.oprright, $3) END 1540 | ); 1541 | $$ LANGUAGE SQL; 1542 | 1543 | -- has_operator( left_type, schema, name, right_type, return_type, description ) 1544 | CREATE OR REPLACE FUNCTION has_operator ( NAME, NAME, NAME, NAME, NAME, TEXT ) 1545 | RETURNS TEXT AS $$ 1546 | SELECT ok( _op_exists($1, $2, $3, $4, $5 ), $6 ); 1547 | $$ LANGUAGE SQL; 1548 | 1549 | -- has_operator( left_type, schema, name, right_type, return_type ) 1550 | CREATE OR REPLACE FUNCTION has_operator ( NAME, NAME, NAME, NAME, NAME ) 1551 | RETURNS TEXT AS $$ 1552 | SELECT ok( 1553 | _op_exists($1, $2, $3, $4, $5 ), 1554 | 'Operator ' || quote_ident($2) || '.' || $3 || '(' || $1 || ',' || $4 1555 | || ') RETURNS ' || $5 || ' should exist' 1556 | ); 1557 | $$ LANGUAGE SQL; 1558 | 1559 | -- has_operator( left_type, name, right_type, return_type, description ) 1560 | CREATE OR REPLACE FUNCTION has_operator ( NAME, NAME, NAME, NAME, TEXT ) 1561 | RETURNS TEXT AS $$ 1562 | SELECT ok( _op_exists($1, $2, $3, $4 ), $5 ); 1563 | $$ LANGUAGE SQL; 1564 | 1565 | -- has_operator( left_type, name, right_type, return_type ) 1566 | CREATE OR REPLACE FUNCTION has_operator ( NAME, NAME, NAME, NAME ) 1567 | RETURNS TEXT AS $$ 1568 | SELECT ok( 1569 | _op_exists($1, $2, $3, $4 ), 1570 | 'Operator ' || $2 || '(' || $1 || ',' || $3 1571 | || ') RETURNS ' || $4 || ' should exist' 1572 | ); 1573 | $$ LANGUAGE SQL; 1574 | 1575 | -- has_operator( left_type, name, right_type, description ) 1576 | CREATE OR REPLACE FUNCTION has_operator ( NAME, NAME, NAME, TEXT ) 1577 | RETURNS TEXT AS $$ 1578 | SELECT ok( _op_exists($1, $2, $3 ), $4 ); 1579 | $$ LANGUAGE SQL; 1580 | 1581 | -- has_operator( left_type, name, right_type ) 1582 | CREATE OR REPLACE FUNCTION has_operator ( NAME, NAME, NAME ) 1583 | RETURNS TEXT AS $$ 1584 | SELECT ok( 1585 | _op_exists($1, $2, $3 ), 1586 | 'Operator ' || $2 || '(' || $1 || ',' || $3 1587 | || ') should exist' 1588 | ); 1589 | $$ LANGUAGE SQL; 1590 | 1591 | -- has_leftop( schema, name, right_type, return_type, description ) 1592 | CREATE OR REPLACE FUNCTION has_leftop ( NAME, NAME, NAME, NAME, TEXT ) 1593 | RETURNS TEXT AS $$ 1594 | SELECT ok( _op_exists(NULL, $1, $2, $3, $4), $5 ); 1595 | $$ LANGUAGE SQL; 1596 | 1597 | -- has_leftop( schema, name, right_type, return_type ) 1598 | CREATE OR REPLACE FUNCTION has_leftop ( NAME, NAME, NAME, NAME ) 1599 | RETURNS TEXT AS $$ 1600 | SELECT ok( 1601 | _op_exists(NULL, $1, $2, $3, $4 ), 1602 | 'Left operator ' || quote_ident($1) || '.' || $2 || '(NONE,' 1603 | || $3 || ') RETURNS ' || $4 || ' should exist' 1604 | ); 1605 | $$ LANGUAGE SQL; 1606 | 1607 | -- has_leftop( name, right_type, return_type, description ) 1608 | CREATE OR REPLACE FUNCTION has_leftop ( NAME, NAME, NAME, TEXT ) 1609 | RETURNS TEXT AS $$ 1610 | SELECT ok( _op_exists(NULL, $1, $2, $3), $4 ); 1611 | $$ LANGUAGE SQL; 1612 | 1613 | -- has_leftop( name, right_type, return_type ) 1614 | CREATE OR REPLACE FUNCTION has_leftop ( NAME, NAME, NAME ) 1615 | RETURNS TEXT AS $$ 1616 | SELECT ok( 1617 | _op_exists(NULL, $1, $2, $3 ), 1618 | 'Left operator ' || $1 || '(NONE,' || $2 || ') RETURNS ' || $3 || ' should exist' 1619 | ); 1620 | $$ LANGUAGE SQL; 1621 | 1622 | -- has_leftop( name, right_type, description ) 1623 | CREATE OR REPLACE FUNCTION has_leftop ( NAME, NAME, TEXT ) 1624 | RETURNS TEXT AS $$ 1625 | SELECT ok( _op_exists(NULL, $1, $2), $3 ); 1626 | $$ LANGUAGE SQL; 1627 | 1628 | -- has_leftop( name, right_type ) 1629 | CREATE OR REPLACE FUNCTION has_leftop ( NAME, NAME ) 1630 | RETURNS TEXT AS $$ 1631 | SELECT ok( 1632 | _op_exists(NULL, $1, $2 ), 1633 | 'Left operator ' || $1 || '(NONE,' || $2 || ') should exist' 1634 | ); 1635 | $$ LANGUAGE SQL; 1636 | 1637 | -- has_rightop( left_type, schema, name, return_type, description ) 1638 | CREATE OR REPLACE FUNCTION has_rightop ( NAME, NAME, NAME, NAME, TEXT ) 1639 | RETURNS TEXT AS $$ 1640 | SELECT ok( _op_exists( $1, $2, $3, NULL, $4), $5 ); 1641 | $$ LANGUAGE SQL; 1642 | 1643 | -- has_rightop( left_type, schema, name, return_type ) 1644 | CREATE OR REPLACE FUNCTION has_rightop ( NAME, NAME, NAME, NAME ) 1645 | RETURNS TEXT AS $$ 1646 | SELECT ok( 1647 | _op_exists($1, $2, $3, NULL, $4 ), 1648 | 'Right operator ' || quote_ident($2) || '.' || $3 || '(' 1649 | || $1 || ',NONE) RETURNS ' || $4 || ' should exist' 1650 | ); 1651 | $$ LANGUAGE SQL; 1652 | 1653 | -- has_rightop( left_type, name, return_type, description ) 1654 | CREATE OR REPLACE FUNCTION has_rightop ( NAME, NAME, NAME, TEXT ) 1655 | RETURNS TEXT AS $$ 1656 | SELECT ok( _op_exists( $1, $2, NULL, $3), $4 ); 1657 | $$ LANGUAGE SQL; 1658 | 1659 | -- has_rightop( left_type, name, return_type ) 1660 | CREATE OR REPLACE FUNCTION has_rightop ( NAME, NAME, NAME ) 1661 | RETURNS TEXT AS $$ 1662 | SELECT ok( 1663 | _op_exists($1, $2, NULL, $3 ), 1664 | 'Right operator ' || $2 || '(' 1665 | || $1 || ',NONE) RETURNS ' || $3 || ' should exist' 1666 | ); 1667 | $$ LANGUAGE SQL; 1668 | 1669 | -- has_rightop( left_type, name, description ) 1670 | CREATE OR REPLACE FUNCTION has_rightop ( NAME, NAME, TEXT ) 1671 | RETURNS TEXT AS $$ 1672 | SELECT ok( _op_exists( $1, $2, NULL), $3 ); 1673 | $$ LANGUAGE SQL; 1674 | 1675 | -- has_rightop( left_type, name ) 1676 | CREATE OR REPLACE FUNCTION has_rightop ( NAME, NAME ) 1677 | RETURNS TEXT AS $$ 1678 | SELECT ok( 1679 | _op_exists($1, $2, NULL ), 1680 | 'Right operator ' || $2 || '(' || $1 || ',NONE) should exist' 1681 | ); 1682 | $$ LANGUAGE SQL; 1683 | 1684 | CREATE OR REPLACE FUNCTION _is_trusted( NAME ) 1685 | RETURNS BOOLEAN AS $$ 1686 | SELECT lanpltrusted FROM pg_catalog.pg_language WHERE lanname = $1; 1687 | $$ LANGUAGE SQL; 1688 | 1689 | -- has_language( language, description) 1690 | CREATE OR REPLACE FUNCTION has_language( NAME, TEXT ) 1691 | RETURNS TEXT AS $$ 1692 | SELECT ok( _is_trusted($1) IS NOT NULL, $2 ); 1693 | $$ LANGUAGE SQL; 1694 | 1695 | -- has_language( language ) 1696 | CREATE OR REPLACE FUNCTION has_language( NAME ) 1697 | RETURNS TEXT AS $$ 1698 | SELECT ok( _is_trusted($1) IS NOT NULL, 'Procedural language ' || quote_ident($1) || ' should exist' ); 1699 | $$ LANGUAGE SQL; 1700 | 1701 | -- hasnt_language( language, description) 1702 | CREATE OR REPLACE FUNCTION hasnt_language( NAME, TEXT ) 1703 | RETURNS TEXT AS $$ 1704 | SELECT ok( _is_trusted($1) IS NULL, $2 ); 1705 | $$ LANGUAGE SQL; 1706 | 1707 | -- hasnt_language( language ) 1708 | CREATE OR REPLACE FUNCTION hasnt_language( NAME ) 1709 | RETURNS TEXT AS $$ 1710 | SELECT ok( _is_trusted($1) IS NULL, 'Procedural language ' || quote_ident($1) || ' should not exist' ); 1711 | $$ LANGUAGE SQL; 1712 | 1713 | -- language_is_trusted( language, description ) 1714 | CREATE OR REPLACE FUNCTION language_is_trusted( NAME, TEXT ) 1715 | RETURNS TEXT AS $$ 1716 | DECLARE 1717 | is_trusted boolean := _is_trusted($1); 1718 | BEGIN 1719 | IF is_trusted IS NULL THEN 1720 | RETURN fail( $2 ) || E'\n' || diag( ' Procedural language ' || quote_ident($1) || ' does not exist') ; 1721 | END IF; 1722 | RETURN ok( is_trusted, $2 ); 1723 | END; 1724 | $$ LANGUAGE plpgsql; 1725 | 1726 | -- language_is_trusted( language ) 1727 | CREATE OR REPLACE FUNCTION language_is_trusted( NAME ) 1728 | RETURNS TEXT AS $$ 1729 | SELECT language_is_trusted($1, 'Procedural language ' || quote_ident($1) || ' should be trusted' ); 1730 | $$ LANGUAGE SQL; 1731 | 1732 | CREATE OR REPLACE FUNCTION _opc_exists( NAME, NAME ) 1733 | RETURNS BOOLEAN AS $$ 1734 | SELECT EXISTS ( 1735 | SELECT TRUE 1736 | FROM pg_catalog.pg_opclass oc 1737 | JOIN pg_catalog.pg_namespace n ON oc.opcnamespace = n.oid 1738 | WHERE n.nspname = COALESCE($1, n.nspname) 1739 | AND oc.opcname = $2 1740 | ); 1741 | $$ LANGUAGE SQL; 1742 | 1743 | -- has_opclass( schema, name, description ) 1744 | CREATE OR REPLACE FUNCTION has_opclass( NAME, NAME, TEXT ) 1745 | RETURNS TEXT AS $$ 1746 | SELECT ok( _opc_exists( $1, $2 ), $3 ); 1747 | $$ LANGUAGE SQL; 1748 | 1749 | -- has_opclass( schema, name ) 1750 | CREATE OR REPLACE FUNCTION has_opclass( NAME, NAME ) 1751 | RETURNS TEXT AS $$ 1752 | SELECT ok( _opc_exists( $1, $2 ), 'Operator class ' || quote_ident($1) || '.' || quote_ident($2) || ' should exist' ); 1753 | $$ LANGUAGE SQL; 1754 | 1755 | -- has_opclass( name, description ) 1756 | CREATE OR REPLACE FUNCTION has_opclass( NAME, TEXT ) 1757 | RETURNS TEXT AS $$ 1758 | SELECT ok( _opc_exists( NULL, $1 ), $2) 1759 | $$ LANGUAGE SQL; 1760 | 1761 | -- has_opclass( name ) 1762 | CREATE OR REPLACE FUNCTION has_opclass( NAME ) 1763 | RETURNS TEXT AS $$ 1764 | SELECT ok( _opc_exists( NULL, $1 ), 'Operator class ' || quote_ident($1) || ' should exist' ); 1765 | $$ LANGUAGE SQL; 1766 | 1767 | -- hasnt_opclass( schema, name, description ) 1768 | CREATE OR REPLACE FUNCTION hasnt_opclass( NAME, NAME, TEXT ) 1769 | RETURNS TEXT AS $$ 1770 | SELECT ok( NOT _opc_exists( $1, $2 ), $3 ); 1771 | $$ LANGUAGE SQL; 1772 | 1773 | -- hasnt_opclass( schema, name ) 1774 | CREATE OR REPLACE FUNCTION hasnt_opclass( NAME, NAME ) 1775 | RETURNS TEXT AS $$ 1776 | SELECT ok( NOT _opc_exists( $1, $2 ), 'Operator class ' || quote_ident($1) || '.' || quote_ident($2) || ' should exist' ); 1777 | $$ LANGUAGE SQL; 1778 | 1779 | -- hasnt_opclass( name, description ) 1780 | CREATE OR REPLACE FUNCTION hasnt_opclass( NAME, TEXT ) 1781 | RETURNS TEXT AS $$ 1782 | SELECT ok( NOT _opc_exists( NULL, $1 ), $2) 1783 | $$ LANGUAGE SQL; 1784 | 1785 | -- hasnt_opclass( name ) 1786 | CREATE OR REPLACE FUNCTION hasnt_opclass( NAME ) 1787 | RETURNS TEXT AS $$ 1788 | SELECT ok( NOT _opc_exists( NULL, $1 ), 'Operator class ' || quote_ident($1) || ' should exist' ); 1789 | $$ LANGUAGE SQL; 1790 | 1791 | -- opclasses_are( schema, opclasses[], description ) 1792 | CREATE OR REPLACE FUNCTION _nosuch( NAME, NAME, NAME[]) 1793 | RETURNS TEXT AS $$ 1794 | SELECT E'\n' || diag( 1795 | ' Function ' 1796 | || CASE WHEN $1 IS NOT NULL THEN quote_ident($1) || '.' ELSE '' END 1797 | || quote_ident($2) || '(' 1798 | || array_to_string($3, ', ') || ') does not exist' 1799 | ); 1800 | $$ LANGUAGE SQL IMMUTABLE; 1801 | 1802 | CREATE OR REPLACE FUNCTION _func_compare( NAME, NAME, NAME[], anyelement, anyelement, TEXT) 1803 | RETURNS TEXT AS $$ 1804 | SELECT CASE WHEN $4 IS NULL 1805 | THEN ok( FALSE, $6 ) || _nosuch($1, $2, $3) 1806 | ELSE is( $4, $5, $6 ) 1807 | END; 1808 | $$ LANGUAGE SQL; 1809 | 1810 | CREATE OR REPLACE FUNCTION _func_compare( NAME, NAME, NAME[], boolean, TEXT) 1811 | RETURNS TEXT AS $$ 1812 | SELECT CASE WHEN $4 IS NULL 1813 | THEN ok( FALSE, $5 ) || _nosuch($1, $2, $3) 1814 | ELSE ok( $4, $5 ) 1815 | END; 1816 | $$ LANGUAGE sql; 1817 | 1818 | CREATE OR REPLACE FUNCTION _func_compare( NAME, NAME, anyelement, anyelement, TEXT) 1819 | RETURNS TEXT AS $$ 1820 | SELECT CASE WHEN $3 IS NULL 1821 | THEN ok( FALSE, $5 ) || _nosuch($1, $2, '{}') 1822 | ELSE is( $3, $4, $5 ) 1823 | END; 1824 | $$ LANGUAGE SQL; 1825 | 1826 | CREATE OR REPLACE FUNCTION _func_compare( NAME, NAME, boolean, TEXT) 1827 | RETURNS TEXT AS $$ 1828 | SELECT CASE WHEN $3 IS NULL 1829 | THEN ok( FALSE, $4 ) || _nosuch($1, $2, '{}') 1830 | ELSE ok( $3, $4 ) 1831 | END; 1832 | $$ LANGUAGE SQL; 1833 | 1834 | CREATE OR REPLACE FUNCTION _lang ( NAME, NAME, NAME[] ) 1835 | RETURNS NAME AS $$ 1836 | SELECT l.lanname 1837 | FROM tap_funky f 1838 | JOIN pg_catalog.pg_language l ON f.langoid = l.oid 1839 | WHERE f.schema = $1 1840 | and f.name = $2 1841 | AND f.args = array_to_string($3, ',') 1842 | $$ LANGUAGE SQL; 1843 | 1844 | CREATE OR REPLACE FUNCTION _lang ( NAME, NAME ) 1845 | RETURNS NAME AS $$ 1846 | SELECT l.lanname 1847 | FROM tap_funky f 1848 | JOIN pg_catalog.pg_language l ON f.langoid = l.oid 1849 | WHERE f.schema = $1 1850 | and f.name = $2 1851 | $$ LANGUAGE SQL; 1852 | 1853 | CREATE OR REPLACE FUNCTION _lang ( NAME, NAME[] ) 1854 | RETURNS NAME AS $$ 1855 | SELECT l.lanname 1856 | FROM tap_funky f 1857 | JOIN pg_catalog.pg_language l ON f.langoid = l.oid 1858 | WHERE f.name = $1 1859 | AND f.args = array_to_string($2, ',') 1860 | AND f.is_visible; 1861 | $$ LANGUAGE SQL; 1862 | 1863 | CREATE OR REPLACE FUNCTION _lang ( NAME ) 1864 | RETURNS NAME AS $$ 1865 | SELECT l.lanname 1866 | FROM tap_funky f 1867 | JOIN pg_catalog.pg_language l ON f.langoid = l.oid 1868 | WHERE f.name = $1 1869 | AND f.is_visible; 1870 | $$ LANGUAGE SQL; 1871 | 1872 | -- function_lang_is( schema, function, args[], language, description ) 1873 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME, NAME[], NAME, TEXT ) 1874 | RETURNS TEXT AS $$ 1875 | SELECT _func_compare($1, $2, $3, _lang($1, $2, $3), $4, $5 ); 1876 | $$ LANGUAGE SQL; 1877 | 1878 | -- function_lang_is( schema, function, args[], language ) 1879 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME, NAME[], NAME ) 1880 | RETURNS TEXT AS $$ 1881 | SELECT function_lang_is( 1882 | $1, $2, $3, $4, 1883 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 1884 | array_to_string($3, ', ') || ') should be written in ' || quote_ident($4) 1885 | ); 1886 | $$ LANGUAGE SQL; 1887 | 1888 | -- function_lang_is( schema, function, language, description ) 1889 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME, NAME, TEXT ) 1890 | RETURNS TEXT AS $$ 1891 | SELECT _func_compare($1, $2, _lang($1, $2), $3, $4 ); 1892 | $$ LANGUAGE SQL; 1893 | 1894 | -- function_lang_is( schema, function, language ) 1895 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME, NAME ) 1896 | RETURNS TEXT AS $$ 1897 | SELECT function_lang_is( 1898 | $1, $2, $3, 1899 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) 1900 | || '() should be written in ' || quote_ident($3) 1901 | ); 1902 | $$ LANGUAGE SQL; 1903 | 1904 | -- function_lang_is( function, args[], language, description ) 1905 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME[], NAME, TEXT ) 1906 | RETURNS TEXT AS $$ 1907 | SELECT _func_compare(NULL, $1, $2, _lang($1, $2), $3, $4 ); 1908 | $$ LANGUAGE SQL; 1909 | 1910 | -- function_lang_is( function, args[], language ) 1911 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME[], NAME ) 1912 | RETURNS TEXT AS $$ 1913 | SELECT function_lang_is( 1914 | $1, $2, $3, 1915 | 'Function ' || quote_ident($1) || '(' || 1916 | array_to_string($2, ', ') || ') should be written in ' || quote_ident($3) 1917 | ); 1918 | $$ LANGUAGE SQL; 1919 | 1920 | -- function_lang_is( function, language, description ) 1921 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME, TEXT ) 1922 | RETURNS TEXT AS $$ 1923 | SELECT _func_compare(NULL, $1, _lang($1), $2, $3 ); 1924 | $$ LANGUAGE SQL; 1925 | 1926 | -- function_lang_is( function, language ) 1927 | CREATE OR REPLACE FUNCTION function_lang_is( NAME, NAME ) 1928 | RETURNS TEXT AS $$ 1929 | SELECT function_lang_is( 1930 | $1, $2, 1931 | 'Function ' || quote_ident($1) 1932 | || '() should be written in ' || quote_ident($2) 1933 | ); 1934 | $$ LANGUAGE SQL; 1935 | 1936 | CREATE OR REPLACE FUNCTION _returns ( NAME, NAME, NAME[] ) 1937 | RETURNS TEXT AS $$ 1938 | SELECT returns 1939 | FROM tap_funky 1940 | WHERE schema = $1 1941 | AND name = $2 1942 | AND args = array_to_string($3, ',') 1943 | $$ LANGUAGE SQL; 1944 | 1945 | CREATE OR REPLACE FUNCTION _returns ( NAME, NAME ) 1946 | RETURNS TEXT AS $$ 1947 | SELECT returns FROM tap_funky WHERE schema = $1 AND name = $2 1948 | $$ LANGUAGE SQL; 1949 | 1950 | CREATE OR REPLACE FUNCTION _returns ( NAME, NAME[] ) 1951 | RETURNS TEXT AS $$ 1952 | SELECT returns 1953 | FROM tap_funky 1954 | WHERE name = $1 1955 | AND args = array_to_string($2, ',') 1956 | AND is_visible; 1957 | $$ LANGUAGE SQL; 1958 | 1959 | CREATE OR REPLACE FUNCTION _returns ( NAME ) 1960 | RETURNS TEXT AS $$ 1961 | SELECT returns FROM tap_funky WHERE name = $1 AND is_visible; 1962 | $$ LANGUAGE SQL; 1963 | 1964 | -- function_returns( schema, function, args[], type, description ) 1965 | CREATE OR REPLACE FUNCTION function_returns( NAME, NAME, NAME[], TEXT, TEXT ) 1966 | RETURNS TEXT AS $$ 1967 | SELECT _func_compare($1, $2, $3, _returns($1, $2, $3), $4, $5 ); 1968 | $$ LANGUAGE SQL; 1969 | 1970 | -- function_returns( schema, function, args[], type ) 1971 | CREATE OR REPLACE FUNCTION function_returns( NAME, NAME, NAME[], TEXT ) 1972 | RETURNS TEXT AS $$ 1973 | SELECT function_returns( 1974 | $1, $2, $3, $4, 1975 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 1976 | array_to_string($3, ', ') || ') should return ' || $4 1977 | ); 1978 | $$ LANGUAGE SQL; 1979 | 1980 | -- function_returns( schema, function, type, description ) 1981 | CREATE OR REPLACE FUNCTION function_returns( NAME, NAME, TEXT, TEXT ) 1982 | RETURNS TEXT AS $$ 1983 | SELECT _func_compare($1, $2, _returns($1, $2), $3, $4 ); 1984 | $$ LANGUAGE SQL; 1985 | 1986 | -- function_returns( schema, function, type ) 1987 | CREATE OR REPLACE FUNCTION function_returns( NAME, NAME, TEXT ) 1988 | RETURNS TEXT AS $$ 1989 | SELECT function_returns( 1990 | $1, $2, $3, 1991 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) 1992 | || '() should return ' || $3 1993 | ); 1994 | $$ LANGUAGE SQL; 1995 | 1996 | -- function_returns( function, args[], type, description ) 1997 | CREATE OR REPLACE FUNCTION function_returns( NAME, NAME[], TEXT, TEXT ) 1998 | RETURNS TEXT AS $$ 1999 | SELECT _func_compare(NULL, $1, $2, _returns($1, $2), $3, $4 ); 2000 | $$ LANGUAGE SQL; 2001 | 2002 | -- function_returns( function, args[], type ) 2003 | CREATE OR REPLACE FUNCTION function_returns( NAME, NAME[], TEXT ) 2004 | RETURNS TEXT AS $$ 2005 | SELECT function_returns( 2006 | $1, $2, $3, 2007 | 'Function ' || quote_ident($1) || '(' || 2008 | array_to_string($2, ', ') || ') should return ' || $3 2009 | ); 2010 | $$ LANGUAGE SQL; 2011 | 2012 | -- function_returns( function, type, description ) 2013 | CREATE OR REPLACE FUNCTION function_returns( NAME, TEXT, TEXT ) 2014 | RETURNS TEXT AS $$ 2015 | SELECT _func_compare(NULL, $1, _returns($1), $2, $3 ); 2016 | $$ LANGUAGE SQL; 2017 | 2018 | -- function_returns( function, type ) 2019 | CREATE OR REPLACE FUNCTION function_returns( NAME, TEXT ) 2020 | RETURNS TEXT AS $$ 2021 | SELECT function_returns( 2022 | $1, $2, 2023 | 'Function ' || quote_ident($1) || '() should return ' || $2 2024 | ); 2025 | $$ LANGUAGE SQL; 2026 | 2027 | CREATE OR REPLACE FUNCTION _definer ( NAME, NAME, NAME[] ) 2028 | RETURNS BOOLEAN AS $$ 2029 | SELECT is_definer 2030 | FROM tap_funky 2031 | WHERE schema = $1 2032 | AND name = $2 2033 | AND args = array_to_string($3, ',') 2034 | $$ LANGUAGE SQL; 2035 | 2036 | CREATE OR REPLACE FUNCTION _definer ( NAME, NAME ) 2037 | RETURNS BOOLEAN AS $$ 2038 | SELECT is_definer FROM tap_funky WHERE schema = $1 AND name = $2 2039 | $$ LANGUAGE SQL; 2040 | 2041 | CREATE OR REPLACE FUNCTION _definer ( NAME, NAME[] ) 2042 | RETURNS BOOLEAN AS $$ 2043 | SELECT is_definer 2044 | FROM tap_funky 2045 | WHERE name = $1 2046 | AND args = array_to_string($2, ',') 2047 | AND is_visible; 2048 | $$ LANGUAGE SQL; 2049 | 2050 | CREATE OR REPLACE FUNCTION _definer ( NAME ) 2051 | RETURNS BOOLEAN AS $$ 2052 | SELECT is_definer FROM tap_funky WHERE name = $1 AND is_visible; 2053 | $$ LANGUAGE SQL; 2054 | 2055 | -- is_definer( schema, function, args[], description ) 2056 | CREATE OR REPLACE FUNCTION is_definer ( NAME, NAME, NAME[], TEXT ) 2057 | RETURNS TEXT AS $$ 2058 | SELECT _func_compare($1, $2, $3, _definer($1, $2, $3), $4 ); 2059 | $$ LANGUAGE SQL; 2060 | 2061 | -- is_definer( schema, function, args[] ) 2062 | CREATE OR REPLACE FUNCTION is_definer( NAME, NAME, NAME[] ) 2063 | RETURNS TEXT AS $$ 2064 | SELECT ok( 2065 | _definer($1, $2, $3), 2066 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 2067 | array_to_string($3, ', ') || ') should be security definer' 2068 | ); 2069 | $$ LANGUAGE sql; 2070 | 2071 | -- is_definer( schema, function, description ) 2072 | CREATE OR REPLACE FUNCTION is_definer ( NAME, NAME, TEXT ) 2073 | RETURNS TEXT AS $$ 2074 | SELECT _func_compare($1, $2, _definer($1, $2), $3 ); 2075 | $$ LANGUAGE SQL; 2076 | 2077 | -- is_definer( schema, function ) 2078 | CREATE OR REPLACE FUNCTION is_definer( NAME, NAME ) 2079 | RETURNS TEXT AS $$ 2080 | SELECT ok( 2081 | _definer($1, $2), 2082 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '() should be security definer' 2083 | ); 2084 | $$ LANGUAGE sql; 2085 | 2086 | -- is_definer( function, args[], description ) 2087 | CREATE OR REPLACE FUNCTION is_definer ( NAME, NAME[], TEXT ) 2088 | RETURNS TEXT AS $$ 2089 | SELECT _func_compare(NULL, $1, $2, _definer($1, $2), $3 ); 2090 | $$ LANGUAGE SQL; 2091 | 2092 | -- is_definer( function, args[] ) 2093 | CREATE OR REPLACE FUNCTION is_definer( NAME, NAME[] ) 2094 | RETURNS TEXT AS $$ 2095 | SELECT ok( 2096 | _definer($1, $2), 2097 | 'Function ' || quote_ident($1) || '(' || 2098 | array_to_string($2, ', ') || ') should be security definer' 2099 | ); 2100 | $$ LANGUAGE sql; 2101 | 2102 | -- is_definer( function, description ) 2103 | CREATE OR REPLACE FUNCTION is_definer( NAME, TEXT ) 2104 | RETURNS TEXT AS $$ 2105 | SELECT _func_compare(NULL, $1, _definer($1), $2 ); 2106 | $$ LANGUAGE sql; 2107 | 2108 | -- is_definer( function ) 2109 | CREATE OR REPLACE FUNCTION is_definer( NAME ) 2110 | RETURNS TEXT AS $$ 2111 | SELECT ok( _definer($1), 'Function ' || quote_ident($1) || '() should be security definer' ); 2112 | $$ LANGUAGE sql; 2113 | 2114 | CREATE OR REPLACE FUNCTION _agg ( NAME, NAME, NAME[] ) 2115 | RETURNS BOOLEAN AS $$ 2116 | SELECT is_agg 2117 | FROM tap_funky 2118 | WHERE schema = $1 2119 | AND name = $2 2120 | AND args = array_to_string($3, ',') 2121 | $$ LANGUAGE SQL; 2122 | 2123 | CREATE OR REPLACE FUNCTION _agg ( NAME, NAME ) 2124 | RETURNS BOOLEAN AS $$ 2125 | SELECT is_agg FROM tap_funky WHERE schema = $1 AND name = $2 2126 | $$ LANGUAGE SQL; 2127 | 2128 | CREATE OR REPLACE FUNCTION _agg ( NAME, NAME[] ) 2129 | RETURNS BOOLEAN AS $$ 2130 | SELECT is_agg 2131 | FROM tap_funky 2132 | WHERE name = $1 2133 | AND args = array_to_string($2, ',') 2134 | AND is_visible; 2135 | $$ LANGUAGE SQL; 2136 | 2137 | CREATE OR REPLACE FUNCTION _agg ( NAME ) 2138 | RETURNS BOOLEAN AS $$ 2139 | SELECT is_agg FROM tap_funky WHERE name = $1 AND is_visible; 2140 | $$ LANGUAGE SQL; 2141 | 2142 | -- is_aggregate( schema, function, args[], description ) 2143 | CREATE OR REPLACE FUNCTION is_aggregate ( NAME, NAME, NAME[], TEXT ) 2144 | RETURNS TEXT AS $$ 2145 | SELECT _func_compare($1, $2, $3, _agg($1, $2, $3), $4 ); 2146 | $$ LANGUAGE SQL; 2147 | 2148 | -- is_aggregate( schema, function, args[] ) 2149 | CREATE OR REPLACE FUNCTION is_aggregate( NAME, NAME, NAME[] ) 2150 | RETURNS TEXT AS $$ 2151 | SELECT ok( 2152 | _agg($1, $2, $3), 2153 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 2154 | array_to_string($3, ', ') || ') should be an aggregate function' 2155 | ); 2156 | $$ LANGUAGE sql; 2157 | 2158 | -- is_aggregate( schema, function, description ) 2159 | CREATE OR REPLACE FUNCTION is_aggregate ( NAME, NAME, TEXT ) 2160 | RETURNS TEXT AS $$ 2161 | SELECT _func_compare($1, $2, _agg($1, $2), $3 ); 2162 | $$ LANGUAGE SQL; 2163 | 2164 | -- is_aggregate( schema, function ) 2165 | CREATE OR REPLACE FUNCTION is_aggregate( NAME, NAME ) 2166 | RETURNS TEXT AS $$ 2167 | SELECT ok( 2168 | _agg($1, $2), 2169 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '() should be an aggregate function' 2170 | ); 2171 | $$ LANGUAGE sql; 2172 | 2173 | -- is_aggregate( function, args[], description ) 2174 | CREATE OR REPLACE FUNCTION is_aggregate ( NAME, NAME[], TEXT ) 2175 | RETURNS TEXT AS $$ 2176 | SELECT _func_compare(NULL, $1, $2, _agg($1, $2), $3 ); 2177 | $$ LANGUAGE SQL; 2178 | 2179 | -- is_aggregate( function, args[] ) 2180 | CREATE OR REPLACE FUNCTION is_aggregate( NAME, NAME[] ) 2181 | RETURNS TEXT AS $$ 2182 | SELECT ok( 2183 | _agg($1, $2), 2184 | 'Function ' || quote_ident($1) || '(' || 2185 | array_to_string($2, ', ') || ') should be an aggregate function' 2186 | ); 2187 | $$ LANGUAGE sql; 2188 | 2189 | -- is_aggregate( function, description ) 2190 | CREATE OR REPLACE FUNCTION is_aggregate( NAME, TEXT ) 2191 | RETURNS TEXT AS $$ 2192 | SELECT _func_compare(NULL, $1, _agg($1), $2 ); 2193 | $$ LANGUAGE sql; 2194 | 2195 | -- is_aggregate( function ) 2196 | CREATE OR REPLACE FUNCTION is_aggregate( NAME ) 2197 | RETURNS TEXT AS $$ 2198 | SELECT ok( _agg($1), 'Function ' || quote_ident($1) || '() should be an aggregate function' ); 2199 | $$ LANGUAGE sql; 2200 | 2201 | CREATE OR REPLACE FUNCTION _strict ( NAME, NAME, NAME[] ) 2202 | RETURNS BOOLEAN AS $$ 2203 | SELECT is_strict 2204 | FROM tap_funky 2205 | WHERE schema = $1 2206 | AND name = $2 2207 | AND args = array_to_string($3, ',') 2208 | $$ LANGUAGE SQL; 2209 | 2210 | CREATE OR REPLACE FUNCTION _strict ( NAME, NAME ) 2211 | RETURNS BOOLEAN AS $$ 2212 | SELECT is_strict FROM tap_funky WHERE schema = $1 AND name = $2 2213 | $$ LANGUAGE SQL; 2214 | 2215 | CREATE OR REPLACE FUNCTION _strict ( NAME, NAME[] ) 2216 | RETURNS BOOLEAN AS $$ 2217 | SELECT is_strict 2218 | FROM tap_funky 2219 | WHERE name = $1 2220 | AND args = array_to_string($2, ',') 2221 | AND is_visible; 2222 | $$ LANGUAGE SQL; 2223 | 2224 | CREATE OR REPLACE FUNCTION _strict ( NAME ) 2225 | RETURNS BOOLEAN AS $$ 2226 | SELECT is_strict FROM tap_funky WHERE name = $1 AND is_visible; 2227 | $$ LANGUAGE SQL; 2228 | 2229 | -- is_strict( schema, function, args[], description ) 2230 | CREATE OR REPLACE FUNCTION is_strict ( NAME, NAME, NAME[], TEXT ) 2231 | RETURNS TEXT AS $$ 2232 | SELECT _func_compare($1, $2, $3, _strict($1, $2, $3), $4 ); 2233 | $$ LANGUAGE SQL; 2234 | 2235 | -- is_strict( schema, function, args[] ) 2236 | CREATE OR REPLACE FUNCTION is_strict( NAME, NAME, NAME[] ) 2237 | RETURNS TEXT AS $$ 2238 | SELECT ok( 2239 | _strict($1, $2, $3), 2240 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 2241 | array_to_string($3, ', ') || ') should be strict' 2242 | ); 2243 | $$ LANGUAGE sql; 2244 | 2245 | -- is_strict( schema, function, description ) 2246 | CREATE OR REPLACE FUNCTION is_strict ( NAME, NAME, TEXT ) 2247 | RETURNS TEXT AS $$ 2248 | SELECT _func_compare($1, $2, _strict($1, $2), $3 ); 2249 | $$ LANGUAGE SQL; 2250 | 2251 | -- is_strict( schema, function ) 2252 | CREATE OR REPLACE FUNCTION is_strict( NAME, NAME ) 2253 | RETURNS TEXT AS $$ 2254 | SELECT ok( 2255 | _strict($1, $2), 2256 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '() should be strict' 2257 | ); 2258 | $$ LANGUAGE sql; 2259 | 2260 | -- is_strict( function, args[], description ) 2261 | CREATE OR REPLACE FUNCTION is_strict ( NAME, NAME[], TEXT ) 2262 | RETURNS TEXT AS $$ 2263 | SELECT _func_compare(NULL, $1, $2, _strict($1, $2), $3 ); 2264 | $$ LANGUAGE SQL; 2265 | 2266 | -- is_strict( function, args[] ) 2267 | CREATE OR REPLACE FUNCTION is_strict( NAME, NAME[] ) 2268 | RETURNS TEXT AS $$ 2269 | SELECT ok( 2270 | _strict($1, $2), 2271 | 'Function ' || quote_ident($1) || '(' || 2272 | array_to_string($2, ', ') || ') should be strict' 2273 | ); 2274 | $$ LANGUAGE sql; 2275 | 2276 | -- is_strict( function, description ) 2277 | CREATE OR REPLACE FUNCTION is_strict( NAME, TEXT ) 2278 | RETURNS TEXT AS $$ 2279 | SELECT _func_compare(NULL, $1, _strict($1), $2 ); 2280 | $$ LANGUAGE sql; 2281 | 2282 | -- is_strict( function ) 2283 | CREATE OR REPLACE FUNCTION is_strict( NAME ) 2284 | RETURNS TEXT AS $$ 2285 | SELECT ok( _strict($1), 'Function ' || quote_ident($1) || '() should be strict' ); 2286 | $$ LANGUAGE sql; 2287 | 2288 | CREATE OR REPLACE FUNCTION _expand_vol( char ) 2289 | RETURNS TEXT AS $$ 2290 | SELECT CASE $1 2291 | WHEN 'i' THEN 'IMMUTABLE' 2292 | WHEN 's' THEN 'STABLE' 2293 | WHEN 'v' THEN 'VOLATILE' 2294 | ELSE 'UNKNOWN' END 2295 | $$ LANGUAGE SQL IMMUTABLE; 2296 | 2297 | CREATE OR REPLACE FUNCTION _refine_vol( text ) 2298 | RETURNS text AS $$ 2299 | SELECT _expand_vol(substring(LOWER($1) FROM 1 FOR 1)::char); 2300 | $$ LANGUAGE SQL IMMUTABLE; 2301 | 2302 | CREATE OR REPLACE FUNCTION _vol ( NAME, NAME, NAME[] ) 2303 | RETURNS TEXT AS $$ 2304 | SELECT _expand_vol(volatility) 2305 | FROM tap_funky f 2306 | WHERE f.schema = $1 2307 | and f.name = $2 2308 | AND f.args = array_to_string($3, ',') 2309 | $$ LANGUAGE SQL; 2310 | 2311 | CREATE OR REPLACE FUNCTION _vol ( NAME, NAME ) 2312 | RETURNS TEXT AS $$ 2313 | SELECT _expand_vol(volatility) FROM tap_funky f 2314 | WHERE f.schema = $1 and f.name = $2 2315 | $$ LANGUAGE SQL; 2316 | 2317 | CREATE OR REPLACE FUNCTION _vol ( NAME, NAME[] ) 2318 | RETURNS TEXT AS $$ 2319 | SELECT _expand_vol(volatility) 2320 | FROM tap_funky f 2321 | WHERE f.name = $1 2322 | AND f.args = array_to_string($2, ',') 2323 | AND f.is_visible; 2324 | $$ LANGUAGE SQL; 2325 | 2326 | CREATE OR REPLACE FUNCTION _vol ( NAME ) 2327 | RETURNS TEXT AS $$ 2328 | SELECT _expand_vol(volatility) FROM tap_funky f 2329 | WHERE f.name = $1 AND f.is_visible; 2330 | $$ LANGUAGE SQL; 2331 | 2332 | -- volatility_is( schema, function, args[], volatility, description ) 2333 | CREATE OR REPLACE FUNCTION volatility_is( NAME, NAME, NAME[], TEXT, TEXT ) 2334 | RETURNS TEXT AS $$ 2335 | SELECT _func_compare($1, $2, $3, _vol($1, $2, $3), _refine_vol($4), $5 ); 2336 | $$ LANGUAGE SQL; 2337 | 2338 | -- volatility_is( schema, function, args[], volatility ) 2339 | CREATE OR REPLACE FUNCTION volatility_is( NAME, NAME, NAME[], TEXT ) 2340 | RETURNS TEXT AS $$ 2341 | SELECT volatility_is( 2342 | $1, $2, $3, $4, 2343 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) || '(' || 2344 | array_to_string($3, ', ') || ') should be ' || _refine_vol($4) 2345 | ); 2346 | $$ LANGUAGE SQL; 2347 | 2348 | -- volatility_is( schema, function, volatility, description ) 2349 | CREATE OR REPLACE FUNCTION volatility_is( NAME, NAME, TEXT, TEXT ) 2350 | RETURNS TEXT AS $$ 2351 | SELECT _func_compare($1, $2, _vol($1, $2), _refine_vol($3), $4 ); 2352 | $$ LANGUAGE SQL; 2353 | 2354 | -- volatility_is( schema, function, volatility ) 2355 | CREATE OR REPLACE FUNCTION volatility_is( NAME, NAME, TEXT ) 2356 | RETURNS TEXT AS $$ 2357 | SELECT volatility_is( 2358 | $1, $2, $3, 2359 | 'Function ' || quote_ident($1) || '.' || quote_ident($2) 2360 | || '() should be ' || _refine_vol($3) 2361 | ); 2362 | $$ LANGUAGE SQL; 2363 | 2364 | -- volatility_is( function, args[], volatility, description ) 2365 | CREATE OR REPLACE FUNCTION volatility_is( NAME, NAME[], TEXT, TEXT ) 2366 | RETURNS TEXT AS $$ 2367 | SELECT _func_compare(NULL, $1, $2, _vol($1, $2), _refine_vol($3), $4 ); 2368 | $$ LANGUAGE SQL; 2369 | 2370 | -- volatility_is( function, args[], volatility ) 2371 | CREATE OR REPLACE FUNCTION volatility_is( NAME, NAME[], TEXT ) 2372 | RETURNS TEXT AS $$ 2373 | SELECT volatility_is( 2374 | $1, $2, $3, 2375 | 'Function ' || quote_ident($1) || '(' || 2376 | array_to_string($2, ', ') || ') should be ' || _refine_vol($3) 2377 | ); 2378 | $$ LANGUAGE SQL; 2379 | 2380 | -- volatility_is( function, volatility, description ) 2381 | CREATE OR REPLACE FUNCTION volatility_is( NAME, TEXT, TEXT ) 2382 | RETURNS TEXT AS $$ 2383 | SELECT _func_compare(NULL, $1, _vol($1), _refine_vol($2), $3 ); 2384 | $$ LANGUAGE SQL; 2385 | 2386 | -- volatility_is( function, volatility ) 2387 | CREATE OR REPLACE FUNCTION volatility_is( NAME, TEXT ) 2388 | RETURNS TEXT AS $$ 2389 | SELECT volatility_is( 2390 | $1, $2, 2391 | 'Function ' || quote_ident($1) || '() should be ' || _refine_vol($2) 2392 | ); 2393 | $$ LANGUAGE SQL; 2394 | 2395 | -- check_test( test_output, pass, name, description, diag, match_diag ) 2396 | CREATE OR REPLACE FUNCTION findfuncs( NAME, TEXT ) 2397 | RETURNS TEXT[] AS $$ 2398 | SELECT ARRAY( 2399 | SELECT DISTINCT quote_ident(n.nspname) || '.' || quote_ident(p.proname) AS pname 2400 | FROM pg_catalog.pg_proc p 2401 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 2402 | WHERE n.nspname = $1 2403 | AND p.proname ~ $2 2404 | ORDER BY pname 2405 | ); 2406 | $$ LANGUAGE sql; 2407 | 2408 | CREATE OR REPLACE FUNCTION findfuncs( TEXT ) 2409 | RETURNS TEXT[] AS $$ 2410 | SELECT ARRAY( 2411 | SELECT DISTINCT quote_ident(n.nspname) || '.' || quote_ident(p.proname) AS pname 2412 | FROM pg_catalog.pg_proc p 2413 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 2414 | WHERE pg_catalog.pg_function_is_visible(p.oid) 2415 | AND p.proname ~ $1 2416 | ORDER BY pname 2417 | ); 2418 | $$ LANGUAGE sql; 2419 | 2420 | CREATE OR REPLACE FUNCTION _runem( text[], boolean ) 2421 | RETURNS SETOF TEXT AS $$ 2422 | DECLARE 2423 | tap text; 2424 | lbound int := array_lower($1, 1); 2425 | BEGIN 2426 | IF lbound IS NULL THEN RETURN; END IF; 2427 | FOR i IN lbound..array_upper($1, 1) LOOP 2428 | -- Send the name of the function to diag if warranted. 2429 | IF $2 THEN RETURN NEXT diag( $1[i] || '()' ); END IF; 2430 | -- Execute the tap function and return its results. 2431 | FOR tap IN EXECUTE 'SELECT * FROM ' || $1[i] || '()' LOOP 2432 | RETURN NEXT tap; 2433 | END LOOP; 2434 | END LOOP; 2435 | RETURN; 2436 | END; 2437 | $$ LANGUAGE plpgsql; 2438 | 2439 | CREATE OR REPLACE FUNCTION _is_verbose() 2440 | RETURNS BOOLEAN AS $$ 2441 | SELECT current_setting('client_min_messages') NOT IN ( 2442 | 'warning', 'error', 'fatal', 'panic' 2443 | ); 2444 | $$ LANGUAGE sql STABLE; 2445 | 2446 | -- do_tap( schema, pattern ) 2447 | CREATE OR REPLACE FUNCTION do_tap( name, text ) 2448 | RETURNS SETOF TEXT AS $$ 2449 | SELECT * FROM _runem( findfuncs($1, $2), _is_verbose() ); 2450 | $$ LANGUAGE sql; 2451 | 2452 | -- do_tap( schema ) 2453 | CREATE OR REPLACE FUNCTION do_tap( name ) 2454 | RETURNS SETOF TEXT AS $$ 2455 | SELECT * FROM _runem( findfuncs($1, '^test'), _is_verbose() ); 2456 | $$ LANGUAGE sql; 2457 | 2458 | -- do_tap( pattern ) 2459 | CREATE OR REPLACE FUNCTION do_tap( text ) 2460 | RETURNS SETOF TEXT AS $$ 2461 | SELECT * FROM _runem( findfuncs($1), _is_verbose() ); 2462 | $$ LANGUAGE sql; 2463 | 2464 | -- do_tap() 2465 | CREATE OR REPLACE FUNCTION do_tap( ) 2466 | RETURNS SETOF TEXT AS $$ 2467 | SELECT * FROM _runem( findfuncs('^test'), _is_verbose()); 2468 | $$ LANGUAGE sql; 2469 | 2470 | CREATE OR REPLACE FUNCTION _currtest() 2471 | RETURNS INTEGER AS $$ 2472 | BEGIN 2473 | RETURN currval('__tresults___numb_seq'); 2474 | EXCEPTION 2475 | WHEN object_not_in_prerequisite_state THEN RETURN 0; 2476 | END; 2477 | $$ LANGUAGE plpgsql; 2478 | 2479 | CREATE OR REPLACE FUNCTION _cleanup() 2480 | RETURNS boolean AS $$ 2481 | DROP TABLE __tresults__; 2482 | DROP SEQUENCE __tresults___numb_seq; 2483 | DROP TABLE __tcache__; 2484 | DROP SEQUENCE __tcache___id_seq; 2485 | SELECT TRUE; 2486 | $$ LANGUAGE sql; 2487 | 2488 | CREATE OR REPLACE FUNCTION _runner( text[], text[], text[], text[], text[] ) 2489 | RETURNS SETOF TEXT AS $$ 2490 | DECLARE 2491 | startup ALIAS FOR $1; 2492 | shutdown ALIAS FOR $2; 2493 | setup ALIAS FOR $3; 2494 | teardown ALIAS FOR $4; 2495 | tests ALIAS FOR $5; 2496 | tap text; 2497 | verbos boolean := _is_verbose(); -- verbose is a reserved word in 8.5. 2498 | num_faild INTEGER := 0; 2499 | BEGIN 2500 | BEGIN 2501 | -- No plan support. 2502 | PERFORM * FROM no_plan(); 2503 | FOR tap IN SELECT * FROM _runem(startup, false) LOOP RETURN NEXT tap; END LOOP; 2504 | EXCEPTION 2505 | -- Catch all exceptions and simply rethrow custom exceptions. This 2506 | -- will roll back everything in the above block. 2507 | WHEN raise_exception THEN 2508 | RAISE EXCEPTION '%', SQLERRM; 2509 | END; 2510 | 2511 | BEGIN 2512 | FOR i IN 1..array_upper(tests, 1) LOOP 2513 | BEGIN 2514 | -- What test are we running? 2515 | IF verbos THEN RETURN NEXT diag(tests[i] || '()'); END IF; 2516 | 2517 | -- Run the setup functions. 2518 | FOR tap IN SELECT * FROM _runem(setup, false) LOOP RETURN NEXT tap; END LOOP; 2519 | 2520 | -- Run the actual test function. 2521 | FOR tap IN EXECUTE 'SELECT * FROM ' || tests[i] || '()' LOOP 2522 | RETURN NEXT tap; 2523 | END LOOP; 2524 | 2525 | -- Run the teardown functions. 2526 | FOR tap IN SELECT * FROM _runem(teardown, false) LOOP RETURN NEXT tap; END LOOP; 2527 | 2528 | -- Remember how many failed and then roll back. 2529 | num_faild := num_faild + num_failed(); 2530 | RAISE EXCEPTION '__TAP_ROLLBACK__'; 2531 | 2532 | EXCEPTION WHEN raise_exception THEN 2533 | IF SQLERRM <> '__TAP_ROLLBACK__' THEN 2534 | -- We didn't raise it, so propagate it. 2535 | RAISE EXCEPTION '%', SQLERRM; 2536 | END IF; 2537 | END; 2538 | END LOOP; 2539 | 2540 | -- Run the shutdown functions. 2541 | FOR tap IN SELECT * FROM _runem(shutdown, false) LOOP RETURN NEXT tap; END LOOP; 2542 | 2543 | -- Raise an exception to rollback any changes. 2544 | RAISE EXCEPTION '__TAP_ROLLBACK__'; 2545 | EXCEPTION WHEN raise_exception THEN 2546 | IF SQLERRM <> '__TAP_ROLLBACK__' THEN 2547 | -- We didn't raise it, so propagate it. 2548 | RAISE EXCEPTION '%', SQLERRM; 2549 | END IF; 2550 | END; 2551 | -- Finish up. 2552 | FOR tap IN SELECT * FROM _finish( currval('__tresults___numb_seq')::integer, 0, num_faild ) LOOP 2553 | RETURN NEXT tap; 2554 | END LOOP; 2555 | 2556 | -- Clean up and return. 2557 | PERFORM _cleanup(); 2558 | RETURN; 2559 | END; 2560 | $$ LANGUAGE plpgsql; 2561 | 2562 | -- runtests( schema, match ) 2563 | CREATE OR REPLACE FUNCTION runtests( NAME, TEXT ) 2564 | RETURNS SETOF TEXT AS $$ 2565 | SELECT * FROM _runner( 2566 | findfuncs( $1, '^startup' ), 2567 | findfuncs( $1, '^shutdown' ), 2568 | findfuncs( $1, '^setup' ), 2569 | findfuncs( $1, '^teardown' ), 2570 | findfuncs( $1, $2 ) 2571 | ); 2572 | $$ LANGUAGE sql; 2573 | 2574 | -- runtests( schema ) 2575 | CREATE OR REPLACE FUNCTION runtests( NAME ) 2576 | RETURNS SETOF TEXT AS $$ 2577 | SELECT * FROM runtests( $1, '^test' ); 2578 | $$ LANGUAGE sql; 2579 | 2580 | -- runtests( match ) 2581 | CREATE OR REPLACE FUNCTION runtests( TEXT ) 2582 | RETURNS SETOF TEXT AS $$ 2583 | SELECT * FROM _runner( 2584 | findfuncs( '^startup' ), 2585 | findfuncs( '^shutdown' ), 2586 | findfuncs( '^setup' ), 2587 | findfuncs( '^teardown' ), 2588 | findfuncs( $1 ) 2589 | ); 2590 | $$ LANGUAGE sql; 2591 | 2592 | -- runtests( ) 2593 | CREATE OR REPLACE FUNCTION runtests( ) 2594 | RETURNS SETOF TEXT AS $$ 2595 | SELECT * FROM runtests( '^test' ); 2596 | $$ LANGUAGE sql; 2597 | 2598 | CREATE OR REPLACE FUNCTION _temptable ( TEXT, TEXT ) 2599 | RETURNS TEXT AS $$ 2600 | BEGIN 2601 | EXECUTE 'CREATE TEMP TABLE ' || $2 || ' AS ' || _query($1); 2602 | return $2; 2603 | END; 2604 | $$ LANGUAGE plpgsql; 2605 | 2606 | CREATE OR REPLACE FUNCTION _temptable ( anyarray, TEXT ) 2607 | RETURNS TEXT AS $$ 2608 | BEGIN 2609 | CREATE TEMP TABLE _____coltmp___ AS 2610 | SELECT $1[i] 2611 | FROM generate_series(array_lower($1, 1), array_upper($1, 1)) s(i); 2612 | EXECUTE 'ALTER TABLE _____coltmp___ RENAME TO ' || $2; 2613 | return $2; 2614 | END; 2615 | $$ LANGUAGE plpgsql; 2616 | 2617 | CREATE OR REPLACE FUNCTION _temptypes( TEXT ) 2618 | RETURNS TEXT AS $$ 2619 | SELECT array_to_string(ARRAY( 2620 | SELECT pg_catalog.format_type(a.atttypid, a.atttypmod) 2621 | FROM pg_catalog.pg_attribute a 2622 | JOIN pg_catalog.pg_class c ON a.attrelid = c.oid 2623 | JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid 2624 | WHERE c.relname = $1 2625 | AND n.nspname LIKE 'pg_temp%' 2626 | AND attnum > 0 2627 | AND NOT attisdropped 2628 | ORDER BY attnum 2629 | ), ','); 2630 | $$ LANGUAGE sql; 2631 | 2632 | CREATE OR REPLACE FUNCTION _docomp( TEXT, TEXT, TEXT, TEXT ) 2633 | RETURNS TEXT AS $$ 2634 | DECLARE 2635 | have ALIAS FOR $1; 2636 | want ALIAS FOR $2; 2637 | extras TEXT[] := '{}'; 2638 | missing TEXT[] := '{}'; 2639 | res BOOLEAN := TRUE; 2640 | msg TEXT := ''; 2641 | rec RECORD; 2642 | BEGIN 2643 | BEGIN 2644 | -- Find extra records. 2645 | FOR rec in EXECUTE 'SELECT * FROM ' || have || ' EXCEPT ' || $4 2646 | || 'SELECT * FROM ' || want LOOP 2647 | extras := extras || rec::text; 2648 | END LOOP; 2649 | 2650 | -- Find missing records. 2651 | FOR rec in EXECUTE 'SELECT * FROM ' || want || ' EXCEPT ' || $4 2652 | || 'SELECT * FROM ' || have LOOP 2653 | missing := missing || rec::text; 2654 | END LOOP; 2655 | 2656 | -- Drop the temporary tables. 2657 | EXECUTE 'DROP TABLE ' || have; 2658 | EXECUTE 'DROP TABLE ' || want; 2659 | EXCEPTION WHEN syntax_error OR datatype_mismatch THEN 2660 | msg := E'\n' || diag( 2661 | E' Columns differ between queries:\n' 2662 | || ' have: (' || _temptypes(have) || E')\n' 2663 | || ' want: (' || _temptypes(want) || ')' 2664 | ); 2665 | EXECUTE 'DROP TABLE ' || have; 2666 | EXECUTE 'DROP TABLE ' || want; 2667 | RETURN ok(FALSE, $3) || msg; 2668 | END; 2669 | 2670 | -- What extra records do we have? 2671 | IF extras[1] IS NOT NULL THEN 2672 | res := FALSE; 2673 | msg := E'\n' || diag( 2674 | E' Extra records:\n ' 2675 | || array_to_string( extras, E'\n ' ) 2676 | ); 2677 | END IF; 2678 | 2679 | -- What missing records do we have? 2680 | IF missing[1] IS NOT NULL THEN 2681 | res := FALSE; 2682 | msg := msg || E'\n' || diag( 2683 | E' Missing records:\n ' 2684 | || array_to_string( missing, E'\n ' ) 2685 | ); 2686 | END IF; 2687 | 2688 | RETURN ok(res, $3) || msg; 2689 | END; 2690 | $$ LANGUAGE plpgsql; 2691 | 2692 | CREATE OR REPLACE FUNCTION _relcomp( TEXT, TEXT, TEXT, TEXT ) 2693 | RETURNS TEXT AS $$ 2694 | SELECT _docomp( 2695 | _temptable( $1, '__taphave__' ), 2696 | _temptable( $2, '__tapwant__' ), 2697 | $3, $4 2698 | ); 2699 | $$ LANGUAGE sql; 2700 | 2701 | CREATE OR REPLACE FUNCTION _relcomp( TEXT, anyarray, TEXT, TEXT ) 2702 | RETURNS TEXT AS $$ 2703 | SELECT _docomp( 2704 | _temptable( $1, '__taphave__' ), 2705 | _temptable( $2, '__tapwant__' ), 2706 | $3, $4 2707 | ); 2708 | $$ LANGUAGE sql; 2709 | 2710 | -- set_eq( sql, sql, description ) 2711 | CREATE OR REPLACE FUNCTION set_eq( TEXT, TEXT, TEXT ) 2712 | RETURNS TEXT AS $$ 2713 | SELECT _relcomp( $1, $2, $3, '' ); 2714 | $$ LANGUAGE sql; 2715 | 2716 | -- set_eq( sql, sql ) 2717 | CREATE OR REPLACE FUNCTION set_eq( TEXT, TEXT ) 2718 | RETURNS TEXT AS $$ 2719 | SELECT _relcomp( $1, $2, NULL::text, '' ); 2720 | $$ LANGUAGE sql; 2721 | 2722 | -- set_eq( sql, array, description ) 2723 | CREATE OR REPLACE FUNCTION set_eq( TEXT, anyarray, TEXT ) 2724 | RETURNS TEXT AS $$ 2725 | SELECT _relcomp( $1, $2, $3, '' ); 2726 | $$ LANGUAGE sql; 2727 | 2728 | -- set_eq( sql, array ) 2729 | CREATE OR REPLACE FUNCTION set_eq( TEXT, anyarray ) 2730 | RETURNS TEXT AS $$ 2731 | SELECT _relcomp( $1, $2, NULL::text, '' ); 2732 | $$ LANGUAGE sql; 2733 | 2734 | -- bag_eq( sql, sql, description ) 2735 | CREATE OR REPLACE FUNCTION bag_eq( TEXT, TEXT, TEXT ) 2736 | RETURNS TEXT AS $$ 2737 | SELECT _relcomp( $1, $2, $3, 'ALL ' ); 2738 | $$ LANGUAGE sql; 2739 | 2740 | -- bag_eq( sql, sql ) 2741 | CREATE OR REPLACE FUNCTION bag_eq( TEXT, TEXT ) 2742 | RETURNS TEXT AS $$ 2743 | SELECT _relcomp( $1, $2, NULL::text, 'ALL ' ); 2744 | $$ LANGUAGE sql; 2745 | 2746 | -- bag_eq( sql, array, description ) 2747 | CREATE OR REPLACE FUNCTION bag_eq( TEXT, anyarray, TEXT ) 2748 | RETURNS TEXT AS $$ 2749 | SELECT _relcomp( $1, $2, $3, 'ALL ' ); 2750 | $$ LANGUAGE sql; 2751 | 2752 | -- bag_eq( sql, array ) 2753 | CREATE OR REPLACE FUNCTION bag_eq( TEXT, anyarray ) 2754 | RETURNS TEXT AS $$ 2755 | SELECT _relcomp( $1, $2, NULL::text, 'ALL ' ); 2756 | $$ LANGUAGE sql; 2757 | 2758 | CREATE OR REPLACE FUNCTION _do_ne( TEXT, TEXT, TEXT, TEXT ) 2759 | RETURNS TEXT AS $$ 2760 | DECLARE 2761 | have ALIAS FOR $1; 2762 | want ALIAS FOR $2; 2763 | extras TEXT[] := '{}'; 2764 | missing TEXT[] := '{}'; 2765 | res BOOLEAN := TRUE; 2766 | msg TEXT := ''; 2767 | BEGIN 2768 | BEGIN 2769 | -- Find extra records. 2770 | EXECUTE 'SELECT EXISTS ( ' 2771 | || '( SELECT * FROM ' || have || ' EXCEPT ' || $4 2772 | || ' SELECT * FROM ' || want 2773 | || ' ) UNION ( ' 2774 | || ' SELECT * FROM ' || want || ' EXCEPT ' || $4 2775 | || ' SELECT * FROM ' || have 2776 | || ' ) LIMIT 1 )' INTO res; 2777 | 2778 | -- Drop the temporary tables. 2779 | EXECUTE 'DROP TABLE ' || have; 2780 | EXECUTE 'DROP TABLE ' || want; 2781 | EXCEPTION WHEN syntax_error OR datatype_mismatch THEN 2782 | msg := E'\n' || diag( 2783 | E' Columns differ between queries:\n' 2784 | || ' have: (' || _temptypes(have) || E')\n' 2785 | || ' want: (' || _temptypes(want) || ')' 2786 | ); 2787 | EXECUTE 'DROP TABLE ' || have; 2788 | EXECUTE 'DROP TABLE ' || want; 2789 | RETURN ok(FALSE, $3) || msg; 2790 | END; 2791 | 2792 | -- Return the value from the query. 2793 | RETURN ok(res, $3); 2794 | END; 2795 | $$ LANGUAGE plpgsql; 2796 | 2797 | CREATE OR REPLACE FUNCTION _relne( TEXT, TEXT, TEXT, TEXT ) 2798 | RETURNS TEXT AS $$ 2799 | SELECT _do_ne( 2800 | _temptable( $1, '__taphave__' ), 2801 | _temptable( $2, '__tapwant__' ), 2802 | $3, $4 2803 | ); 2804 | $$ LANGUAGE sql; 2805 | 2806 | CREATE OR REPLACE FUNCTION _relne( TEXT, anyarray, TEXT, TEXT ) 2807 | RETURNS TEXT AS $$ 2808 | SELECT _do_ne( 2809 | _temptable( $1, '__taphave__' ), 2810 | _temptable( $2, '__tapwant__' ), 2811 | $3, $4 2812 | ); 2813 | $$ LANGUAGE sql; 2814 | 2815 | -- set_ne( sql, sql, description ) 2816 | CREATE OR REPLACE FUNCTION set_ne( TEXT, TEXT, TEXT ) 2817 | RETURNS TEXT AS $$ 2818 | SELECT _relne( $1, $2, $3, '' ); 2819 | $$ LANGUAGE sql; 2820 | 2821 | -- set_ne( sql, sql ) 2822 | CREATE OR REPLACE FUNCTION set_ne( TEXT, TEXT ) 2823 | RETURNS TEXT AS $$ 2824 | SELECT _relne( $1, $2, NULL::text, '' ); 2825 | $$ LANGUAGE sql; 2826 | 2827 | -- set_ne( sql, array, description ) 2828 | CREATE OR REPLACE FUNCTION set_ne( TEXT, anyarray, TEXT ) 2829 | RETURNS TEXT AS $$ 2830 | SELECT _relne( $1, $2, $3, '' ); 2831 | $$ LANGUAGE sql; 2832 | 2833 | -- set_ne( sql, array ) 2834 | CREATE OR REPLACE FUNCTION set_ne( TEXT, anyarray ) 2835 | RETURNS TEXT AS $$ 2836 | SELECT _relne( $1, $2, NULL::text, '' ); 2837 | $$ LANGUAGE sql; 2838 | 2839 | -- bag_ne( sql, sql, description ) 2840 | CREATE OR REPLACE FUNCTION bag_ne( TEXT, TEXT, TEXT ) 2841 | RETURNS TEXT AS $$ 2842 | SELECT _relne( $1, $2, $3, 'ALL ' ); 2843 | $$ LANGUAGE sql; 2844 | 2845 | -- bag_ne( sql, sql ) 2846 | CREATE OR REPLACE FUNCTION bag_ne( TEXT, TEXT ) 2847 | RETURNS TEXT AS $$ 2848 | SELECT _relne( $1, $2, NULL::text, 'ALL ' ); 2849 | $$ LANGUAGE sql; 2850 | 2851 | -- bag_ne( sql, array, description ) 2852 | CREATE OR REPLACE FUNCTION bag_ne( TEXT, anyarray, TEXT ) 2853 | RETURNS TEXT AS $$ 2854 | SELECT _relne( $1, $2, $3, 'ALL ' ); 2855 | $$ LANGUAGE sql; 2856 | 2857 | -- bag_ne( sql, array ) 2858 | CREATE OR REPLACE FUNCTION bag_ne( TEXT, anyarray ) 2859 | RETURNS TEXT AS $$ 2860 | SELECT _relne( $1, $2, NULL::text, 'ALL ' ); 2861 | $$ LANGUAGE sql; 2862 | 2863 | CREATE OR REPLACE FUNCTION _relcomp( TEXT, TEXT, TEXT, TEXT, TEXT ) 2864 | RETURNS TEXT AS $$ 2865 | DECLARE 2866 | have TEXT := _temptable( $1, '__taphave__' ); 2867 | want TEXT := _temptable( $2, '__tapwant__' ); 2868 | results TEXT[] := '{}'; 2869 | res BOOLEAN := TRUE; 2870 | msg TEXT := ''; 2871 | rec RECORD; 2872 | BEGIN 2873 | BEGIN 2874 | -- Find relevant records. 2875 | FOR rec in EXECUTE 'SELECT * FROM ' || want || ' ' || $4 2876 | || ' SELECT * FROM ' || have LOOP 2877 | results := results || rec::text; 2878 | END LOOP; 2879 | 2880 | -- Drop the temporary tables. 2881 | EXECUTE 'DROP TABLE ' || have; 2882 | EXECUTE 'DROP TABLE ' || want; 2883 | EXCEPTION WHEN syntax_error OR datatype_mismatch THEN 2884 | msg := E'\n' || diag( 2885 | E' Columns differ between queries:\n' 2886 | || ' have: (' || _temptypes(have) || E')\n' 2887 | || ' want: (' || _temptypes(want) || ')' 2888 | ); 2889 | EXECUTE 'DROP TABLE ' || have; 2890 | EXECUTE 'DROP TABLE ' || want; 2891 | RETURN ok(FALSE, $3) || msg; 2892 | END; 2893 | 2894 | -- What records do we have? 2895 | IF results[1] IS NOT NULL THEN 2896 | res := FALSE; 2897 | msg := msg || E'\n' || diag( 2898 | ' ' || $5 || E' records:\n ' 2899 | || array_to_string( results, E'\n ' ) 2900 | ); 2901 | END IF; 2902 | 2903 | RETURN ok(res, $3) || msg; 2904 | END; 2905 | $$ LANGUAGE plpgsql; 2906 | 2907 | -- set_has( sql, sql, description ) 2908 | CREATE OR REPLACE FUNCTION set_has( TEXT, TEXT, TEXT ) 2909 | RETURNS TEXT AS $$ 2910 | SELECT _relcomp( $1, $2, $3, 'EXCEPT', 'Missing' ); 2911 | $$ LANGUAGE sql; 2912 | 2913 | -- set_has( sql, sql ) 2914 | CREATE OR REPLACE FUNCTION set_has( TEXT, TEXT ) 2915 | RETURNS TEXT AS $$ 2916 | SELECT _relcomp( $1, $2, NULL::TEXT, 'EXCEPT', 'Missing' ); 2917 | $$ LANGUAGE sql; 2918 | 2919 | -- bag_has( sql, sql, description ) 2920 | CREATE OR REPLACE FUNCTION bag_has( TEXT, TEXT, TEXT ) 2921 | RETURNS TEXT AS $$ 2922 | SELECT _relcomp( $1, $2, $3, 'EXCEPT ALL', 'Missing' ); 2923 | $$ LANGUAGE sql; 2924 | 2925 | -- bag_has( sql, sql ) 2926 | CREATE OR REPLACE FUNCTION bag_has( TEXT, TEXT ) 2927 | RETURNS TEXT AS $$ 2928 | SELECT _relcomp( $1, $2, NULL::TEXT, 'EXCEPT ALL', 'Missing' ); 2929 | $$ LANGUAGE sql; 2930 | 2931 | -- set_hasnt( sql, sql, description ) 2932 | CREATE OR REPLACE FUNCTION set_hasnt( TEXT, TEXT, TEXT ) 2933 | RETURNS TEXT AS $$ 2934 | SELECT _relcomp( $1, $2, $3, 'INTERSECT', 'Extra' ); 2935 | $$ LANGUAGE sql; 2936 | 2937 | -- set_hasnt( sql, sql ) 2938 | CREATE OR REPLACE FUNCTION set_hasnt( TEXT, TEXT ) 2939 | RETURNS TEXT AS $$ 2940 | SELECT _relcomp( $1, $2, NULL::TEXT, 'INTERSECT', 'Extra' ); 2941 | $$ LANGUAGE sql; 2942 | 2943 | -- bag_hasnt( sql, sql, description ) 2944 | CREATE OR REPLACE FUNCTION bag_hasnt( TEXT, TEXT, TEXT ) 2945 | RETURNS TEXT AS $$ 2946 | SELECT _relcomp( $1, $2, $3, 'INTERSECT ALL', 'Extra' ); 2947 | $$ LANGUAGE sql; 2948 | 2949 | -- bag_hasnt( sql, sql ) 2950 | CREATE OR REPLACE FUNCTION bag_hasnt( TEXT, TEXT ) 2951 | RETURNS TEXT AS $$ 2952 | SELECT _relcomp( $1, $2, NULL::TEXT, 'INTERSECT ALL', 'Extra' ); 2953 | $$ LANGUAGE sql; 2954 | 2955 | -- results_eq( cursor, cursor, description ) 2956 | CREATE OR REPLACE FUNCTION results_eq( refcursor, refcursor, text ) 2957 | RETURNS TEXT AS $$ 2958 | DECLARE 2959 | have ALIAS FOR $1; 2960 | want ALIAS FOR $2; 2961 | have_rec RECORD; 2962 | want_rec RECORD; 2963 | have_found BOOLEAN; 2964 | want_found BOOLEAN; 2965 | rownum INTEGER := 1; 2966 | BEGIN 2967 | FETCH have INTO have_rec; 2968 | have_found := FOUND; 2969 | FETCH want INTO want_rec; 2970 | want_found := FOUND; 2971 | WHILE have_found OR want_found LOOP 2972 | IF have_rec::text IS DISTINCT FROM want_rec::text OR have_found <> want_found THEN 2973 | RETURN ok( false, $3 ) || E'\n' || diag( 2974 | ' Results differ beginning at row ' || rownum || E':\n' || 2975 | ' have: ' || CASE WHEN have_found THEN have_rec::text ELSE 'NULL' END || E'\n' || 2976 | ' want: ' || CASE WHEN want_found THEN want_rec::text ELSE 'NULL' END 2977 | ); 2978 | END IF; 2979 | rownum = rownum + 1; 2980 | FETCH have INTO have_rec; 2981 | have_found := FOUND; 2982 | FETCH want INTO want_rec; 2983 | want_found := FOUND; 2984 | END LOOP; 2985 | 2986 | RETURN ok( true, $3 ); 2987 | EXCEPTION 2988 | WHEN datatype_mismatch THEN 2989 | RETURN ok( false, $3 ) || E'\n' || diag( 2990 | E' Columns differ between queries:\n' || 2991 | ' have: ' || CASE WHEN have_found THEN have_rec::text ELSE 'NULL' END || E'\n' || 2992 | ' want: ' || CASE WHEN want_found THEN want_rec::text ELSE 'NULL' END 2993 | ); 2994 | END; 2995 | $$ LANGUAGE plpgsql; 2996 | 2997 | -- results_eq( cursor, cursor ) 2998 | CREATE OR REPLACE FUNCTION results_eq( refcursor, refcursor ) 2999 | RETURNS TEXT AS $$ 3000 | SELECT results_eq( $1, $2, NULL::text ); 3001 | $$ LANGUAGE sql; 3002 | 3003 | -- results_eq( sql, sql, description ) 3004 | CREATE OR REPLACE FUNCTION results_eq( TEXT, TEXT, TEXT ) 3005 | RETURNS TEXT AS $$ 3006 | DECLARE 3007 | have REFCURSOR; 3008 | want REFCURSOR; 3009 | res TEXT; 3010 | BEGIN 3011 | OPEN have FOR EXECUTE _query($1); 3012 | OPEN want FOR EXECUTE _query($2); 3013 | res := results_eq(have, want, $3); 3014 | CLOSE have; 3015 | CLOSE want; 3016 | RETURN res; 3017 | END; 3018 | $$ LANGUAGE plpgsql; 3019 | 3020 | -- results_eq( sql, sql ) 3021 | CREATE OR REPLACE FUNCTION results_eq( TEXT, TEXT ) 3022 | RETURNS TEXT AS $$ 3023 | SELECT results_eq( $1, $2, NULL::text ); 3024 | $$ LANGUAGE sql; 3025 | 3026 | -- results_eq( sql, array, description ) 3027 | CREATE OR REPLACE FUNCTION results_eq( TEXT, anyarray, TEXT ) 3028 | RETURNS TEXT AS $$ 3029 | DECLARE 3030 | have REFCURSOR; 3031 | want REFCURSOR; 3032 | res TEXT; 3033 | BEGIN 3034 | OPEN have FOR EXECUTE _query($1); 3035 | OPEN want FOR SELECT $2[i] 3036 | FROM generate_series(array_lower($2, 1), array_upper($2, 1)) s(i); 3037 | res := results_eq(have, want, $3); 3038 | CLOSE have; 3039 | CLOSE want; 3040 | RETURN res; 3041 | END; 3042 | $$ LANGUAGE plpgsql; 3043 | 3044 | -- results_eq( sql, array ) 3045 | CREATE OR REPLACE FUNCTION results_eq( TEXT, anyarray ) 3046 | RETURNS TEXT AS $$ 3047 | SELECT results_eq( $1, $2, NULL::text ); 3048 | $$ LANGUAGE sql; 3049 | 3050 | -- results_eq( sql, cursor, description ) 3051 | CREATE OR REPLACE FUNCTION results_eq( TEXT, refcursor, TEXT ) 3052 | RETURNS TEXT AS $$ 3053 | DECLARE 3054 | have REFCURSOR; 3055 | res TEXT; 3056 | BEGIN 3057 | OPEN have FOR EXECUTE _query($1); 3058 | res := results_eq(have, $2, $3); 3059 | CLOSE have; 3060 | RETURN res; 3061 | END; 3062 | $$ LANGUAGE plpgsql; 3063 | 3064 | -- results_eq( sql, cursor ) 3065 | CREATE OR REPLACE FUNCTION results_eq( TEXT, refcursor ) 3066 | RETURNS TEXT AS $$ 3067 | SELECT results_eq( $1, $2, NULL::text ); 3068 | $$ LANGUAGE sql; 3069 | 3070 | -- results_eq( cursor, sql, description ) 3071 | CREATE OR REPLACE FUNCTION results_eq( refcursor, TEXT, TEXT ) 3072 | RETURNS TEXT AS $$ 3073 | DECLARE 3074 | want REFCURSOR; 3075 | res TEXT; 3076 | BEGIN 3077 | OPEN want FOR EXECUTE _query($2); 3078 | res := results_eq($1, want, $3); 3079 | CLOSE want; 3080 | RETURN res; 3081 | END; 3082 | $$ LANGUAGE plpgsql; 3083 | 3084 | -- results_eq( cursor, sql ) 3085 | CREATE OR REPLACE FUNCTION results_eq( refcursor, TEXT ) 3086 | RETURNS TEXT AS $$ 3087 | SELECT results_eq( $1, $2, NULL::text ); 3088 | $$ LANGUAGE sql; 3089 | 3090 | -- results_eq( cursor, array, description ) 3091 | CREATE OR REPLACE FUNCTION results_eq( refcursor, anyarray, TEXT ) 3092 | RETURNS TEXT AS $$ 3093 | DECLARE 3094 | want REFCURSOR; 3095 | res TEXT; 3096 | BEGIN 3097 | OPEN want FOR SELECT $2[i] 3098 | FROM generate_series(array_lower($2, 1), array_upper($2, 1)) s(i); 3099 | res := results_eq($1, want, $3); 3100 | CLOSE want; 3101 | RETURN res; 3102 | END; 3103 | $$ LANGUAGE plpgsql; 3104 | 3105 | -- results_eq( cursor, array ) 3106 | CREATE OR REPLACE FUNCTION results_eq( refcursor, anyarray ) 3107 | RETURNS TEXT AS $$ 3108 | SELECT results_eq( $1, $2, NULL::text ); 3109 | $$ LANGUAGE sql; 3110 | 3111 | -- results_ne( cursor, cursor, description ) 3112 | CREATE OR REPLACE FUNCTION results_ne( refcursor, refcursor, text ) 3113 | RETURNS TEXT AS $$ 3114 | DECLARE 3115 | have ALIAS FOR $1; 3116 | want ALIAS FOR $2; 3117 | have_rec RECORD; 3118 | want_rec RECORD; 3119 | have_found BOOLEAN; 3120 | want_found BOOLEAN; 3121 | BEGIN 3122 | FETCH have INTO have_rec; 3123 | have_found := FOUND; 3124 | FETCH want INTO want_rec; 3125 | want_found := FOUND; 3126 | WHILE have_found OR want_found LOOP 3127 | IF have_rec::text IS DISTINCT FROM want_rec::text OR have_found <> want_found THEN 3128 | RETURN ok( true, $3 ); 3129 | ELSE 3130 | FETCH have INTO have_rec; 3131 | have_found := FOUND; 3132 | FETCH want INTO want_rec; 3133 | want_found := FOUND; 3134 | END IF; 3135 | END LOOP; 3136 | RETURN ok( false, $3 ); 3137 | EXCEPTION 3138 | WHEN datatype_mismatch THEN 3139 | RETURN ok( false, $3 ) || E'\n' || diag( 3140 | E' Columns differ between queries:\n' || 3141 | ' have: ' || CASE WHEN have_found THEN have_rec::text ELSE 'NULL' END || E'\n' || 3142 | ' want: ' || CASE WHEN want_found THEN want_rec::text ELSE 'NULL' END 3143 | ); 3144 | END; 3145 | $$ LANGUAGE plpgsql; 3146 | 3147 | -- results_ne( cursor, cursor ) 3148 | CREATE OR REPLACE FUNCTION results_ne( refcursor, refcursor ) 3149 | RETURNS TEXT AS $$ 3150 | SELECT results_ne( $1, $2, NULL::text ); 3151 | $$ LANGUAGE sql; 3152 | 3153 | -- results_ne( sql, sql, description ) 3154 | CREATE OR REPLACE FUNCTION results_ne( TEXT, TEXT, TEXT ) 3155 | RETURNS TEXT AS $$ 3156 | DECLARE 3157 | have REFCURSOR; 3158 | want REFCURSOR; 3159 | res TEXT; 3160 | BEGIN 3161 | OPEN have FOR EXECUTE _query($1); 3162 | OPEN want FOR EXECUTE _query($2); 3163 | res := results_ne(have, want, $3); 3164 | CLOSE have; 3165 | CLOSE want; 3166 | RETURN res; 3167 | END; 3168 | $$ LANGUAGE plpgsql; 3169 | 3170 | -- results_ne( sql, sql ) 3171 | CREATE OR REPLACE FUNCTION results_ne( TEXT, TEXT ) 3172 | RETURNS TEXT AS $$ 3173 | SELECT results_ne( $1, $2, NULL::text ); 3174 | $$ LANGUAGE sql; 3175 | 3176 | -- results_ne( sql, array, description ) 3177 | CREATE OR REPLACE FUNCTION results_ne( TEXT, anyarray, TEXT ) 3178 | RETURNS TEXT AS $$ 3179 | DECLARE 3180 | have REFCURSOR; 3181 | want REFCURSOR; 3182 | res TEXT; 3183 | BEGIN 3184 | OPEN have FOR EXECUTE _query($1); 3185 | OPEN want FOR SELECT $2[i] 3186 | FROM generate_series(array_lower($2, 1), array_upper($2, 1)) s(i); 3187 | res := results_ne(have, want, $3); 3188 | CLOSE have; 3189 | CLOSE want; 3190 | RETURN res; 3191 | END; 3192 | $$ LANGUAGE plpgsql; 3193 | 3194 | -- results_ne( sql, array ) 3195 | CREATE OR REPLACE FUNCTION results_ne( TEXT, anyarray ) 3196 | RETURNS TEXT AS $$ 3197 | SELECT results_ne( $1, $2, NULL::text ); 3198 | $$ LANGUAGE sql; 3199 | 3200 | -- results_ne( sql, cursor, description ) 3201 | CREATE OR REPLACE FUNCTION results_ne( TEXT, refcursor, TEXT ) 3202 | RETURNS TEXT AS $$ 3203 | DECLARE 3204 | have REFCURSOR; 3205 | res TEXT; 3206 | BEGIN 3207 | OPEN have FOR EXECUTE _query($1); 3208 | res := results_ne(have, $2, $3); 3209 | CLOSE have; 3210 | RETURN res; 3211 | END; 3212 | $$ LANGUAGE plpgsql; 3213 | 3214 | -- results_ne( sql, cursor ) 3215 | CREATE OR REPLACE FUNCTION results_ne( TEXT, refcursor ) 3216 | RETURNS TEXT AS $$ 3217 | SELECT results_ne( $1, $2, NULL::text ); 3218 | $$ LANGUAGE sql; 3219 | 3220 | -- results_ne( cursor, sql, description ) 3221 | CREATE OR REPLACE FUNCTION results_ne( refcursor, TEXT, TEXT ) 3222 | RETURNS TEXT AS $$ 3223 | DECLARE 3224 | want REFCURSOR; 3225 | res TEXT; 3226 | BEGIN 3227 | OPEN want FOR EXECUTE _query($2); 3228 | res := results_ne($1, want, $3); 3229 | CLOSE want; 3230 | RETURN res; 3231 | END; 3232 | $$ LANGUAGE plpgsql; 3233 | 3234 | -- results_ne( cursor, sql ) 3235 | CREATE OR REPLACE FUNCTION results_ne( refcursor, TEXT ) 3236 | RETURNS TEXT AS $$ 3237 | SELECT results_ne( $1, $2, NULL::text ); 3238 | $$ LANGUAGE sql; 3239 | 3240 | -- results_ne( cursor, array, description ) 3241 | CREATE OR REPLACE FUNCTION results_ne( refcursor, anyarray, TEXT ) 3242 | RETURNS TEXT AS $$ 3243 | DECLARE 3244 | want REFCURSOR; 3245 | res TEXT; 3246 | BEGIN 3247 | OPEN want FOR SELECT $2[i] 3248 | FROM generate_series(array_lower($2, 1), array_upper($2, 1)) s(i); 3249 | res := results_ne($1, want, $3); 3250 | CLOSE want; 3251 | RETURN res; 3252 | END; 3253 | $$ LANGUAGE plpgsql; 3254 | 3255 | -- results_ne( cursor, array ) 3256 | CREATE OR REPLACE FUNCTION results_ne( refcursor, anyarray ) 3257 | RETURNS TEXT AS $$ 3258 | SELECT results_ne( $1, $2, NULL::text ); 3259 | $$ LANGUAGE sql; 3260 | 3261 | -- isa_ok( value, regtype, description ) 3262 | CREATE OR REPLACE FUNCTION isa_ok( anyelement, regtype, TEXT ) 3263 | RETURNS TEXT AS $$ 3264 | DECLARE 3265 | typeof regtype := pg_typeof($1); 3266 | BEGIN 3267 | IF typeof = $2 THEN RETURN ok(true, $3 || ' isa ' || $2 ); END IF; 3268 | RETURN ok(false, $3 || ' isa ' || $2 ) || E'\n' || 3269 | diag(' ' || $3 || ' isn''t a "' || $2 || '" it''s a "' || typeof || '"'); 3270 | END; 3271 | $$ LANGUAGE plpgsql; 3272 | 3273 | -- isa_ok( value, regtype ) 3274 | CREATE OR REPLACE FUNCTION isa_ok( anyelement, regtype ) 3275 | RETURNS TEXT AS $$ 3276 | SELECT isa_ok($1, $2, 'the value'); 3277 | $$ LANGUAGE sql; 3278 | 3279 | -- is_empty( sql, description ) 3280 | CREATE OR REPLACE FUNCTION is_empty( TEXT, TEXT ) 3281 | RETURNS TEXT AS $$ 3282 | DECLARE 3283 | extras TEXT[] := '{}'; 3284 | res BOOLEAN := TRUE; 3285 | msg TEXT := ''; 3286 | rec RECORD; 3287 | BEGIN 3288 | -- Find extra records. 3289 | FOR rec in EXECUTE _query($1) LOOP 3290 | extras := extras || rec::text; 3291 | END LOOP; 3292 | 3293 | -- What extra records do we have? 3294 | IF extras[1] IS NOT NULL THEN 3295 | res := FALSE; 3296 | msg := E'\n' || diag( 3297 | E' Unexpected records:\n ' 3298 | || array_to_string( extras, E'\n ' ) 3299 | ); 3300 | END IF; 3301 | 3302 | RETURN ok(res, $2) || msg; 3303 | END; 3304 | $$ LANGUAGE plpgsql; 3305 | 3306 | -- is_empty( sql ) 3307 | CREATE OR REPLACE FUNCTION is_empty( TEXT ) 3308 | RETURNS TEXT AS $$ 3309 | SELECT is_empty( $1, NULL ); 3310 | $$ LANGUAGE sql; 3311 | 3312 | -- collect_tap( tap, tap, tap ) 3313 | CREATE OR REPLACE FUNCTION collect_tap( text[] ) 3314 | RETURNS TEXT AS $$ 3315 | SELECT array_to_string($1, E'\n'); 3316 | $$ LANGUAGE sql; 3317 | 3318 | CREATE OR REPLACE FUNCTION _tlike ( BOOLEAN, TEXT, TEXT, TEXT ) 3319 | RETURNS TEXT AS $$ 3320 | SELECT ok( $1, $4 ) || CASE WHEN $1 THEN '' ELSE E'\n' || diag( 3321 | ' error message: ' || COALESCE( quote_literal($2), 'NULL' ) || 3322 | E'\n doesn''t match: ' || COALESCE( quote_literal($3), 'NULL' ) 3323 | ) END; 3324 | $$ LANGUAGE sql; 3325 | 3326 | -- throws_like ( sql, pattern, description ) 3327 | CREATE OR REPLACE FUNCTION throws_like ( TEXT, TEXT, TEXT ) 3328 | RETURNS TEXT AS $$ 3329 | BEGIN 3330 | EXECUTE _query($1); 3331 | RETURN ok( FALSE, $3 ) || E'\n' || diag( ' no exception thrown' ); 3332 | EXCEPTION WHEN OTHERS THEN 3333 | return _tlike( SQLERRM ~~ $2, SQLERRM, $2, $3 ); 3334 | END; 3335 | $$ LANGUAGE plpgsql; 3336 | 3337 | -- throws_like ( sql, pattern ) 3338 | CREATE OR REPLACE FUNCTION throws_like ( TEXT, TEXT ) 3339 | RETURNS TEXT AS $$ 3340 | SELECT throws_like($1, $2, 'Should throw exception like ' || quote_literal($2) ); 3341 | $$ LANGUAGE sql; 3342 | 3343 | -- throws_ilike ( sql, pattern, description ) 3344 | CREATE OR REPLACE FUNCTION throws_ilike ( TEXT, TEXT, TEXT ) 3345 | RETURNS TEXT AS $$ 3346 | BEGIN 3347 | EXECUTE _query($1); 3348 | RETURN ok( FALSE, $3 ) || E'\n' || diag( ' no exception thrown' ); 3349 | EXCEPTION WHEN OTHERS THEN 3350 | return _tlike( SQLERRM ~~* $2, SQLERRM, $2, $3 ); 3351 | END; 3352 | $$ LANGUAGE plpgsql; 3353 | 3354 | -- throws_ilike ( sql, pattern ) 3355 | CREATE OR REPLACE FUNCTION throws_ilike ( TEXT, TEXT ) 3356 | RETURNS TEXT AS $$ 3357 | SELECT throws_ilike($1, $2, 'Should throw exception like ' || quote_literal($2) ); 3358 | $$ LANGUAGE sql; 3359 | 3360 | -- throws_matching ( sql, pattern, description ) 3361 | CREATE OR REPLACE FUNCTION throws_matching ( TEXT, TEXT, TEXT ) 3362 | RETURNS TEXT AS $$ 3363 | BEGIN 3364 | EXECUTE _query($1); 3365 | RETURN ok( FALSE, $3 ) || E'\n' || diag( ' no exception thrown' ); 3366 | EXCEPTION WHEN OTHERS THEN 3367 | return _tlike( SQLERRM ~ $2, SQLERRM, $2, $3 ); 3368 | END; 3369 | $$ LANGUAGE plpgsql; 3370 | 3371 | -- throws_matching ( sql, pattern ) 3372 | CREATE OR REPLACE FUNCTION throws_matching ( TEXT, TEXT ) 3373 | RETURNS TEXT AS $$ 3374 | SELECT throws_matching($1, $2, 'Should throw exception matching ' || quote_literal($2) ); 3375 | $$ LANGUAGE sql; 3376 | 3377 | -- throws_imatching ( sql, pattern, description ) 3378 | CREATE OR REPLACE FUNCTION throws_imatching ( TEXT, TEXT, TEXT ) 3379 | RETURNS TEXT AS $$ 3380 | BEGIN 3381 | EXECUTE _query($1); 3382 | RETURN ok( FALSE, $3 ) || E'\n' || diag( ' no exception thrown' ); 3383 | EXCEPTION WHEN OTHERS THEN 3384 | return _tlike( SQLERRM ~* $2, SQLERRM, $2, $3 ); 3385 | END; 3386 | $$ LANGUAGE plpgsql; 3387 | 3388 | -- throws_imatching ( sql, pattern ) 3389 | CREATE OR REPLACE FUNCTION throws_imatching ( TEXT, TEXT ) 3390 | RETURNS TEXT AS $$ 3391 | SELECT throws_imatching($1, $2, 'Should throw exception matching ' || quote_literal($2) ); 3392 | $$ LANGUAGE sql; 3393 | 3394 | -- roles_are( roles[], description ) 3395 | CREATE OR REPLACE FUNCTION _dexists ( NAME, NAME ) 3396 | RETURNS BOOLEAN AS $$ 3397 | SELECT EXISTS( 3398 | SELECT true 3399 | FROM pg_catalog.pg_namespace n 3400 | JOIN pg_catalog.pg_type t on n.oid = t.typnamespace 3401 | WHERE n.nspname = $1 3402 | AND t.typname = $2 3403 | ); 3404 | $$ LANGUAGE SQL; 3405 | 3406 | CREATE OR REPLACE FUNCTION _dexists ( NAME ) 3407 | RETURNS BOOLEAN AS $$ 3408 | SELECT EXISTS( 3409 | SELECT true 3410 | FROM pg_catalog.pg_type t 3411 | WHERE t.typname = $1 3412 | AND pg_catalog.pg_type_is_visible(t.oid) 3413 | ); 3414 | $$ LANGUAGE SQL; 3415 | 3416 | CREATE OR REPLACE FUNCTION _get_dtype( NAME, TEXT, BOOLEAN ) 3417 | RETURNS TEXT AS $$ 3418 | SELECT display_type(CASE WHEN $3 THEN tn.nspname ELSE NULL END, t.oid, t.typtypmod) 3419 | FROM pg_catalog.pg_type d 3420 | JOIN pg_catalog.pg_namespace dn ON d.typnamespace = dn.oid 3421 | JOIN pg_catalog.pg_type t ON d.typbasetype = t.oid 3422 | JOIN pg_catalog.pg_namespace tn ON d.typnamespace = tn.oid 3423 | WHERE d.typisdefined 3424 | AND dn.nspname = $1 3425 | AND d.typname = LOWER($2) 3426 | AND d.typtype = 'd' 3427 | $$ LANGUAGE sql; 3428 | 3429 | CREATE OR REPLACE FUNCTION _get_dtype( NAME ) 3430 | RETURNS TEXT AS $$ 3431 | SELECT display_type(t.oid, t.typtypmod) 3432 | FROM pg_catalog.pg_type d 3433 | JOIN pg_catalog.pg_type t ON d.typbasetype = t.oid 3434 | WHERE d.typisdefined 3435 | AND d.typname = LOWER($1) 3436 | AND d.typtype = 'd' 3437 | $$ LANGUAGE sql; 3438 | 3439 | -- domain_type_is( schema, domain, schema, type, description ) 3440 | CREATE OR REPLACE FUNCTION domain_type_is( NAME, TEXT, NAME, TEXT, TEXT ) 3441 | RETURNS TEXT AS $$ 3442 | DECLARE 3443 | actual_type TEXT := _get_dtype($1, $2, true); 3444 | BEGIN 3445 | IF actual_type IS NULL THEN 3446 | RETURN fail( $5 ) || E'\n' || diag ( 3447 | ' Domain ' || quote_ident($1) || '.' || $2 3448 | || ' does not exist' 3449 | ); 3450 | END IF; 3451 | 3452 | RETURN is( actual_type, quote_ident($3) || '.' || _quote_ident_like($4, actual_type), $5 ); 3453 | END; 3454 | $$ LANGUAGE plpgsql; 3455 | 3456 | -- domain_type_is( schema, domain, schema, type ) 3457 | CREATE OR REPLACE FUNCTION domain_type_is( NAME, TEXT, NAME, TEXT ) 3458 | RETURNS TEXT AS $$ 3459 | SELECT domain_type_is( 3460 | $1, $2, $3, $4, 3461 | 'Domain ' || quote_ident($1) || '.' || $2 3462 | || ' should extend type ' || quote_ident($3) || '.' || $4 3463 | ); 3464 | $$ LANGUAGE SQL; 3465 | 3466 | -- domain_type_is( schema, domain, type, description ) 3467 | CREATE OR REPLACE FUNCTION domain_type_is( NAME, TEXT, TEXT, TEXT ) 3468 | RETURNS TEXT AS $$ 3469 | DECLARE 3470 | actual_type TEXT := _get_dtype($1, $2, false); 3471 | BEGIN 3472 | IF actual_type IS NULL THEN 3473 | RETURN fail( $4 ) || E'\n' || diag ( 3474 | ' Domain ' || quote_ident($1) || '.' || $2 3475 | || ' does not exist' 3476 | ); 3477 | END IF; 3478 | 3479 | RETURN is( actual_type, _quote_ident_like($3, actual_type), $4 ); 3480 | END; 3481 | $$ LANGUAGE plpgsql; 3482 | 3483 | -- domain_type_is( schema, domain, type ) 3484 | CREATE OR REPLACE FUNCTION domain_type_is( NAME, TEXT, TEXT ) 3485 | RETURNS TEXT AS $$ 3486 | SELECT domain_type_is( 3487 | $1, $2, $3, 3488 | 'Domain ' || quote_ident($1) || '.' || $2 3489 | || ' should extend type ' || $3 3490 | ); 3491 | $$ LANGUAGE SQL; 3492 | 3493 | -- domain_type_is( domain, type, description ) 3494 | CREATE OR REPLACE FUNCTION domain_type_is( TEXT, TEXT, TEXT ) 3495 | RETURNS TEXT AS $$ 3496 | DECLARE 3497 | actual_type TEXT := _get_dtype($1); 3498 | BEGIN 3499 | IF actual_type IS NULL THEN 3500 | RETURN fail( $3 ) || E'\n' || diag ( 3501 | ' Domain ' || $1 || ' does not exist' 3502 | ); 3503 | END IF; 3504 | 3505 | RETURN is( actual_type, _quote_ident_like($2, actual_type), $3 ); 3506 | END; 3507 | $$ LANGUAGE plpgsql; 3508 | 3509 | -- domain_type_is( domain, type ) 3510 | CREATE OR REPLACE FUNCTION domain_type_is( TEXT, TEXT ) 3511 | RETURNS TEXT AS $$ 3512 | SELECT domain_type_is( 3513 | $1, $2, 3514 | 'Domain ' || $1 || ' should extend type ' || $2 3515 | ); 3516 | $$ LANGUAGE SQL; 3517 | 3518 | -- domain_type_isnt( schema, domain, schema, type, description ) 3519 | CREATE OR REPLACE FUNCTION domain_type_isnt( NAME, TEXT, NAME, TEXT, TEXT ) 3520 | RETURNS TEXT AS $$ 3521 | DECLARE 3522 | actual_type TEXT := _get_dtype($1, $2, true); 3523 | BEGIN 3524 | IF actual_type IS NULL THEN 3525 | RETURN fail( $5 ) || E'\n' || diag ( 3526 | ' Domain ' || quote_ident($1) || '.' || $2 3527 | || ' does not exist' 3528 | ); 3529 | END IF; 3530 | 3531 | RETURN isnt( actual_type, quote_ident($3) || '.' || _quote_ident_like($4, actual_type), $5 ); 3532 | END; 3533 | $$ LANGUAGE plpgsql; 3534 | 3535 | -- domain_type_isnt( schema, domain, schema, type ) 3536 | CREATE OR REPLACE FUNCTION domain_type_isnt( NAME, TEXT, NAME, TEXT ) 3537 | RETURNS TEXT AS $$ 3538 | SELECT domain_type_isnt( 3539 | $1, $2, $3, $4, 3540 | 'Domain ' || quote_ident($1) || '.' || $2 3541 | || ' should not extend type ' || quote_ident($3) || '.' || $4 3542 | ); 3543 | $$ LANGUAGE SQL; 3544 | 3545 | -- domain_type_isnt( schema, domain, type, description ) 3546 | CREATE OR REPLACE FUNCTION domain_type_isnt( NAME, TEXT, TEXT, TEXT ) 3547 | RETURNS TEXT AS $$ 3548 | DECLARE 3549 | actual_type TEXT := _get_dtype($1, $2, false); 3550 | BEGIN 3551 | IF actual_type IS NULL THEN 3552 | RETURN fail( $4 ) || E'\n' || diag ( 3553 | ' Domain ' || quote_ident($1) || '.' || $2 3554 | || ' does not exist' 3555 | ); 3556 | END IF; 3557 | 3558 | RETURN isnt( actual_type, _quote_ident_like($3, actual_type), $4 ); 3559 | END; 3560 | $$ LANGUAGE plpgsql; 3561 | 3562 | -- domain_type_isnt( schema, domain, type ) 3563 | CREATE OR REPLACE FUNCTION domain_type_isnt( NAME, TEXT, TEXT ) 3564 | RETURNS TEXT AS $$ 3565 | SELECT domain_type_isnt( 3566 | $1, $2, $3, 3567 | 'Domain ' || quote_ident($1) || '.' || $2 3568 | || ' should not extend type ' || $3 3569 | ); 3570 | $$ LANGUAGE SQL; 3571 | 3572 | -- domain_type_isnt( domain, type, description ) 3573 | CREATE OR REPLACE FUNCTION domain_type_isnt( TEXT, TEXT, TEXT ) 3574 | RETURNS TEXT AS $$ 3575 | DECLARE 3576 | actual_type TEXT := _get_dtype($1); 3577 | BEGIN 3578 | IF actual_type IS NULL THEN 3579 | RETURN fail( $3 ) || E'\n' || diag ( 3580 | ' Domain ' || $1 || ' does not exist' 3581 | ); 3582 | END IF; 3583 | 3584 | RETURN isnt( actual_type, _quote_ident_like($2, actual_type), $3 ); 3585 | END; 3586 | $$ LANGUAGE plpgsql; 3587 | 3588 | -- domain_type_isnt( domain, type ) 3589 | CREATE OR REPLACE FUNCTION domain_type_isnt( TEXT, TEXT ) 3590 | RETURNS TEXT AS $$ 3591 | SELECT domain_type_isnt( 3592 | $1, $2, 3593 | 'Domain ' || $1 || ' should not extend type ' || $2 3594 | ); 3595 | $$ LANGUAGE SQL; 3596 | 3597 | -- row_eq( sql, record, description ) 3598 | CREATE OR REPLACE FUNCTION row_eq( TEXT, anyelement, TEXT ) 3599 | RETURNS TEXT AS $$ 3600 | DECLARE 3601 | rec RECORD; 3602 | BEGIN 3603 | EXECUTE _query($1) INTO rec; 3604 | IF NOT rec::text IS DISTINCT FROM $2::text THEN RETURN ok(true, $3); END IF; 3605 | RETURN ok(false, $3 ) || E'\n' || diag( 3606 | ' have: ' || CASE WHEN rec IS NULL THEN 'NULL' ELSE rec::text END || 3607 | E'\n want: ' || CASE WHEN $2 IS NULL THEN 'NULL' ELSE $2::text END 3608 | ); 3609 | END; 3610 | $$ LANGUAGE plpgsql; 3611 | 3612 | -- row_eq( sql, record ) 3613 | CREATE OR REPLACE FUNCTION row_eq( TEXT, anyelement ) 3614 | RETURNS TEXT AS $$ 3615 | SELECT row_eq($1, $2, NULL ); 3616 | $$ LANGUAGE sql; 3617 | 3618 | -- triggers_are( schema, table, triggers[], description ) 3619 | -------------------------------------------------------------------------------- /test/sql/base.sql: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | \i sql/hostname.sql 3 | SELECT COALESCE(length(hostname()), 0) >= 0; 4 | --------------------------------------------------------------------------------