Project

General

Profile

1 2094 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6 11667 aaronmk
SET lock_timeout = 0;
7 2094 aaronmk
SET client_encoding = 'UTF8';
8 6213 aaronmk
SET standard_conforming_strings = on;
9 2094 aaronmk
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11
12
--
13 8183 aaronmk
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
14 2094 aaronmk
--
15
16 8183 aaronmk
CREATE SCHEMA util;
17 2094 aaronmk
18
19 4982 aaronmk
--
20 8183 aaronmk
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
21 4982 aaronmk
--
22
23 12235 aaronmk
COMMENT ON SCHEMA util IS '
24
IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
25 4982 aaronmk
26 12447 aaronmk
NOTE: SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding. avoiding use of STRICT also makes functions *much* easier to troubleshoot, because they won''t mysteriously do nothing if called with only NULL arguments, even when you have added debug-print statements.
27 12235 aaronmk
';
28 4982 aaronmk
29 10378 aaronmk
30 8183 aaronmk
SET search_path = util, pg_catalog;
31 2107 aaronmk
32 2094 aaronmk
--
33 8183 aaronmk
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34 8107 aaronmk
--
35
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40
41
42
--
43 8183 aaronmk
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44 8106 aaronmk
--
45
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50
51
52
--
53 8183 aaronmk
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54 7673 aaronmk
--
55
56
CREATE TYPE compass_dir AS ENUM (
57
    'N',
58
    'E',
59
    'S',
60
    'W'
61
);
62
63
64
--
65 8183 aaronmk
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66 2610 aaronmk
--
67
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72
73
74
--
75 12423 aaronmk
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77
78
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
79 12443 aaronmk
    LANGUAGE sql STABLE
80 12423 aaronmk
    AS $_$
81 12436 aaronmk
SELECT keys($1) = keys($2)
82 12423 aaronmk
$_$;
83
84
85
--
86 12443 aaronmk
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
87
--
88
89
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
90
needs to be declared STABLE instead of IMMUTABLE because it depends on the search_path (as described at http://vegpath.org/links/#PostgreSQL:%20Documentation:%209.3:%20Function%20Volatility%20Categories%20**)
91
';
92
93
94
--
95 8183 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
96 2596 aaronmk
--
97
98 4501 aaronmk
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
99 3422 aaronmk
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102 3422 aaronmk
$_$;
103
104
105
--
106 8183 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
107 5937 aaronmk
--
108
109 5956 aaronmk
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
110 5937 aaronmk
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117 5956 aaronmk
    , ($3)
118
    , ($4)
119
    , ($5)
120 5937 aaronmk
)
121
AS v (value)
122
$_$;
123
124
125
--
126 8183 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
127 5937 aaronmk
--
128
129 12235 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
130
_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.
131
';
132 5937 aaronmk
133
134
--
135 8183 aaronmk
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
136 7704 aaronmk
--
137
138
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152
153
154
--
155 8183 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
156 7679 aaronmk
--
157
158
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
159 12441 aaronmk
    LANGUAGE sql IMMUTABLE
160 7679 aaronmk
    AS $_$
