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