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