161 8183 aaronmk
SELECT (g[1]||'1')::integer*util._dms_to_dd(deg := g[2]::double precision, min := g[3]::double precision, sec := g[4]::double precision, dir := g[5]::util.compass_dir)
162 7698 aaronmk
FROM
163
(
164
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
165
    UNION ALL
166 7702 aaronmk
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
167
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
168 7698 aaronmk
)
169
matches (g)
170 7679 aaronmk
$_$;
171
172
173
--
174 8183 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
175 7672 aaronmk
--
176
177 7674 aaronmk
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
178 7672 aaronmk
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180 8183 aaronmk
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181 7672 aaronmk
FROM
182
(VALUES
183 7677 aaronmk
      ($1)
184 7672 aaronmk
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189
190
191
--
192 8183 aaronmk
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
193 7723 aaronmk
--
194
195
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198 8183 aaronmk
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199 7723 aaronmk
$_$;
200
201
202
--
203 8183 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
204 4142 aaronmk
--
205
206
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
207
    LANGUAGE sql IMMUTABLE
208
    AS $_$
209
SELECT $1 = $2
210
$_$;
211
212
213
--
214 8183 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
215 7396 aaronmk
--
216
217
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
218
    LANGUAGE sql IMMUTABLE
219
    AS $_$
220
-- Fix dates after threshold date
221
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
222
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
223
$_$;
224
225
226
--
227 8183 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
228 4147 aaronmk
--
229
230
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
231
    LANGUAGE sql IMMUTABLE
232
    AS $_$
233
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
234
$_$;
235
236
237
--
238 8183 aaronmk
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
239 4147 aaronmk
--
240
241
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
242
    LANGUAGE sql IMMUTABLE
243
    AS $_$
244 8183 aaronmk
SELECT util._if($1 != '', $2, $3)
245 4147 aaronmk
$_$;
246
247
248
--
249 10699 aaronmk
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
250 4325 aaronmk
--
251
252 10699 aaronmk
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
253 4325 aaronmk
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255 7848 aaronmk
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256 4325 aaronmk
$_$;
257
258
259
--
260 10699 aaronmk
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
261 5009 aaronmk
--
262
263 10699 aaronmk
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
264 5009 aaronmk
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266 7848 aaronmk
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267 5009 aaronmk
$_$;
268
269
270
--
271 10699 aaronmk
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
272 3422 aaronmk
--
273
274 10699 aaronmk
CREATE FUNCTION _label(label text, value text) RETURNS text
275 4682 aaronmk
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277
SELECT coalesce($1 || ': ', '') || $2
278
$_$;
279 2596 aaronmk
280
281
--
282 8825 aaronmk
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
283
--
284
285
CREATE FUNCTION _lowercase(value text) RETURNS text
286 10388 aaronmk
    LANGUAGE sql IMMUTABLE
287 8825 aaronmk
    AS $_$
288
SELECT lower($1)
289
$_$;
290
291
292
--
293 11667 aaronmk
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
294
--
295
296
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
297
    LANGUAGE plpgsql IMMUTABLE STRICT
298
    AS $$
299
DECLARE
300
    result value%TYPE := util._map(map, value::text)::unknown;
301
BEGIN
302
    RETURN result;
303
END;
304
$$;
305
306
307
--
308 8183 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
309 6222 aaronmk
--
310
311
CREATE FUNCTION _map(map hstore, value text) RETURNS text
312 7820 aaronmk
    LANGUAGE plpgsql IMMUTABLE STRICT
313 6222 aaronmk
    AS $$
314
DECLARE
315 6271 aaronmk
    match text := map -> value;
316 6222 aaronmk
BEGIN
317 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
318
        match := map -> '*'; -- use default entry
319
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
320
        END IF;
321
    END IF;
322
323
    -- Interpret result
324 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
325
    ELSIF match = '*' THEN RETURN value;
326
    ELSE RETURN match;
327 6222 aaronmk
    END IF;
328
END;
329
$$;
330
331
332
--
333 8183 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
334 5408 aaronmk
--
335
336
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
337
    LANGUAGE sql IMMUTABLE
338
    AS $_$
339 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
340 5408 aaronmk
$_$;
341
342
343
--
344 8183 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
345 2940 aaronmk
--
346
347 4150 aaronmk
CREATE FUNCTION _merge("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
348 2940 aaronmk
    LANGUAGE sql IMMUTABLE
349
    AS $_$
350 8183 aaronmk
SELECT util.join_strs(value, '; ')
351 2940 aaronmk
FROM
352
(
353
    SELECT *
354
    FROM
355
    (
356
        SELECT
357
        DISTINCT ON (value)
358
        *
359
        FROM
360
        (VALUES
361 4012 aaronmk
              (1, $1)
362
            , (2, $2)
363
            , (3, $3)
364
            , (4, $4)
365
            , (5, $5)
366
            , (6, $6)
367
            , (7, $7)
368
            , (8, $8)
369
            , (9, $9)
370
            , (10, $10)
371 2940 aaronmk
        )
372
        AS v (sort_order, value)
373 4011 aaronmk
        WHERE value IS NOT NULL
374 2940 aaronmk
    )
375
    AS v
376
    ORDER BY sort_order
377
)
378
AS v
379
$_$;
380
381
382
--
383 8183 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
384 7140 aaronmk
--
385
386
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
387
    LANGUAGE sql IMMUTABLE
388
    AS $_$
389
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
390
$_$;
391
392
393
--
394 8183 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
395 6354 aaronmk
--
396
397
CREATE FUNCTION _merge_words("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
398
    LANGUAGE sql IMMUTABLE
399
    AS $_$
400 8183 aaronmk
SELECT util.join_strs(value, ' ')
401 6354 aaronmk
FROM
402
(
403
    SELECT *
404
    FROM
405
    (
406
        SELECT
407
        DISTINCT ON (value)
408
        *
409
        FROM
410
        (VALUES
411
              (1, $1)
412
            , (2, $2)
413
            , (3, $3)
414
            , (4, $4)
415
            , (5, $5)
416
            , (6, $6)
417
            , (7, $7)
418
            , (8, $8)
419
            , (9, $9)
420
            , (10, $10)
421
        )
422
        AS v (sort_order, value)
423
        WHERE value IS NOT NULL
424
    )
425
    AS v
426
    ORDER BY sort_order
427
)
428
AS v
429
$_$;
430
431
432
--
433 8183 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
434 5408 aaronmk
--
435
436
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
437
    LANGUAGE sql IMMUTABLE
438
    AS $_$
439 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
440 5408 aaronmk
$_$;
441
442
443
--
444 8183 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
445 6316 aaronmk
--
446
447
CREATE FUNCTION _not(value boolean) RETURNS boolean
448 10388 aaronmk
    LANGUAGE sql IMMUTABLE
449 6316 aaronmk
    AS $_$
450
SELECT NOT $1
451
$_$;
452
453
454
--
455 8183 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
456 7104 aaronmk
--
457
458
CREATE FUNCTION _now() RETURNS timestamp with time zone
459
    LANGUAGE sql STABLE
460
    AS $$
461
SELECT now()
462
$$;
463
464
465
--
466 11667 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
467
--
468
469
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
470
    LANGUAGE sql IMMUTABLE
471
    AS $_$
472
SELECT util."_nullIf"($1, $2, $3::util.datatype)
473
$_$;
474
475
476
--
477 8183 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
478 2949 aaronmk
--
479
480 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
481 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
482
    AS $$
483
DECLARE
484 8183 aaronmk
    type util.datatype NOT NULL := type; -- add NOT NULL
485 2949 aaronmk
BEGIN
486 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
487 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
488 2949 aaronmk
    ELSIF type = 'float' THEN
489 2722 aaronmk
        DECLARE
490
            -- Outside the try block so that invalid null value generates error
491 2949 aaronmk
            "null" double precision := "null"::double precision;
492 2722 aaronmk
        BEGIN
493 2949 aaronmk
            RETURN nullif(value::double precision, "null");
494 2722 aaronmk
        EXCEPTION
495 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
496 2722 aaronmk
        END;
497 2610 aaronmk
    END IF;
498
END;
499
$$;
500
501
502
--
503 8183 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
504 6355 aaronmk
--
505
506
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT bool_or(value)
510
FROM
511
(VALUES
512
      ($1)
513
    , ($2)
514
    , ($3)
515
    , ($4)
516
    , ($5)
517
)
518
AS v (value)
519
$_$;
520
521
522
--
523 8183 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
524 6437 aaronmk
--
525
526 12235 aaronmk
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
527
_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.
528
';
529 6437 aaronmk
530
531
--
532 8183 aaronmk
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
533 7706 aaronmk
--
534
535
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
536
    LANGUAGE sql IMMUTABLE
537
    AS $_$
538
SELECT $2 - $1
539
$_$;
540
541
542
--
543 8183 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
544 6793 aaronmk
--
545
546
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
547 10388 aaronmk
    LANGUAGE sql IMMUTABLE
548 6793 aaronmk
    AS $_$
549
SELECT regexp_split_to_table($1, $2)
550
$_$;
551
552
553
--
554 10594 aaronmk
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
555
--
556
557
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
558 12446 aaronmk
    LANGUAGE sql STABLE
559 10594 aaronmk
    AS $_$
560
SELECT util.derived_cols($1, $2)
561
UNION
562
SELECT util.eval2set($$
563
SELECT col
564
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
565
JOIN $$||$2||$$ ON "to" = col
566
WHERE "from" LIKE ':%'
567
$$, NULL::text)
568
$_$;
569
570
571
--
572
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
573
--
574
575 12235 aaronmk
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
576
gets table_''s added columns (all the columns not in the original data)
577
';
578 10594 aaronmk
579
580
--
581 9959 aaronmk
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
582
--
583
584
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
585
    LANGUAGE sql IMMUTABLE
586
    AS $_$
587
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
588
$_$;
589
590
591
--
592
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
593
--
594
595
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
596
    LANGUAGE plpgsql IMMUTABLE
597
    AS $$
598
DECLARE
599
	value_cmp         state%TYPE = ARRAY[value];
600
	state             state%TYPE = COALESCE(state, value_cmp);
601
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
602
BEGIN
603
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
604
END;
605
$$;
606
607
608
--
609 12320 aaronmk
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
610
--
611
612
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
613
    LANGUAGE sql
614
    AS $_$
615
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
616
$_$;
617
618
619
--
620 12369 aaronmk
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
621
--
622
623
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
624 12446 aaronmk
    LANGUAGE sql
625 12369 aaronmk
    AS $_$
626
SELECT util.set_comment($1, concat(util.comment($1), $2))
627
$_$;
628
629
630
--
631
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
632
--
633
634
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
635
comment: must start and end with a newline
636
';
637
638
639
--
640 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
641
--
642
643
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
644
    LANGUAGE sql IMMUTABLE
645
    AS $_$
646
SELECT pg_catalog.array_fill($1, ARRAY[$2])
647
$_$;
648
649
650
--
651 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
652
--
653
654
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
655 10354 aaronmk
    LANGUAGE sql IMMUTABLE
656 10303 aaronmk
    AS $_$
657 10321 aaronmk
SELECT util.array_length($1, 1)
658 10303 aaronmk
$_$;
659
660
661
--
662 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
663
--
664
665
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
666 10354 aaronmk
    LANGUAGE sql IMMUTABLE
667 10304 aaronmk
    AS $_$
668 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
669 10304 aaronmk
$_$;
670
671
672
--
673
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
674
--
675
676 12235 aaronmk
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
677
returns 0 instead of NULL for empty arrays
678
';
679 10304 aaronmk
680
681
--
682 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
683 8104 aaronmk
--
684
685
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
686 12446 aaronmk
    LANGUAGE sql STABLE
687 8104 aaronmk
    AS $_$
688
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
689
$_$;
690
691
692
--
693 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
694 8105 aaronmk
--
695
696
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
697
    LANGUAGE plpgsql STRICT
698
    AS $_$
699
BEGIN
700
    -- not yet clustered (ARRAY[] compares NULLs literally)
701 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
702 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
703
    END IF;
704
END;
705
$_$;
706
707
708
--
709 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
710 8105 aaronmk
--
711
712 12235 aaronmk
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
713
idempotent
714
';
715 8105 aaronmk
716
717
--
718 10986 aaronmk
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
719
--
720
721
CREATE FUNCTION col__min(col col_ref) RETURNS integer
722
    LANGUAGE sql STABLE
723
    AS $_$
724
SELECT util.eval2val($$
725
SELECT $$||quote_ident($1.name)||$$
726
FROM $$||$1.table_||$$
727
ORDER BY $$||quote_ident($1.name)||$$ ASC
728
LIMIT 1
729
$$, NULL::integer)
730
$_$;
731
732
733
--
734 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
735
--
736
737
CREATE FUNCTION col_comment(col col_ref) RETURNS text
738
    LANGUAGE plpgsql STABLE STRICT
739
    AS $$
740
DECLARE
741
	comment text;
742
BEGIN
743
	SELECT description
744
	FROM pg_attribute
745
	LEFT JOIN pg_description ON objoid = attrelid
746
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
747
	WHERE attrelid = col.table_ AND attname = col.name
748
	INTO STRICT comment
749
	;
750
	RETURN comment;
751
EXCEPTION
752
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
753
END;
754
$$;
755
756
757
--
758 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
759
--
760
761
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
762
    LANGUAGE plpgsql STABLE STRICT
763
    AS $$
764
DECLARE
765
	default_sql text;
766
BEGIN
767
	SELECT adsrc
768
	FROM pg_attribute
769
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
770
	WHERE attrelid = col.table_ AND attname = col.name
771
	INTO STRICT default_sql
772
	;
773
	RETURN default_sql;
774
EXCEPTION
775
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
776
END;
777
$$;
778
779
780
--
781 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
782
--
783
784
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
785
    LANGUAGE sql STABLE
786
    AS $_$
787
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
788
$_$;
789
790
791
--
792
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
793
--
794
795 12235 aaronmk
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
796
ret_type_null: NULL::ret_type
797
';
798 10134 aaronmk
799
800
--
801 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
802 8180 aaronmk
--
803
804
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
805
    LANGUAGE plpgsql STRICT
806
    AS $$
807
BEGIN
808 8183 aaronmk
    PERFORM util.col_type(col);
809 8180 aaronmk
    RETURN true;
810
EXCEPTION
811
    WHEN undefined_column THEN RETURN false;
812
END;
813
$$;
814
815
816
--
817 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
818 8084 aaronmk
--
819
820
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
821 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
822 8084 aaronmk
    AS $$
823
DECLARE
824 8183 aaronmk
    prefix text := util.name(type)||'.';
825 8084 aaronmk
BEGIN
826
    RETURN QUERY
827 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
828
        FROM util.col_names(type) f (name_);
829 8084 aaronmk
END;
830
$$;
831
832
833
--
834 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
835 8151 aaronmk
--
836
837
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
838 12446 aaronmk
    LANGUAGE sql STABLE
839 8151 aaronmk
    AS $_$
840
SELECT attname::text
841
FROM pg_attribute
842 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
843 8151 aaronmk
ORDER BY attnum
844
$_$;
845
846
847
--
848 11667 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
849
--
850
851
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
852
    LANGUAGE plpgsql STABLE STRICT
853
    AS $_$
854
BEGIN
855
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
856
END;
857
$_$;
858
859
860
--
861 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
862 8106 aaronmk
--
863
864
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
865 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
866
    AS $$
867
DECLARE
868
    type regtype;
869
BEGIN
870
    SELECT atttypid FROM pg_attribute
871
    WHERE attrelid = col.table_ AND attname = col.name
872
    INTO STRICT type
873
    ;
874
    RETURN type;
875
EXCEPTION
876 8171 aaronmk
    WHEN no_data_found THEN
877 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
878
            concat('undefined column: ', col.name);
879 8169 aaronmk
END;
880
$$;
881 8106 aaronmk
882
883
--
884 12368 aaronmk
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
885
--
886
887
CREATE FUNCTION comment(element oid) RETURNS text
888 12446 aaronmk
    LANGUAGE sql STABLE
889 12368 aaronmk
    AS $_$
890
SELECT description FROM pg_description WHERE objoid = $1
891
$_$;
892
893
894
--
895 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
896
--
897
898
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
899
    LANGUAGE sql IMMUTABLE
900
    AS $_$
901
SELECT util.esc_name__append($2, $1)
902
$_$;
903
904
905
--
906 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
907 8095 aaronmk
--
908
909
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
910 10388 aaronmk
    LANGUAGE sql IMMUTABLE
911 8095 aaronmk
    AS $_$
912
SELECT position($1 in $2) > 0 /*1-based offset*/
913
$_$;
914
915
916
--
917 12288 aaronmk
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
918
--
919
920
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
921
    LANGUAGE sql
922
    AS $_$
923
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
924
$_$;
925
926
927
--
928 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
929 8094 aaronmk
--
930
931
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
932
    LANGUAGE plpgsql STRICT
933
    AS $$
934
BEGIN
935 10146 aaronmk
    PERFORM util.eval(sql);
936 8094 aaronmk
EXCEPTION
937 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
938 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
939 8103 aaronmk
    WHEN duplicate_column THEN NULL;
940 10244 aaronmk
    WHEN invalid_table_definition THEN
941
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
942
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
943
        END IF;
944 8094 aaronmk
END;
945
$$;
946
947
948
--
949 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
950 8094 aaronmk
--
951
952 12235 aaronmk
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
953
idempotent
954
';
955 8094 aaronmk
956
957
--
958 12378 aaronmk
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
959
--
960
961
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
962
    LANGUAGE sql IMMUTABLE
963
    AS $$
964
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
965
$$;
966
967
968
--
969 12433 aaronmk
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
970 12430 aaronmk
--
971
972 12433 aaronmk
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
973 12430 aaronmk
    LANGUAGE sql IMMUTABLE
974
    AS $_$
975 12534 aaronmk
SELECT util.raise('NOTICE', 'returns: '
976 12433 aaronmk
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
977 12430 aaronmk
SELECT $1;
978
$_$;
979
980
981
--
982 12250 aaronmk
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
983
--
984
985
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
986
    LANGUAGE sql IMMUTABLE
987
    AS $_$
988
/* newline before so the query starts at the beginning of the line.
989
newline after to visually separate queries from one another. */
990 12534 aaronmk
SELECT util.raise('NOTICE', $$
991 12474 aaronmk
$$||util.runnable_sql($1)||$$
992 12464 aaronmk
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
993 12250 aaronmk
$_$;
994
995
996
--
997 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
998
--
999
1000
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1001 12446 aaronmk
    LANGUAGE sql STABLE
1002 10364 aaronmk
    AS $_$
1003
SELECT util.eval2set($$
1004
SELECT col
1005
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1006
LEFT JOIN $$||$2||$$ ON "to" = col
1007
WHERE "from" IS NULL
1008
$$, NULL::text)
1009
$_$;
1010
1011
1012
--
1013
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1014
--
1015
1016 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1017
gets table_''s derived columns (all the columns not in the names table)
1018
';
1019 10364 aaronmk
1020
1021
--
1022 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1023 12044 aaronmk
--
1024
1025 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1026 12427 aaronmk
    LANGUAGE sql
1027 12044 aaronmk
    AS $_$
1028 12300 aaronmk
SELECT * FROM util.diff($1::text, $2::text, $3,
1029 12491 aaronmk
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1030 12298 aaronmk
$_$;
1031
1032
1033
--
1034
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1035
--
1036
1037
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1038
col_type_null (*required*): NULL::shared_base_type
1039
usage:
1040
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1041
';
1042
1043
1044
--
1045 12491 aaronmk
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1046 12298 aaronmk
--
1047
1048 12491 aaronmk
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1049 12429 aaronmk
    LANGUAGE plpgsql
1050
    SET search_path TO pg_temp
1051 12298 aaronmk
    AS $_$
1052 12429 aaronmk
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1053
changes of search_path (schema elements are bound at inline time rather than
1054
runtime) */
1055
/* function option search_path is needed to limit the effects of
1056 12492 aaronmk
`SET LOCAL search_path` to the current function */
1057 12429 aaronmk
BEGIN
1058 12491 aaronmk
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1059 12429 aaronmk
1060
	RETURN QUERY
1061 12554 aaronmk
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1062 12479 aaronmk
$$/* need to explicitly cast each side to the return type because this does not
1063 12284 aaronmk
happen automatically even when an implicit cast is available */
1064 12479 aaronmk
  left_::$$||util.typeof($3)||$$
1065
, right_::$$||util.typeof($3)
1066 12496 aaronmk
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1067
the *same* base type, *even though* this is optional when using a custom %== */
1068 12553 aaronmk
, util._if($4, $$true/*= CROSS JOIN*/$$,
1069
$$ left_::$$||util.typeof($3)||$$
1070 12496 aaronmk
%== right_::$$||util.typeof($3)||$$
1071
	-- refer to EXPLAIN output for expansion of %==$$
1072 12553 aaronmk
)), $3)
1073 12429 aaronmk
	;
1074
END;
1075 12044 aaronmk
$_$;
1076
1077
1078
--
1079 12491 aaronmk
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1080 12280 aaronmk
--
1081
1082 12491 aaronmk
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1083 12280 aaronmk
col_type_null (*required*): NULL::col_type
1084 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
1085
	displayed side-by-side
1086 12282 aaronmk
1087 12498 aaronmk
to match up rows using a subset of the columns, create a custom keys() function
1088
which returns this subset as a record:
1089
-- note that OUT parameters for the returned fields are *not* needed
1090
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1091
  RETURNS record AS
1092
$BODY$
1093
SELECT ($1.key_field_0, $1.key_field_1)
1094
$BODY$
1095
  LANGUAGE sql IMMUTABLE
1096
  COST 100;
1097
1098
1099 12282 aaronmk
to run EXPLAIN on the FULL JOIN query:
1100
# run this function
1101
# look for a NOTICE containing the expanded query that it ran
1102
# run EXPLAIN on this expanded query
1103 12280 aaronmk
';
1104
1105
1106
--
1107 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1108
--
1109
1110
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1111 12446 aaronmk
    LANGUAGE sql
1112 8200 aaronmk
    AS $_$
1113
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1114
$_$;
1115
1116
1117
--
1118
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1119
--
1120
1121 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1122
idempotent
1123
';
1124 8200 aaronmk
1125
1126
--
1127 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1128 10362 aaronmk
--
1129
1130 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1131 12446 aaronmk
    LANGUAGE sql
1132 10362 aaronmk
    AS $_$
1133
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1134 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1135 10362 aaronmk
$_$;
1136
1137
1138
--
1139 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1140 10362 aaronmk
--
1141
1142 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1143 12235 aaronmk
idempotent
1144
';
1145 10362 aaronmk
1146
1147
--
1148 12331 aaronmk
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1149
--
1150
1151
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1152
    LANGUAGE sql
1153
    AS $_$
1154 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1155
included in the debug SQL */
1156
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1157 12331 aaronmk
$_$;
1158
1159
1160
--
1161 12343 aaronmk
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1162
--
1163
1164 12364 aaronmk
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1165 12343 aaronmk
    LANGUAGE sql
1166
    AS $_$
1167 12347 aaronmk
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1168 12343 aaronmk
||util._if($3, $$ CASCADE$$, ''::text))
1169
$_$;
1170
1171
1172
--
1173 12364 aaronmk
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1174 12343 aaronmk
--
1175
1176 12364 aaronmk
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1177 12343 aaronmk
idempotent
1178
';
1179
1180
1181
--
1182 12413 aaronmk
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1183
--
1184
1185
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1186
    LANGUAGE sql
1187
    AS $_$
1188 12502 aaronmk
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1189 12413 aaronmk
$_$;
1190
1191
1192
--
1193
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1194
--
1195
1196
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1197
    LANGUAGE sql
1198
    AS $_$
1199
SELECT util.drop_relation(relation, $3)
1200
FROM util.show_relations_like($1, $2) relation
1201
;
1202
SELECT NULL::void; -- don't fold away functions called in previous query
1203
$_$;
1204
1205
1206
--
1207 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1208 10150 aaronmk
--
1209
1210 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1211 12446 aaronmk
    LANGUAGE sql
1212 10150 aaronmk
    AS $_$
1213 12347 aaronmk
SELECT util.drop_relation('TABLE', $1, $2)
1214 10150 aaronmk
$_$;
1215
1216
1217
--
1218 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1219 10150 aaronmk
--
1220
1221 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1222 12235 aaronmk
idempotent
1223
';
1224 10150 aaronmk
1225
1226
--
1227 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1228 12229 aaronmk
--
1229
1230 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1231 12446 aaronmk
    LANGUAGE sql
1232 12229 aaronmk
    AS $_$
1233 12347 aaronmk
SELECT util.drop_relation('VIEW', $1, $2)
1234 12229 aaronmk
$_$;
1235
1236
1237
--
1238 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1239 12229 aaronmk
--
1240
1241 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1242 12235 aaronmk
idempotent
1243
';
1244 12229 aaronmk
1245
1246
--
1247 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1248
--
1249
1250
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1251
    LANGUAGE sql IMMUTABLE
1252
    AS $_$
1253
SELECT util.array_fill($1, 0)
1254
$_$;
1255
1256
1257
--
1258
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1259
--
1260
1261 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1262
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1263
';
1264 10322 aaronmk
1265
1266
--
1267 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1268 8086 aaronmk
--
1269
1270
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1271 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1272 8086 aaronmk
    AS $_$
1273 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1274 8086 aaronmk
$_$;
1275
1276
1277
--
1278 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1279
--
1280
1281
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1282
    LANGUAGE sql IMMUTABLE
1283
    AS $_$
1284
SELECT regexp_replace($2, '("?)$', $1||'\1')
1285
$_$;
1286
1287
1288
--
1289 12531 aaronmk
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1290 9824 aaronmk
--
1291
1292 12531 aaronmk
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1293 9824 aaronmk
    LANGUAGE plpgsql STRICT
1294
    AS $$
1295
BEGIN
1296 12531 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1297 12251 aaronmk
	EXECUTE sql;
1298 9824 aaronmk
END;
1299
$$;
1300
1301
1302
--
1303 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1304
--
1305
1306
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1307
    LANGUAGE plpgsql
1308
    AS $$
1309
BEGIN
1310 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1311 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1312
END;
1313
$$;
1314
1315
1316
--
1317
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1318
--
1319
1320 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1321
col_type_null (*required*): NULL::col_type
1322
';
1323 12181 aaronmk
1324
1325
--
1326 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1327
--
1328
1329
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1330
    LANGUAGE plpgsql
1331
    AS $$
1332
BEGIN
1333
	PERFORM util.debug_print_sql(sql);
1334
	RETURN QUERY EXECUTE sql;
1335
END;
1336
$$;
1337
1338
1339
--
1340 12458 aaronmk
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1341 10363 aaronmk
--
1342
1343 12458 aaronmk
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1344 10363 aaronmk
    LANGUAGE plpgsql
1345
    AS $$
1346
BEGIN
1347 12458 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1348 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1349
END;
1350
$$;
1351
1352
1353
--
1354 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1355 10128 aaronmk
--
1356
1357 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1358 12514 aaronmk
    LANGUAGE plpgsql STABLE
1359 10128 aaronmk
    AS $$
1360
DECLARE
1361
	ret_val ret_type_null%TYPE;
1362
BEGIN
1363 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1364 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1365
	RETURN ret_val;
1366
END;
1367
$$;
1368
1369
1370
--
1371 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1372 10128 aaronmk
--
1373
1374 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1375
ret_type_null: NULL::ret_type
1376
';
1377 10128 aaronmk
1378
1379
--
1380 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1381
--
1382
1383
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1384
    LANGUAGE sql
1385
    AS $_$
1386 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1387 10131 aaronmk
$_$;
1388
1389
1390
--
1391
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1392
--
1393
1394 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1395
ret_type_null: NULL::ret_type
1396
';
1397 10131 aaronmk
1398
1399
--
1400 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1401
--
1402
1403
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1404
    LANGUAGE sql
1405
    AS $_$
1406
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1407
$_$;
1408
1409
1410
--
1411
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1412
--
1413
1414 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1415
sql: can be NULL, which will be passed through
1416
ret_type_null: NULL::ret_type
1417
';
1418 10133 aaronmk
1419
1420
--
1421 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1422 8182 aaronmk
--
1423
1424
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1425 12446 aaronmk
    LANGUAGE sql STABLE
1426 8182 aaronmk
    AS $_$
1427
SELECT col_name
1428
FROM unnest($2) s (col_name)
1429 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1430 8182 aaronmk
$_$;
1431
1432
1433
--
1434 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1435
--
1436
1437
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1438
    LANGUAGE sql
1439
    AS $_$
1440 12459 aaronmk
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1441 11830 aaronmk
$_$;
1442
1443
1444
--
1445 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1446
--
1447
1448
CREATE FUNCTION explain2notice(sql text) RETURNS void
1449 12449 aaronmk
    LANGUAGE sql
1450
    AS $_$
1451 12534 aaronmk
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1452 12449 aaronmk
$_$;
1453 12448 aaronmk
1454
1455
--
1456
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1457
--
1458
1459
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1460
    LANGUAGE sql
1461
    AS $_$
1462 12464 aaronmk
-- newline before and after to visually separate it from other debug info
1463
SELECT $$
1464
EXPLAIN:
1465
$$||util.explain2str($1)||$$
1466
$$
1467 11833 aaronmk
$_$;
1468
1469
1470
--
1471 12452 aaronmk
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1472
--
1473
1474
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1475
    LANGUAGE sql
1476
    AS $_$
1477
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1478
$_$;
1479
1480
1481
--
1482 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1483
--
1484
1485
CREATE FUNCTION explain2str(sql text) RETURNS text
1486
    LANGUAGE sql
1487
    AS $_$
1488
SELECT util.join_strs(explain, $$
1489
$$) FROM util.explain($1)
1490
$_$;
1491
1492
1493 11835 aaronmk
SET default_tablespace = '';
1494
1495
SET default_with_oids = false;
1496
1497 11832 aaronmk
--
1498 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1499 11831 aaronmk
--
1500
1501 11835 aaronmk
CREATE TABLE explain (
1502
    line text NOT NULL
1503
);
1504
1505
1506
--
1507
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1508
--
1509
1510
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1511 11831 aaronmk
    LANGUAGE sql
1512
    AS $_$
1513 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1514
$$||quote_nullable($1)||$$
1515 11831 aaronmk
)$$)
1516
$_$;
1517
1518
1519
--
1520 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1521
--
1522
1523 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1524
usage:
1525 11836 aaronmk
PERFORM util.explain2table($$
1526
query
1527 12235 aaronmk
$$);
1528
';
1529 11836 aaronmk
1530
1531
--
1532 12450 aaronmk
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1533
--
1534
1535
CREATE FUNCTION first_word(str text) RETURNS text
1536
    LANGUAGE sql IMMUTABLE
1537
    AS $_$
1538 12461 aaronmk
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1539 12450 aaronmk
$_$;
1540
1541
1542
--
1543 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1544
--
1545
1546
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1547 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1548 10323 aaronmk
    AS $_$
1549 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1550
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1551
) END
1552 10323 aaronmk
$_$;
1553
1554
1555
--
1556
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1557
--
1558
1559 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1560
ensures that an array will always have proper non-NULL dimensions
1561
';
1562 10323 aaronmk
1563
1564
--
1565 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1566
--
1567
1568
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1569
    LANGUAGE plpgsql
1570
    AS $_$
1571
DECLARE
1572
	PG_EXCEPTION_DETAIL text;
1573
	recreate_users_cmd text = util.save_drop_views(users);
1574
BEGIN
1575
	PERFORM util.eval(cmd);
1576
	PERFORM util.eval(recreate_users_cmd);
1577
EXCEPTION
1578
WHEN dependent_objects_still_exist THEN
1579
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1580
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1581
	users = array(SELECT * FROM util.regexp_matches_group(
1582
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1583
	IF util.is_empty(users) THEN RAISE; END IF;
1584
	PERFORM util.force_recreate(cmd, users);
1585
END;
1586
$_$;
1587
1588
1589
--
1590
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1591
--
1592
1593 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1594
idempotent
1595 11695 aaronmk
1596 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1597
';
1598 11695 aaronmk
1599
1600
--
1601 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1602
--
1603
1604
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1605
    LANGUAGE plpgsql STRICT
1606
    AS $_$
1607
DECLARE
1608
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1609
$$||query;
1610
BEGIN
1611
	EXECUTE mk_view;
1612
EXCEPTION
1613
WHEN invalid_table_definition THEN
1614 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1615
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1616
	THEN
1617 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1618
		EXECUTE mk_view;
1619
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1620
	END IF;
1621
END;
1622
$_$;
1623
1624
1625
--
1626
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1627
--
1628
1629 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1630
idempotent
1631
';
1632 8321 aaronmk
1633
1634
--
1635 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1636
--
1637
1638
CREATE FUNCTION grants_users() RETURNS SETOF text
1639
    LANGUAGE sql IMMUTABLE
1640
    AS $$
1641
VALUES ('bien_read'), ('public_')
1642
$$;
1643
1644
1645
--
1646 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1647 8085 aaronmk
--
1648
1649
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1650 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1651 8085 aaronmk
    AS $_$
1652
SELECT substring($2 for length($1)) = $1
1653
$_$;
1654
1655
1656
--
1657 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1658
--
1659
1660
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1661
    LANGUAGE sql STABLE
1662
    AS $_$
1663
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1664
$_$;
1665
1666
1667
--
1668 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1669
--
1670
1671
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1672
    LANGUAGE sql IMMUTABLE
1673
    AS $_$
1674 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1675 10307 aaronmk
$_$;
1676
1677
1678
--
1679
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1680
--
1681
1682 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1683
avoids repeating the same value for each key
1684
';
1685 10307 aaronmk
1686
1687
--
1688 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1689
--
1690
1691
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1692
    LANGUAGE sql IMMUTABLE
1693
    AS $_$
1694 12222 aaronmk
SELECT COALESCE($1, $2)
1695 12218 aaronmk
$_$;
1696
1697
1698
--
1699
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1700
--
1701
1702 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1703
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1704
';
1705 12218 aaronmk
1706
1707
--
1708 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1709
--
1710
1711
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1712
    LANGUAGE sql
1713
    AS $_$
1714
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1715
$_$;
1716
1717
1718
--
1719 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1720
--
1721
1722
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1723 12446 aaronmk
    LANGUAGE sql STABLE
1724 10137 aaronmk
    AS $_$
1725
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1726
$_$;
1727
1728
1729
--
1730 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1731
--
1732
1733
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1734
    LANGUAGE sql IMMUTABLE
1735
    AS $_$
1736
SELECT util.array_length($1) = 0
1737
$_$;
1738
1739
1740
--
1741 12457 aaronmk
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1742
--
1743
1744
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1745
    LANGUAGE sql IMMUTABLE
1746
    AS $_$
1747
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1748
$_$;
1749
1750
1751
--
1752 12451 aaronmk
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1753
--
1754
1755
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1756
    LANGUAGE sql IMMUTABLE
1757
    AS $_$
1758
SELECT upper(util.first_word($1)) = ANY(
1759
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1760
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1761
)
1762
$_$;
1763
1764
1765
--
1766 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1767
--
1768
1769
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1770
    LANGUAGE sql IMMUTABLE
1771
    AS $_$
1772
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1773
$_$;
1774
1775
1776
--
1777 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779
1780
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1781
    LANGUAGE sql IMMUTABLE
1782
    AS $_$
1783
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1784
$_$;
1785
1786
1787
--
1788 12480 aaronmk
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1789
--
1790
1791
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1792
    LANGUAGE sql IMMUTABLE
1793
    AS $_$
1794
SELECT upper(util.first_word($1)) = 'SET'
1795
$_$;
1796
1797
1798
--
1799 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1800
--
1801
1802
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1803 12332 aaronmk
    LANGUAGE sql STABLE
1804 12330 aaronmk
    AS $_$
1805
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1806
$_$;
1807
1808
1809
--
1810 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1811
--
1812
1813
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1814 12332 aaronmk
    LANGUAGE sql STABLE
1815 12329 aaronmk
    AS $_$
1816
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1817
$_$;
1818
1819
1820
--
1821 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1822 4009 aaronmk
--
1823
1824 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1825 12444 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1826 4009 aaronmk
    AS $_$
1827 4054 aaronmk
SELECT $1 || $3 || $2
1828 2595 aaronmk
$_$;
1829
1830
1831
--
1832 12444 aaronmk
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1833
--
1834
1835
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1836
must be declared STRICT to use the special handling of STRICT aggregating functions
1837
';
1838
1839
1840
--
1841 12436 aaronmk
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1842
--
1843
1844
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1845
    LANGUAGE sql IMMUTABLE
1846
    AS $_$
1847
SELECT $1 -- compare on the entire value
1848
$_$;
1849
1850
1851
--
1852 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1853 10985 aaronmk
--
1854
1855 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1856 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1857
    AS $_$
1858 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1859 10985 aaronmk
$_$;
1860
1861
1862
--
1863 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1864
--
1865
1866
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1867
    LANGUAGE sql IMMUTABLE
1868
    AS $_$
1869
SELECT ltrim($1, $$
1870
$$)
1871
$_$;
1872
1873
1874
--
1875 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1876
--
1877
1878
CREATE FUNCTION map_filter_insert() RETURNS trigger
1879
    LANGUAGE plpgsql
1880
    AS $$
1881
BEGIN
1882
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1883
	RETURN new;
1884
END;
1885
$$;
1886
1887
1888
--
1889 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1890 8146 aaronmk
--
1891
1892
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1893
    LANGUAGE plpgsql STABLE STRICT
1894
    AS $_$
1895
DECLARE
1896
    value text;
1897
BEGIN
1898
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1899 8149 aaronmk
        INTO value USING key;
1900 8146 aaronmk
    RETURN value;
1901
END;
1902
$_$;
1903
1904
1905
--
1906 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1907 10325 aaronmk
--
1908
1909 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1910 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1911 10325 aaronmk
    AS $_$
1912 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1913 10325 aaronmk
$_$;
1914
1915
1916
--
1917 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1918
--
1919
1920 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1921
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1922 10359 aaronmk
1923
[1] inlining of function calls, which is different from constant folding
1924
[2] _map()''s profiling query
1925
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1926
and map_nulls()''s profiling query
1927
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1928 10375 aaronmk
both take ~920 ms.
1929 12235 aaronmk
also, /inputs/REMIB/Specimen/postprocess.sql > country takes the same amount of time (56000 ms) to build with map_nulls() as with a literal hstore.
1930
';
1931 10359 aaronmk
1932
1933
--
1934 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1935 8150 aaronmk
--
1936
1937
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1938
    LANGUAGE plpgsql STABLE STRICT
1939
    AS $_$
1940
BEGIN
1941
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1942
END;
1943
$_$;
1944
1945
1946
--
1947 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1948
--
1949
1950 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1951 12228 aaronmk
    LANGUAGE sql
1952
    AS $_$
1953 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1954 12321 aaronmk
$$||util.ltrim_nl($2));
1955
-- make sure the created table has the correct estimated row count
1956
SELECT util.analyze_($1);
1957 12470 aaronmk
1958
SELECT util.append_comment($1, '
1959
contents generated from:
1960
'||util.ltrim_nl($2)||';
1961
');
1962 12228 aaronmk
$_$;
1963
1964
1965
--
1966 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1967 12228 aaronmk
--
1968
1969 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1970 12235 aaronmk
idempotent
1971
';
1972 12228 aaronmk
1973
1974
--
1975 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1976
--
1977
1978 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1979 12234 aaronmk
    LANGUAGE sql
1980
    AS $_$
1981
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1982
$_$;
1983
1984
1985
--
1986 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1987 12234 aaronmk
--
1988
1989 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1990 12235 aaronmk
idempotent
1991
';
1992 12234 aaronmk
1993
1994
--
1995 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1996
--
1997
1998
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1999 12446 aaronmk
    LANGUAGE sql
2000 8190 aaronmk
    AS $_$
2001 10135 aaronmk
SELECT util.create_if_not_exists($$
2002
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2003 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2004 10135 aaronmk
||quote_literal($2)||$$;
2005 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2006
constant
2007
';
2008 10135 aaronmk
$$)
2009 8190 aaronmk
$_$;
2010
2011
2012
--
2013
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2014
--
2015
2016 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2017
idempotent
2018
';
2019 8190 aaronmk
2020
2021
--
2022 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2023 8187 aaronmk
--
2024
2025 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2026 8187 aaronmk
    LANGUAGE plpgsql STRICT
2027
    AS $_$
2028
DECLARE
2029
    type regtype = util.typeof(expr, col.table_::text::regtype);
2030
    col_name_sql text = quote_ident(col.name);
2031
BEGIN
2032 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2033
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2034 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2035
$$||expr||$$;
2036
$$);
2037
END;
2038
$_$;
2039
2040
2041
--
2042 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2043 8188 aaronmk
--
2044
2045 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2046
idempotent
2047
';
2048 8188 aaronmk
2049
2050
--
2051 12554 aaronmk
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2052 12475 aaronmk
--
2053
2054 12554 aaronmk
CREATE FUNCTION mk_diff_query(left_ text, right_ text, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2055 12475 aaronmk
    LANGUAGE sql IMMUTABLE
2056
    AS $_$
2057
SELECT
2058 12478 aaronmk
$$SELECT
2059 12554 aaronmk
$$||$3||$$
2060 12555 aaronmk
FROM      $$||$1||$$ left_
2061 12554 aaronmk
FULL JOIN $$||$2||$$ right_
2062
ON $$||$4||$$
2063
WHERE $$||$5||$$
2064 12475 aaronmk
ORDER BY left_, right_
2065
$$
2066
$_$;
2067
2068
2069
--
2070 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2071 8139 aaronmk
--
2072
2073
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2074 12446 aaronmk
    LANGUAGE sql
2075 8139 aaronmk
    AS $_$
2076 8183 aaronmk
SELECT util.create_if_not_exists($$
2077 8141 aaronmk
CREATE TABLE $$||$1||$$
2078 8139 aaronmk
(
2079 8183 aaronmk
    LIKE util.map INCLUDING ALL
2080 10110 aaronmk
);
2081
2082
CREATE TRIGGER map_filter_insert
2083
  BEFORE INSERT
2084
  ON $$||$1||$$
2085
  FOR EACH ROW
2086
  EXECUTE PROCEDURE util.map_filter_insert();
2087 8141 aaronmk
$$)
2088 8139 aaronmk
$_$;
2089
2090
2091
--
2092 12556 aaronmk
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2093
--
2094
2095
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2096
    LANGUAGE sql IMMUTABLE
2097
    AS $_$
2098
SELECT string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2099
util.qual_name((unnest).type), '')
2100
FROM unnest($1)
2101
$_$;
2102
2103
2104
--
2105 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2106
--
2107
2108
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2109
    LANGUAGE sql IMMUTABLE
2110
    AS $_$
2111 12486 aaronmk
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2112 12236 aaronmk
$_$;
2113
2114
2115
--
2116 12486 aaronmk
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2117
--
2118
2119
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2120
auto-appends util to the search_path to enable use of util operators
2121
';
2122
2123
2124
--
2125 12467 aaronmk
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2126
--
2127
2128
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2129
    LANGUAGE sql IMMUTABLE
2130
    AS $_$
2131
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2132
$_$;
2133
2134
2135
--
2136 12466 aaronmk
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2137 12270 aaronmk
--
2138
2139 12466 aaronmk
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2140 12270 aaronmk
    LANGUAGE sql IMMUTABLE
2141
    AS $_$
2142 12432 aaronmk
/* debug_print_return_value() needed because this function is used with EXECUTE
2143
rather than util.eval() (in order to affect the calling function), so the
2144
search_path would not otherwise be printed */
2145 12487 aaronmk
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2146
||$$ search_path TO $$||$1
2147 12270 aaronmk
$_$;
2148
2149
2150
--
2151 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2152
--
2153
2154
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2155 12446 aaronmk
    LANGUAGE sql
2156 10113 aaronmk
    AS $_$
2157 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2158 10113 aaronmk
$_$;
2159
2160
2161
--
2162
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2163
--
2164
2165 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2166
idempotent
2167
';
2168 10113 aaronmk
2169
2170
--
2171 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2172
--
2173
2174
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2175
    LANGUAGE plpgsql STRICT
2176
    AS $_$
2177
DECLARE
2178
	view_qual_name text = util.qual_name(view_);
2179
BEGIN
2180
	EXECUTE $$
2181
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2182
  RETURNS SETOF $$||view_||$$ AS
2183
$BODY1$
2184
SELECT * FROM $$||view_qual_name||$$
2185
ORDER BY sort_col
2186
LIMIT $1 OFFSET $2
2187
$BODY1$
2188
  LANGUAGE sql STABLE
2189
  COST 100
2190
  ROWS 1000
2191
$$;
2192
2193
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2194
END;
2195
$_$;
2196
2197
2198
--
2199 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2200
--
2201
2202
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2203
    LANGUAGE plpgsql STRICT
2204
    AS $_$
2205 10990 aaronmk
DECLARE
2206
	view_qual_name text = util.qual_name(view_);
2207
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2208 8325 aaronmk
BEGIN
2209
	EXECUTE $$
2210 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2211
  RETURNS integer AS
2212
$BODY1$
2213
SELECT $$||quote_ident(row_num_col)||$$
2214
FROM $$||view_qual_name||$$
2215
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2216
LIMIT 1
2217
$BODY1$
2218
  LANGUAGE sql STABLE
2219
  COST 100;
2220
$$;
2221
2222
	EXECUTE $$
2223 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2224
  RETURNS SETOF $$||view_||$$ AS
2225
$BODY1$
2226 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
2227
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2228
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2229
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2230 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
2231 8325 aaronmk
$BODY1$
2232
  LANGUAGE sql STABLE
2233
  COST 100
2234
  ROWS 1000
2235
$$;
2236 11010 aaronmk
2237
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2238
END;
2239
$_$;
2240
2241
2242
--
2243
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2244
--
2245
2246
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2247
    LANGUAGE plpgsql STRICT
2248
    AS $_$
2249
DECLARE
2250
	view_qual_name text = util.qual_name(view_);
2251
BEGIN
2252 8326 aaronmk
	EXECUTE $$
2253
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2254
  RETURNS SETOF $$||view_||$$
2255
  SET enable_sort TO 'off'
2256
  AS
2257
$BODY1$
2258 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2259 8326 aaronmk
$BODY1$
2260
  LANGUAGE sql STABLE
2261
  COST 100
2262
  ROWS 1000
2263
;
2264
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2265
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2266
If you want to run EXPLAIN and get expanded output, use the regular subset
2267
function instead. (When a config param is set on a function, EXPLAIN produces
2268
just a function scan.)
2269
';
2270
$$;
2271 8325 aaronmk
END;
2272
$_$;
2273
2274
2275
--
2276 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2277
--
2278
2279 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2280
creates subset function which turns off enable_sort
2281
';
2282 11010 aaronmk
2283
2284
--
2285 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2286
--
2287
2288
CREATE FUNCTION name(table_ regclass) RETURNS text
2289
    LANGUAGE sql STABLE
2290
    AS $_$
2291
SELECT relname::text FROM pg_class WHERE oid = $1
2292
$_$;
2293
2294
2295
--
2296 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2297 8083 aaronmk
--
2298
2299
CREATE FUNCTION name(type regtype) RETURNS text
2300 12446 aaronmk
    LANGUAGE sql STABLE
2301 8083 aaronmk
    AS $_$
2302
SELECT typname::text FROM pg_type WHERE oid = $1
2303
$_$;
2304
2305
2306
--
2307 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2308 12355 aaronmk
--
2309
2310 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2311 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2312
    AS $_$
2313 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2314 12355 aaronmk
$_$;
2315
2316
2317
--
2318 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2319
--
2320
2321
CREATE FUNCTION namedatalen() RETURNS integer
2322
    LANGUAGE sql IMMUTABLE
2323
    AS $$
2324
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2325
$$;
2326
2327
2328
--
2329 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2330
--
2331
2332
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2333
    LANGUAGE sql IMMUTABLE
2334
    AS $_$
2335 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2336 9958 aaronmk
$_$;
2337
2338
2339
--
2340 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2341
--
2342
2343
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2344 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2345 9956 aaronmk
    AS $_$
2346
SELECT $1 IS NOT NULL
2347
$_$;
2348
2349
2350
--
2351 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2352
--
2353
2354
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2355
    LANGUAGE sql IMMUTABLE
2356
    AS $_$
2357
SELECT util.hstore($1, NULL) || '*=>*'
2358
$_$;
2359
2360
2361
--
2362
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2363
--
2364
2365 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2366
for use with _map()
2367
';
2368 10373 aaronmk
2369
2370
--
2371 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2372 10984 aaronmk
--
2373
2374 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2375 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2376
    AS $_$
2377 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2378 10984 aaronmk
$_$;
2379
2380
2381
--
2382 12494 aaronmk
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2383
--
2384
2385
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2386
    LANGUAGE sql
2387
    AS $_$
2388
SELECT util.set_comment($1, concat($2, util.comment($1)))
2389
$_$;
2390
2391
2392
--
2393
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2394
--
2395
2396
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2397
comment: must start and end with a newline
2398
';
2399
2400
2401
--
2402 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2403
--
2404
2405
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2406
    LANGUAGE sql IMMUTABLE
2407
    AS $_$
2408
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2409
$_$;
2410
2411
2412
--
2413 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2414
--
2415
2416
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2417 12446 aaronmk
    LANGUAGE sql STABLE
2418 12267 aaronmk
    SET search_path TO pg_temp
2419 10988 aaronmk
    AS $_$
2420 12267 aaronmk
SELECT $1::text
2421 10988 aaronmk
$_$;
2422
2423
2424
--
2425 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2426
--
2427
2428
CREATE FUNCTION qual_name(type regtype) RETURNS text
2429 12446 aaronmk
    LANGUAGE sql STABLE
2430 12267 aaronmk
    SET search_path TO pg_temp
2431
    AS $_$
2432
SELECT $1::text
2433
$_$;
2434
2435
2436
--
2437
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2438
--
2439
2440
COMMENT ON FUNCTION qual_name(type regtype) IS '
2441
a type''s schema-qualified name
2442
';
2443
2444
2445
--
2446 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2447
--
2448
2449
CREATE FUNCTION qual_name(type unknown) RETURNS text
2450 12446 aaronmk
    LANGUAGE sql STABLE
2451 12268 aaronmk
    AS $_$
2452
SELECT util.qual_name($1::text::regtype)
2453
$_$;
2454
2455
2456
--
2457 12376 aaronmk
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2458
--
2459
2460
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2461
    LANGUAGE sql IMMUTABLE
2462
    AS $_$
2463
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2464
$_$;
2465
2466
2467
--
2468
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2469
--
2470
2471
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2472
    LANGUAGE sql IMMUTABLE
2473
    AS $_$
2474
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2475
$_$;
2476
2477
2478
--
2479 12371 aaronmk
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2480
--
2481
2482
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2483
    LANGUAGE sql IMMUTABLE
2484
    AS $_$
2485 12437 aaronmk
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2486 12371 aaronmk
$_$;
2487
2488
2489
--
2490 12530 aaronmk
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2491
--
2492
2493
CREATE FUNCTION raise(type text, msg text) RETURNS void
2494
    LANGUAGE sql IMMUTABLE
2495
    AS $_$
2496
SELECT util.eval($$
2497
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2498
  RETURNS void AS
2499
$BODY1$
2500
BEGIN
2501
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2502
END;
2503
$BODY1$
2504
  LANGUAGE plpgsql IMMUTABLE
2505
  COST 100;
2506 12532 aaronmk
$$, verbose_ := false);
2507 12530 aaronmk
2508 12532 aaronmk
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2509 12530 aaronmk
$_$;
2510
2511
2512
--
2513 12533 aaronmk
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2514
--
2515
2516
COMMENT ON FUNCTION raise(type text, msg text) IS '
2517
type: a log level from
2518
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2519
or a condition name from
2520
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2521
';
2522
2523
2524
--
2525 12536 aaronmk
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2526 12311 aaronmk
--
2527
2528 12536 aaronmk
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2529 12441 aaronmk
    LANGUAGE sql IMMUTABLE
2530 12311 aaronmk
    AS $_$
2531 12536 aaronmk
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2532 12311 aaronmk
$_$;
2533
2534
2535
--
2536 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2537
--
2538
2539
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2540
    LANGUAGE plpgsql IMMUTABLE STRICT
2541
    AS $$
2542
BEGIN
2543
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2544
END;
2545
$$;
2546
2547
2548
--
2549 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2550
--
2551
2552
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2553
    LANGUAGE sql IMMUTABLE
2554
    AS $_$
2555
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2556
$_$;
2557
2558
2559
--
2560 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2561
--
2562
2563
CREATE FUNCTION regexp_quote(str text) RETURNS text
2564
    LANGUAGE sql IMMUTABLE
2565
    AS $_$
2566
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2567
$_$;
2568
2569
2570
--
2571 12375 aaronmk
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2572
--
2573
2574
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2575
    LANGUAGE sql IMMUTABLE
2576
    AS $_$
2577
SELECT (CASE WHEN right($1, 1) = ')'
2578 12377 aaronmk
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2579 12375 aaronmk
$_$;
2580
2581
2582
--
2583 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2584
--
2585
2586
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2587
    LANGUAGE sql STABLE
2588
    AS $_$
2589
SELECT util.relation_type(util.relation_type_char($1))
2590
$_$;
2591
2592
2593
--
2594 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2595 12339 aaronmk
--
2596
2597 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2598 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2599
    AS $_$
2600
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2601
$_$;
2602
2603
2604
--
2605 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2606
--
2607
2608
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2609
    LANGUAGE sql STABLE
2610
    AS $_$
2611
SELECT relkind FROM pg_class WHERE oid = $1
2612
$_$;
2613
2614
2615
--
2616 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2617
--
2618
2619
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2620
    LANGUAGE sql
2621
    AS $_$
2622
/* can't have in_table/out_table inherit from *each other*, because inheritance
2623
also causes the rows of the parent table to be included in the child table.
2624
instead, they need to inherit from a common, empty table. */
2625 12382 aaronmk
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2626
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2627 12293 aaronmk
SELECT util.inherit($2, $4);
2628
SELECT util.inherit($3, $4);
2629
2630
SELECT util.rematerialize_query($1, $$
2631
SELECT * FROM util.diff(
2632 12419 aaronmk
  $$||util.quote_typed($2)||$$
2633
, $$||util.quote_typed($3)||$$
2634 12293 aaronmk
, NULL::$$||$4||$$)
2635
$$);
2636 12303 aaronmk
2637
/* the table unfortunately cannot be *materialized* in human-readable form,
2638
because this would create column name collisions between the two sides */
2639 12495 aaronmk
SELECT util.prepend_comment($1, '
2640 12303 aaronmk
to view this table in human-readable form (with each side''s tuple column
2641
expanded to its component fields):
2642
SELECT (left_).*, (right_).* FROM '||$1||';
2643
');
2644 12293 aaronmk
$_$;
2645
2646
2647
--
2648
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2649
--
2650
2651
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2652
type_table (*required*): table to create as the shared base type
2653
';
2654
2655
2656
--
2657 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2658
--
2659
2660
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2661
    LANGUAGE sql
2662
    AS $_$
2663
SELECT util.drop_table($1);
2664
SELECT util.materialize_query($1, $2);
2665
$_$;
2666
2667
2668
--
2669
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2670
--
2671
2672
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2673
idempotent, but repeats action each time
2674
';
2675
2676
2677
--
2678 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2679
--
2680
2681 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2682 12247 aaronmk
    LANGUAGE sql
2683
    AS $_$
2684
SELECT util.drop_table($1);
2685
SELECT util.materialize_view($1, $2);
2686
$_$;
2687
2688
2689
--
2690 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2691 12247 aaronmk
--
2692
2693 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2694 12247 aaronmk
idempotent, but repeats action each time
2695
';
2696
2697
2698
--
2699 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2700 8137 aaronmk
--
2701
2702 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2703 12446 aaronmk
    LANGUAGE sql
2704 8137 aaronmk
    AS $_$
2705 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2706 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2707 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
2708
SELECT NULL::void; -- don't fold away functions called in previous query
2709 8137 aaronmk
$_$;
2710
2711
2712
--
2713 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2714 8137 aaronmk
--
2715
2716 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2717
idempotent
2718
';
2719 8137 aaronmk
2720
2721
--
2722 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2723
--
2724
2725
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2726
    LANGUAGE sql
2727
    AS $_$
2728 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2729
included in the debug SQL */
2730
SELECT util.rename_relation(util.qual_name($1), $2)
2731 12349 aaronmk
$_$;
2732
2733
2734
--
2735
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2736
--
2737
2738 12364 aaronmk
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2739 12349 aaronmk
    LANGUAGE sql
2740
    AS $_$
2741
/* 'ALTER TABLE can be used with views too'
2742
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2743 12363 aaronmk
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2744
||quote_ident($2))
2745 12349 aaronmk
$_$;
2746
2747
2748
--
2749 12364 aaronmk
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2750 12349 aaronmk
--
2751
2752 12364 aaronmk
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2753 12349 aaronmk
idempotent
2754
';
2755
2756
2757
--
2758 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2759 12350 aaronmk
--
2760
2761 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2762 12350 aaronmk
    LANGUAGE sql IMMUTABLE
2763
    AS $_$
2764 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2765 12350 aaronmk
$_$;
2766
2767
2768
--
2769 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2770
--
2771
2772
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2773
max_prefix_len: when str may have been truncated (eg. as a table name) due to the prepending of a prefix, support prefixes up to this length
2774
';
2775
2776
2777
--
2778 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2779
--
2780
2781
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2782 12446 aaronmk
    LANGUAGE sql
2783 10297 aaronmk
    AS $_$
2784 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2785
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2786 10297 aaronmk
SELECT util.set_col_names($1, $2);
2787
$_$;
2788
2789
2790
--
2791
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2792
--
2793
2794 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2795
idempotent.
2796
alters the names table, so it will need to be repopulated after running this function.
2797
';
2798 10297 aaronmk
2799
2800
--
2801 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2802 8143 aaronmk
--
2803
2804
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2805 12446 aaronmk
    LANGUAGE sql
2806 8143 aaronmk
    AS $_$
2807 10152 aaronmk
SELECT util.drop_table($1);
2808 8183 aaronmk
SELECT util.mk_map_table($1);
2809 8143 aaronmk
$_$;
2810
2811
2812
--
2813 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2814
--
2815
2816
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2817
    LANGUAGE sql IMMUTABLE
2818
    AS $_$
2819
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2820
$_$;
2821
2822
2823
--
2824 12473 aaronmk
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2825
--
2826
2827
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2828
    LANGUAGE sql IMMUTABLE
2829
    AS $_$
2830 12481 aaronmk
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
2831
ELSE util.mk_set_search_path(for_printing := true)||$$;
2832
$$ END)||$1
2833 12473 aaronmk
$_$;
2834
2835
2836
--
2837 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2838
--
2839
2840
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2841
    LANGUAGE plpgsql STRICT
2842
    AS $_$
2843
DECLARE
2844
	result text = NULL;
2845
BEGIN
2846
	BEGIN
2847
		result = util.show_create_view(view_);
2848
		PERFORM util.eval($$DROP VIEW $$||view_);
2849
	EXCEPTION
2850
		WHEN undefined_table THEN NULL;
2851
	END;
2852
	RETURN result;
2853
END;
2854
$_$;
2855
2856
2857
--
2858 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2859
--
2860
2861
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2862
    LANGUAGE sql
2863
    AS $_$
2864 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2865 11660 aaronmk
$_$;
2866
2867
2868
--
2869 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2870
--
2871
2872
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2873
    LANGUAGE sql STABLE
2874
    AS $_$
2875
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2876
$_$;
2877
2878
2879
--
2880 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2881
--
2882
2883
CREATE FUNCTION schema(table_ regclass) RETURNS text
2884
    LANGUAGE sql STABLE
2885
    AS $_$
2886 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2887 12242 aaronmk
$_$;
2888
2889
2890
--
2891 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2892
--
2893
2894
CREATE FUNCTION schema(type regtype) RETURNS text
2895
    LANGUAGE sql STABLE
2896
    AS $_$
2897 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2898 10794 aaronmk
$_$;
2899
2900
2901
--
2902
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2903
--
2904
2905
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2906
    LANGUAGE sql STABLE
2907
    AS $_$
2908
SELECT util.schema(pg_typeof($1))
2909
$_$;
2910
2911
2912
--
2913 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2914
--
2915
2916
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2917
    LANGUAGE sql STABLE
2918
    AS $_$
2919
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2920
$_$;
2921
2922
2923
--
2924 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2925
--
2926
2927 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2928
a schema bundle is a group of schemas with a common prefix
2929
';
2930 12135 aaronmk
2931
2932
--
2933
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2934
--
2935
2936
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2937
    LANGUAGE sql
2938
    AS $_$
2939
SELECT util.schema_rename(old_schema,
2940
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2941
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2942
SELECT NULL::void; -- don't fold away functions called in previous query
2943
$_$;
2944
2945
2946
--
2947
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2948
--
2949
2950
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2951
    LANGUAGE plpgsql
2952
    AS $$
2953
BEGIN
2954
	-- don't schema_bundle_rm() the schema_bundle to keep!
2955
	IF replace = with_ THEN RETURN; END IF;
2956
2957
	PERFORM util.schema_bundle_rm(replace);
2958
	PERFORM util.schema_bundle_rename(with_, replace);
2959
END;
2960
$$;
2961
2962
2963
--
2964
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2965
--
2966
2967
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2968
    LANGUAGE sql
2969
    AS $_$
2970
SELECT util.schema_rm(schema)
2971
FROM util.schema_bundle_get_schemas($1) f (schema);
2972
SELECT NULL::void; -- don't fold away functions called in previous query
2973
$_$;
2974
2975
2976
--
2977 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2978 10795 aaronmk
--
2979
2980 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2981 10795 aaronmk
    LANGUAGE sql STABLE
2982
    AS $_$
2983
SELECT quote_ident(util.schema($1))
2984
$_$;
2985
2986
2987
--
2988 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2989
--
2990
2991
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2992 12334 aaronmk
    LANGUAGE sql IMMUTABLE
2993 12324 aaronmk
    AS $_$
2994
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2995
$_$;
2996
2997
2998
--
2999 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3000
--
3001
3002
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3003
    LANGUAGE sql STABLE
3004
    AS $_$
3005
SELECT oid FROM pg_namespace WHERE nspname = $1
3006
$_$;
3007
3008
3009
--
3010 12504 aaronmk
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3011
--
3012
3013
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3014
    LANGUAGE sql IMMUTABLE
3015
    AS $_$
3016
SELECT util.schema_regexp(schema_anchor := $1)
3017
$_$;
3018
3019
3020
--
3021 12501 aaronmk
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3022
--
3023
3024
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3025
    LANGUAGE sql IMMUTABLE
3026
    AS $_$
3027
SELECT util.str_equality_regexp(util.schema($1))
3028
$_$;
3029
3030
3031
--
3032 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3033
--
3034
3035
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3036
    LANGUAGE sql
3037
    AS $_$
3038
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3039
$_$;
3040
3041
3042
--
3043 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3044
--
3045
3046
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3047
    LANGUAGE plpgsql
3048
    AS $$
3049
BEGIN
3050
	-- don't schema_rm() the schema to keep!
3051
	IF replace = with_ THEN RETURN; END IF;
3052
3053
	PERFORM util.schema_rm(replace);
3054
	PERFORM util.schema_rename(with_, replace);
3055
END;
3056
$$;
3057
3058
3059
--
3060 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3061
--
3062
3063
CREATE FUNCTION schema_rm(schema text) RETURNS void
3064
    LANGUAGE sql
3065
    AS $_$
3066
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3067
$_$;
3068
3069
3070
--
3071 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3072
--
3073
3074
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3075 12446 aaronmk
    LANGUAGE sql
3076 9825 aaronmk
    AS $_$
3077
SELECT util.eval(
3078
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3079
$_$;
3080
3081
3082
--
3083 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3084 8153 aaronmk
--
3085
3086
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3087
    LANGUAGE plpgsql STRICT
3088
    AS $_$
3089
DECLARE
3090 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
3091
    new text[] = ARRAY(SELECT util.map_values(names));
3092 8153 aaronmk
BEGIN
3093
    old = old[1:array_length(new, 1)]; -- truncate to same length
3094 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3095
||$$ TO $$||quote_ident(value))
3096 10149 aaronmk
    FROM each(hstore(old, new))
3097
    WHERE value != key -- not same name
3098
    ;
3099 8153 aaronmk
END;
3100
$_$;
3101
3102
3103
--
3104 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3105 8153 aaronmk
--
3106
3107 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3108
idempotent
3109
';
3110 8153 aaronmk
3111
3112
--
3113 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3114
--
3115
3116
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3117
    LANGUAGE plpgsql STRICT
3118
    AS $_$
3119
DECLARE
3120
	row_ util.map;
3121
BEGIN
3122 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
3123
	BEGIN
3124
		PERFORM util.set_col_names(table_, names);
3125
	EXCEPTION
3126
		WHEN array_subscript_error THEN -- selective suppress
3127
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3128
				-- metadata cols not yet added
3129
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
3130
			END IF;
3131
	END;
3132
3133 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3134 10145 aaronmk
	LOOP
3135 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
3136
			substring(row_."from" from 2));
3137 10145 aaronmk
	END LOOP;
3138
3139
	PERFORM util.set_col_names(table_, names);
3140
END;
3141
$_$;
3142
3143
3144
--
3145
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3146
--
3147
3148 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3149
idempotent.
3150
the metadata mappings must be *last* in the names table.
3151
';
3152 10145 aaronmk
3153
3154
--
3155 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3156 8107 aaronmk
--
3157
3158
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3159
    LANGUAGE plpgsql STRICT
3160
    AS $_$
3161
DECLARE
3162
    sql text = $$ALTER TABLE $$||table_||$$
3163
$$||NULLIF(array_to_string(ARRAY(
3164
    SELECT
3165
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3166
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3167
    FROM
3168
    (
3169
        SELECT
3170
          quote_ident(col_name) AS col_name_sql
3171 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
3172 8107 aaronmk
        , type AS target_type
3173
        FROM unnest(col_casts)
3174
    ) s
3175
    WHERE curr_type != target_type
3176
), '
3177
, '), '');
3178
BEGIN
3179 12251 aaronmk
    PERFORM util.debug_print_sql(sql);
3180 8107 aaronmk
    EXECUTE COALESCE(sql, '');
3181
END;
3182
$_$;
3183
3184
3185
--
3186 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3187 8107 aaronmk
--
3188
3189 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3190
idempotent
3191
';
3192 8107 aaronmk
3193
3194
--
3195 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3196
--
3197
3198
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3199 12446 aaronmk
    LANGUAGE sql
3200 12302 aaronmk
    AS $_$
3201
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3202
$_$;
3203
3204
3205
--
3206 12482 aaronmk
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3207
--
3208
3209
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3210
    LANGUAGE sql
3211
    AS $_$
3212
SELECT util.eval(util.mk_set_search_path($1, $2))
3213
$_$;
3214
3215
3216
--
3217 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3218
--
3219
3220
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3221
    LANGUAGE sql STABLE
3222
    AS $_$
3223 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3224
$$||util.show_grants_for($1)
3225 11651 aaronmk
$_$;
3226
3227
3228
--
3229 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3230
--
3231
3232
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3233
    LANGUAGE sql STABLE
3234
    AS $_$
3235 12269 aaronmk
SELECT string_agg(cmd, '')
3236 11655 aaronmk
FROM
3237
(
3238
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3239
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3240
$$ ELSE '' END) AS cmd
3241
	FROM util.grants_users() f (user_)
3242
) s
3243
$_$;
3244
3245
3246
--
3247 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3248
--
3249
3250
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3251
    LANGUAGE sql STABLE
3252
    AS $_$
3253
SELECT oid FROM pg_class
3254
WHERE relkind = ANY($3) AND relname ~ $1
3255
AND util.schema_matches(util.schema(relnamespace), $2)
3256
ORDER BY relname
3257
$_$;
3258
3259
3260
--
3261 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3262
--
3263
3264 12385 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3265 12305 aaronmk
    LANGUAGE sql STABLE
3266
    AS $_$
3267 12385 aaronmk
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3268 12305 aaronmk
$_$;
3269
3270
3271
--
3272 12384 aaronmk
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3273
--
3274
3275
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3276
    LANGUAGE sql IMMUTABLE
3277
    AS $_$
3278
SELECT '^'||util.regexp_quote($1)||'$'
3279
$_$;
3280
3281
3282
--
3283 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3284 8144 aaronmk
--
3285
3286
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3287 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
3288 8144 aaronmk
    AS $_$
3289
DECLARE
3290
    hstore hstore;
3291
BEGIN
3292
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3293
        table_||$$))$$ INTO STRICT hstore;
3294
    RETURN hstore;
3295
END;
3296
$_$;
3297
3298
3299
--
3300 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3301
--
3302
3303
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3304 12446 aaronmk
    LANGUAGE sql STABLE
3305 10184 aaronmk
    AS $_$
3306
SELECT COUNT(*) > 0 FROM pg_constraint
3307
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3308
$_$;
3309
3310
3311
--
3312
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3313
--
3314
3315 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3316
gets whether a status flag is set by the presence of a table constraint
3317
';
3318 10184 aaronmk
3319
3320
--
3321 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3322
--
3323
3324
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3325 12446 aaronmk
    LANGUAGE sql
3326 10182 aaronmk
    AS $_$
3327
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3328
||quote_ident($2)||$$ CHECK (true)$$)
3329
$_$;
3330
3331
3332
--
3333
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3334
--
3335
3336 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3337
stores a status flag by the presence of a table constraint.
3338
idempotent.
3339
';
3340 10182 aaronmk
3341
3342
--
3343 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3344
--
3345
3346
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3347 12446 aaronmk
    LANGUAGE sql STABLE
3348 10185 aaronmk
    AS $_$
3349
SELECT util.table_flag__get($1, 'nulls_mapped')
3350
$_$;
3351
3352
3353
--
3354
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3355
--
3356
3357 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3358
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3359
';
3360 10185 aaronmk
3361
3362
--
3363 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3364
--
3365
3366
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3367 12446 aaronmk
    LANGUAGE sql
3368 10183 aaronmk
    AS $_$
3369
SELECT util.table_flag__set($1, 'nulls_mapped')
3370
$_$;
3371
3372
3373
--
3374
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3375
--
3376
3377 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3378
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3379
idempotent.
3380
';
3381 10183 aaronmk
3382
3383
--
3384 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3385 8088 aaronmk
--
3386
3387
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3388
    LANGUAGE plpgsql STRICT
3389
    AS $_$
3390
DECLARE
3391
    row record;
3392
BEGIN
3393 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3394 8088 aaronmk
    LOOP
3395
        IF row.global_name != row.name THEN
3396
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3397
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3398
        END IF;
3399
    END LOOP;
3400
END;
3401
$_$;
3402
3403
3404
--
3405 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3406 8088 aaronmk
--
3407
3408 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3409
idempotent
3410
';
3411 8088 aaronmk
3412
3413
--
3414 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3415
--
3416
3417
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3418 12446 aaronmk
    LANGUAGE sql
3419 10365 aaronmk
    AS $_$
3420 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3421 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3422
$_$;
3423
3424
3425
--
3426
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3427
--
3428
3429 12235 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3430
trims table_ to include only columns in the original data.
3431
idempotent.
3432
';
3433 10365 aaronmk
3434
3435
--
3436 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3437 8142 aaronmk
--
3438
3439
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3440
    LANGUAGE plpgsql STRICT
3441
    AS $_$
3442
BEGIN
3443
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3444
END;
3445
$_$;
3446
3447
3448
--
3449 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3450 8142 aaronmk
--
3451
3452 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3453
idempotent
3454
';
3455 8142 aaronmk
3456
3457
--
3458 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3459
--
3460
3461
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3462
    LANGUAGE sql IMMUTABLE
3463
    AS $_$
3464 12361 aaronmk
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3465 12362 aaronmk
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3466 12357 aaronmk
$_$;
3467
3468
3469
--
3470 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3471
--
3472
3473
CREATE FUNCTION try_create(sql text) RETURNS void
3474
    LANGUAGE plpgsql STRICT
3475
    AS $$
3476
BEGIN
3477 10146 aaronmk
    PERFORM util.eval(sql);
3478 8199 aaronmk
EXCEPTION
3479 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3480 8199 aaronmk
    WHEN undefined_column THEN NULL;
3481
    WHEN duplicate_column THEN NULL;
3482
END;
3483
$$;
3484
3485
3486
--
3487
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3488
--
3489
3490 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
3491
idempotent
3492
';
3493 8199 aaronmk
3494
3495
--
3496 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3497
--
3498
3499
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3500 12446 aaronmk
    LANGUAGE sql
3501 8209 aaronmk
    AS $_$
3502
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3503
$_$;
3504
3505
3506
--
3507
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3508
--
3509
3510 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3511
idempotent
3512
';
3513 8209 aaronmk
3514
3515
--
3516 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3517
--
3518
3519
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3520
    LANGUAGE sql IMMUTABLE
3521
    AS $_$
3522
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3523
$_$;
3524
3525
3526
--
3527 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3528
--
3529
3530 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3531
a type''s NOT NULL qualifier
3532
';
3533 10161 aaronmk
3534
3535
--
3536 12438 aaronmk
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3537
--
3538
3539
CREATE FUNCTION typeof(value anyelement) RETURNS text
3540
    LANGUAGE sql IMMUTABLE
3541
    AS $_$
3542
SELECT util.qual_name(pg_typeof($1))
3543
$_$;
3544
3545
3546
--
3547 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3548
--
3549
3550 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3551
    LANGUAGE plpgsql STABLE
3552 8185 aaronmk
    AS $_$
3553
DECLARE
3554
    type regtype;
3555
BEGIN
3556 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3557
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3558 8185 aaronmk
    RETURN type;
3559
END;
3560
$_$;
3561
3562
3563
--
3564 12490 aaronmk
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3565 12483 aaronmk
--
3566
3567 12490 aaronmk
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3568 12483 aaronmk
    LANGUAGE sql
3569
    AS $_$
3570 12488 aaronmk
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3571 12483 aaronmk
$_$;
3572
3573
3574
--
3575 12490 aaronmk
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3576 12488 aaronmk
--
3577
3578 12490 aaronmk
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3579 12488 aaronmk
auto-appends util to the search_path to enable use of util operators
3580
';
3581
3582
3583
--
3584 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3585
--
3586
3587
CREATE AGGREGATE all_same(anyelement) (
3588
    SFUNC = all_same_transform,
3589
    STYPE = anyarray,
3590
    FINALFUNC = all_same_final
3591
);
3592
3593
3594
--
3595
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3596
--
3597
3598 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
3599
includes NULLs in comparison
3600
';
3601 9959 aaronmk
3602
3603
--
3604 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3605 2595 aaronmk
--
3606
3607
CREATE AGGREGATE join_strs(text, text) (
3608 4052 aaronmk
    SFUNC = join_strs_transform,
3609 4010 aaronmk
    STYPE = text
3610 2595 aaronmk
);
3611
3612
3613 8147 aaronmk
--
3614 12423 aaronmk
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3615
--
3616
3617
CREATE OPERATOR %== (
3618
    PROCEDURE = "%==",
3619
    LEFTARG = anyelement,
3620
    RIGHTARG = anyelement
3621
);
3622
3623
3624
--
3625
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3626
--
3627
3628
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3629
returns whether the map-keys of the compared values are the same
3630
(mnemonic: % is the Perl symbol for a hash map)
3631
3632
should be overridden for types that store both keys and values
3633
3634
used in a FULL JOIN to select which columns to join on
3635
';
3636
3637
3638
--
3639 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3640 8147 aaronmk
--
3641
3642
CREATE OPERATOR -> (
3643
    PROCEDURE = map_get,
3644
    LEFTARG = regclass,
3645
    RIGHTARG = text
3646
);
3647
3648
3649 10308 aaronmk
--
3650
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3651
--
3652
3653
CREATE OPERATOR => (
3654
    PROCEDURE = hstore,
3655 10357 aaronmk
    LEFTARG = text[],
3656 10608 aaronmk
    RIGHTARG = text
3657 10308 aaronmk
);
3658
3659
3660
--
3661 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3662 10308 aaronmk
--
3663
3664 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
3665
usage: array[''key1'', ...]::text[] => ''value''
3666
';
3667 10308 aaronmk
3668
3669 10391 aaronmk
--
3670 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3671
--
3672
3673
CREATE OPERATOR ?*>= (
3674
    PROCEDURE = is_populated_more_often_than,
3675
    LEFTARG = anyelement,
3676
    RIGHTARG = anyelement
3677
);
3678
3679
3680
--
3681 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3682
--
3683
3684
CREATE OPERATOR ?>= (
3685
    PROCEDURE = is_more_complete_than,
3686
    LEFTARG = anyelement,
3687
    RIGHTARG = anyelement
3688
);
3689
3690
3691 11005 aaronmk
--
3692
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3693
--
3694
3695
CREATE OPERATOR ||% (
3696
    PROCEDURE = concat_esc,
3697
    LEFTARG = text,
3698
    RIGHTARG = text
3699
);
3700
3701
3702
--
3703
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3704
--
3705
3706 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
3707
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3708
';
3709 11005 aaronmk
3710
3711 2107 aaronmk
--
3712 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
3713 8140 aaronmk
--
3714
3715
CREATE TABLE map (
3716
    "from" text NOT NULL,
3717 8158 aaronmk
    "to" text,
3718
    filter text,
3719
    notes text
3720 8140 aaronmk
);
3721
3722
3723
--
3724 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3725
--
3726
3727
3728
3729
--
3730 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3731 8140 aaronmk
--
3732
3733
3734
3735
--
3736 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3737 8140 aaronmk
--
3738
3739
ALTER TABLE ONLY map
3740 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3741 8140 aaronmk
3742
3743
--
3744 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3745
--
3746
3747
ALTER TABLE ONLY map
3748
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3749
3750
3751
--
3752 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3753
--
3754
3755
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3756
3757
3758
--
3759 2136 aaronmk
-- PostgreSQL database dump complete
3760
--