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 12044 aaronmk
-- Name: diff_cols(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
926
--
927
928
CREATE FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
929
    LANGUAGE sql STABLE
930
    AS $_$
931
SELECT * FROM
932 12184 aaronmk
util.eval2col_pair($$
933
SELECT * FROM
934
(
935
$$||$1||$$
936
) left_ (left_)
937 12044 aaronmk
FULL JOIN
938 12184 aaronmk
(
939
$$||$2||$$
940
) right_ (right_)
941 12044 aaronmk
ON left_ = right_
942
WHERE left_ IS DISTINCT FROM right_
943
ORDER BY left_, right_
944 12184 aaronmk
$$, $3)
945 12044 aaronmk
$_$;
946
947
948
--
949
-- Name: FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
950
--
951
952 12235 aaronmk
COMMENT ON FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
953
col_type_null (*required*): NULL::col_type
954 12044 aaronmk
usage:
955
SELECT * FROM util.diff_cols($$VALUES (''1''), (''2''), (''4'')$$, $$VALUES (''1''), (''3''), (''4'')$$, NULL::text)
956 12185 aaronmk
957
to run EXPLAIN on the FULL JOIN query:
958
# run this function
959
# look for a NOTICE containing the expanded query that it ran
960
# run EXPLAIN on this expanded query
961 12044 aaronmk
';
962
963
964
--
965 12045 aaronmk
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
966
--
967
968
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
969
    LANGUAGE sql STABLE
970
    AS $_$
971
SELECT * FROM util.diff_cols($$SELECT * FROM $$||$1, $$SELECT * FROM $$||$1, $3)
972
$_$;
973
974
975
--
976
-- Name: FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
977
--
978
979 12235 aaronmk
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
980
col_type_null (*required*): NULL::col_type
981 12045 aaronmk
usage:
982
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
983
';
984
985
986
--
987 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
988
--
989
990
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
991
    LANGUAGE sql STRICT
992
    AS $_$
993
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
994
$_$;
995
996
997
--
998
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
999
--
1000
1001 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1002
idempotent
1003
';
1004 8200 aaronmk
1005
1006
--
1007 10362 aaronmk
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1008
--
1009
1010
CREATE FUNCTION drop_column(col col_ref) RETURNS void
1011
    LANGUAGE sql STRICT
1012
    AS $_$
1013
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1014
quote_ident($1.name))
1015
$_$;
1016
1017
1018
--
1019
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
1020
--
1021
1022 12235 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref) IS '
1023
idempotent
1024
';
1025 10362 aaronmk
1026
1027
--
1028 10150 aaronmk
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
1029
--
1030
1031
CREATE FUNCTION drop_table(table_ text) RETURNS void
1032
    LANGUAGE sql STRICT
1033
    AS $_$
1034
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
1035
$_$;
1036
1037
1038
--
1039
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
1040
--
1041
1042 12235 aaronmk
COMMENT ON FUNCTION drop_table(table_ text) IS '
1043
idempotent
1044
';
1045 10150 aaronmk
1046
1047
--
1048 12229 aaronmk
-- Name: drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1049
--
1050
1051
CREATE FUNCTION drop_view(view_ text) RETURNS void
1052
    LANGUAGE sql STRICT
1053
    AS $_$
1054
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1)
1055
$_$;
1056
1057
1058
--
1059
-- Name: FUNCTION drop_view(view_ text); Type: COMMENT; Schema: util; Owner: -
1060
--
1061
1062 12235 aaronmk
COMMENT ON FUNCTION drop_view(view_ text) IS '
1063
idempotent
1064
';
1065 12229 aaronmk
1066
1067
--
1068 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1069
--
1070
1071
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1072
    LANGUAGE sql IMMUTABLE
1073
    AS $_$
1074
SELECT util.array_fill($1, 0)
1075
$_$;
1076
1077
1078
--
1079
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1080
--
1081
1082 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1083
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1084
';
1085 10322 aaronmk
1086
1087
--
1088 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1089 8086 aaronmk
--
1090
1091
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1092 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1093 8086 aaronmk
    AS $_$
1094 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1095 8086 aaronmk
$_$;
1096
1097
1098
--
1099 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1100
--
1101
1102
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1103
    LANGUAGE sql IMMUTABLE
1104
    AS $_$
1105
SELECT regexp_replace($2, '("?)$', $1||'\1')
1106
$_$;
1107
1108
1109
--
1110 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1111
--
1112
1113
CREATE FUNCTION eval(sql text) RETURNS void
1114
    LANGUAGE plpgsql STRICT
1115
    AS $$
1116
BEGIN
1117 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1118
	EXECUTE sql;
1119 9824 aaronmk
END;
1120
$$;
1121
1122
1123
--
1124 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1125
--
1126
1127
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1128
    LANGUAGE plpgsql
1129
    AS $$
1130
BEGIN
1131 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1132 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1133
END;
1134
$$;
1135
1136
1137
--
1138
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1139
--
1140
1141 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1142
col_type_null (*required*): NULL::col_type
1143
';
1144 12181 aaronmk
1145
1146
--
1147 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1148
--
1149
1150
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1151
    LANGUAGE plpgsql
1152
    AS $$
1153
BEGIN
1154 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1155 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1156
END;
1157
$$;
1158
1159
1160
--
1161
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1162
--
1163
1164 12235 aaronmk
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1165
ret_type_null: NULL::ret_type
1166
';
1167 10363 aaronmk
1168
1169
--
1170 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1171 10128 aaronmk
--
1172
1173 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1174 10128 aaronmk
    LANGUAGE plpgsql
1175
    AS $$
1176
DECLARE
1177
	ret_val ret_type_null%TYPE;
1178
BEGIN
1179 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1180 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1181
	RETURN ret_val;
1182
END;
1183
$$;
1184
1185
1186
--
1187 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1188 10128 aaronmk
--
1189
1190 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1191
ret_type_null: NULL::ret_type
1192
';
1193 10128 aaronmk
1194
1195
--
1196 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1197
--
1198
1199
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1200
    LANGUAGE sql
1201
    AS $_$
1202 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1203 10131 aaronmk
$_$;
1204
1205
1206
--
1207
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1208
--
1209
1210 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1211
ret_type_null: NULL::ret_type
1212
';
1213 10131 aaronmk
1214
1215
--
1216 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1217
--
1218
1219
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1220
    LANGUAGE sql
1221
    AS $_$
1222
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1223
$_$;
1224
1225
1226
--
1227
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1228
--
1229
1230 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1231
sql: can be NULL, which will be passed through
1232
ret_type_null: NULL::ret_type
1233
';
1234 10133 aaronmk
1235
1236
--
1237 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1238 8182 aaronmk
--
1239
1240
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1241
    LANGUAGE sql STABLE STRICT
1242
    AS $_$
1243
SELECT col_name
1244
FROM unnest($2) s (col_name)
1245 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1246 8182 aaronmk
$_$;
1247
1248
1249
--
1250 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1251
--
1252
1253
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1254
    LANGUAGE sql
1255
    AS $_$
1256
SELECT util.eval2set($$EXPLAIN $$||$1)
1257
$_$;
1258
1259
1260
--
1261 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263
1264
CREATE FUNCTION explain2notice(sql text) RETURNS void
1265
    LANGUAGE plpgsql
1266
    AS $_$
1267
BEGIN
1268
	RAISE NOTICE '%', $$EXPLAIN:
1269
$$||util.explain2str(sql);
1270
END;
1271
$_$;
1272
1273
1274
--
1275 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1276
--
1277
1278
CREATE FUNCTION explain2str(sql text) RETURNS text
1279
    LANGUAGE sql
1280
    AS $_$
1281
SELECT util.join_strs(explain, $$
1282
$$) FROM util.explain($1)
1283
$_$;
1284
1285
1286 11835 aaronmk
SET default_tablespace = '';
1287
1288
SET default_with_oids = false;
1289
1290 11832 aaronmk
--
1291 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1292 11831 aaronmk
--
1293
1294 11835 aaronmk
CREATE TABLE explain (
1295
    line text NOT NULL
1296
);
1297
1298
1299
--
1300
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1301
--
1302
1303
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1304 11831 aaronmk
    LANGUAGE sql
1305
    AS $_$
1306 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1307
$$||quote_nullable($1)||$$
1308 11831 aaronmk
)$$)
1309
$_$;
1310
1311
1312
--
1313 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1314
--
1315
1316 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1317
usage:
1318 11836 aaronmk
PERFORM util.explain2table($$
1319
query
1320 12235 aaronmk
$$);
1321
';
1322 11836 aaronmk
1323
1324
--
1325 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327
1328
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1329 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1330 10323 aaronmk
    AS $_$
1331 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1332
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1333
) END
1334 10323 aaronmk
$_$;
1335
1336
1337
--
1338
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1339
--
1340
1341 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1342
ensures that an array will always have proper non-NULL dimensions
1343
';
1344 10323 aaronmk
1345
1346
--
1347 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1348
--
1349
1350
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1351
    LANGUAGE plpgsql
1352
    AS $_$
1353
DECLARE
1354
	PG_EXCEPTION_DETAIL text;
1355
	recreate_users_cmd text = util.save_drop_views(users);
1356
BEGIN
1357
	PERFORM util.eval(cmd);
1358
	PERFORM util.eval(recreate_users_cmd);
1359
EXCEPTION
1360
WHEN dependent_objects_still_exist THEN
1361
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1362
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1363
	users = array(SELECT * FROM util.regexp_matches_group(
1364
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1365
	IF util.is_empty(users) THEN RAISE; END IF;
1366
	PERFORM util.force_recreate(cmd, users);
1367
END;
1368
$_$;
1369
1370
1371
--
1372
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1373
--
1374
1375 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1376
idempotent
1377 11695 aaronmk
1378 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1379
';
1380 11695 aaronmk
1381
1382
--
1383 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385
1386
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1387
    LANGUAGE plpgsql STRICT
1388
    AS $_$
1389
DECLARE
1390
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1391
$$||query;
1392
BEGIN
1393
	EXECUTE mk_view;
1394
EXCEPTION
1395
WHEN invalid_table_definition THEN
1396 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1397
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1398
	THEN
1399 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1400
		EXECUTE mk_view;
1401
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1402
	END IF;
1403
END;
1404
$_$;
1405
1406
1407
--
1408
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1409
--
1410
1411 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1412
idempotent
1413
';
1414 8321 aaronmk
1415
1416
--
1417 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1418
--
1419
1420
CREATE FUNCTION grants_users() RETURNS SETOF text
1421
    LANGUAGE sql IMMUTABLE
1422
    AS $$
1423
VALUES ('bien_read'), ('public_')
1424
$$;
1425
1426
1427
--
1428 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1429 8085 aaronmk
--
1430
1431
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1432 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1433 8085 aaronmk
    AS $_$
1434
SELECT substring($2 for length($1)) = $1
1435
$_$;
1436
1437
1438
--
1439 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1440
--
1441
1442
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1443
    LANGUAGE sql IMMUTABLE
1444
    AS $_$
1445 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1446 10307 aaronmk
$_$;
1447
1448
1449
--
1450
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1451
--
1452
1453 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1454
avoids repeating the same value for each key
1455
';
1456 10307 aaronmk
1457
1458
--
1459 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1460
--
1461
1462
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1463
    LANGUAGE sql IMMUTABLE
1464
    AS $_$
1465 12222 aaronmk
SELECT COALESCE($1, $2)
1466 12218 aaronmk
$_$;
1467
1468
1469
--
1470
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1471
--
1472
1473 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1474
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1475
';
1476 12218 aaronmk
1477
1478
--
1479 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1480
--
1481
1482
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1483
    LANGUAGE sql STABLE STRICT
1484
    AS $_$
1485
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1486
$_$;
1487
1488
1489
--
1490 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1491
--
1492
1493
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1494
    LANGUAGE sql IMMUTABLE
1495
    AS $_$
1496
SELECT util.array_length($1) = 0
1497
$_$;
1498
1499
1500
--
1501 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1502
--
1503
1504
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1505
    LANGUAGE sql IMMUTABLE
1506
    AS $_$
1507
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1508
$_$;
1509
1510
1511
--
1512 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1513
--
1514
1515
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1516
    LANGUAGE sql IMMUTABLE
1517
    AS $_$
1518
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1519
$_$;
1520
1521
1522
--
1523 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1524 4009 aaronmk
--
1525
1526 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1527 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1528 4009 aaronmk
    AS $_$
1529 4054 aaronmk
SELECT $1 || $3 || $2
1530 2595 aaronmk
$_$;
1531
1532
1533
--
1534 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1535 10985 aaronmk
--
1536
1537 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1538 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1539
    AS $_$
1540 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1541 10985 aaronmk
$_$;
1542
1543
1544
--
1545 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1546
--
1547
1548
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1549
    LANGUAGE sql IMMUTABLE
1550
    AS $_$
1551
SELECT ltrim($1, $$
1552
$$)
1553
$_$;
1554
1555
1556
--
1557 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1558
--
1559
1560
CREATE FUNCTION map_filter_insert() RETURNS trigger
1561
    LANGUAGE plpgsql
1562
    AS $$
1563
BEGIN
1564
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1565
	RETURN new;
1566
END;
1567
$$;
1568
1569
1570
--
1571 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1572 8146 aaronmk
--
1573
1574
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1575
    LANGUAGE plpgsql STABLE STRICT
1576
    AS $_$
1577
DECLARE
1578
    value text;
1579
BEGIN
1580
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1581 8149 aaronmk
        INTO value USING key;
1582 8146 aaronmk
    RETURN value;
1583
END;
1584
$_$;
1585
1586
1587
--
1588 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1589 10325 aaronmk
--
1590
1591 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1592 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1593 10325 aaronmk
    AS $_$
1594 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1595 10325 aaronmk
$_$;
1596
1597
1598
--
1599 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1600
--
1601
1602 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1603
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1604 10359 aaronmk
1605
[1] inlining of function calls, which is different from constant folding
1606
[2] _map()''s profiling query
1607
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1608
and map_nulls()''s profiling query
1609
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1610 10375 aaronmk
both take ~920 ms.
1611 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.
1612
';
1613 10359 aaronmk
1614
1615
--
1616 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1617 8150 aaronmk
--
1618
1619
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1620
    LANGUAGE plpgsql STABLE STRICT
1621
    AS $_$
1622
BEGIN
1623
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1624
END;
1625
$_$;
1626
1627
1628
--
1629 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1630
--
1631
1632 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1633 12228 aaronmk
    LANGUAGE sql
1634
    AS $_$
1635 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1636 12228 aaronmk
$$||$2)
1637
$_$;
1638
1639
1640
--
1641 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1642 12228 aaronmk
--
1643
1644 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1645 12235 aaronmk
idempotent
1646
';
1647 12228 aaronmk
1648
1649
--
1650 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1651
--
1652
1653 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1654 12234 aaronmk
    LANGUAGE sql
1655
    AS $_$
1656
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1657
$_$;
1658
1659
1660
--
1661 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1662 12234 aaronmk
--
1663
1664 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1665 12235 aaronmk
idempotent
1666
';
1667 12234 aaronmk
1668
1669
--
1670 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1671
--
1672
1673
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1674
    LANGUAGE sql STRICT
1675
    AS $_$
1676 10135 aaronmk
SELECT util.create_if_not_exists($$
1677
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1678 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1679 10135 aaronmk
||quote_literal($2)||$$;
1680 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1681
constant
1682
';
1683 10135 aaronmk
$$)
1684 8190 aaronmk
$_$;
1685
1686
1687
--
1688
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1689
--
1690
1691 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1692
idempotent
1693
';
1694 8190 aaronmk
1695
1696
--
1697 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1698 8187 aaronmk
--
1699
1700 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1701 8187 aaronmk
    LANGUAGE plpgsql STRICT
1702
    AS $_$
1703
DECLARE
1704
    type regtype = util.typeof(expr, col.table_::text::regtype);
1705
    col_name_sql text = quote_ident(col.name);
1706
BEGIN
1707 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1708
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1709 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1710
$$||expr||$$;
1711
$$);
1712
END;
1713
$_$;
1714
1715
1716
--
1717 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1718 8188 aaronmk
--
1719
1720 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1721
idempotent
1722
';
1723 8188 aaronmk
1724
1725
--
1726 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1727 8139 aaronmk
--
1728
1729
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1730 8141 aaronmk
    LANGUAGE sql STRICT
1731 8139 aaronmk
    AS $_$
1732 8183 aaronmk
SELECT util.create_if_not_exists($$
1733 8141 aaronmk
CREATE TABLE $$||$1||$$
1734 8139 aaronmk
(
1735 8183 aaronmk
    LIKE util.map INCLUDING ALL
1736 10110 aaronmk
);
1737
1738
CREATE TRIGGER map_filter_insert
1739
  BEFORE INSERT
1740
  ON $$||$1||$$
1741
  FOR EACH ROW
1742
  EXECUTE PROCEDURE util.map_filter_insert();
1743 8141 aaronmk
$$)
1744 8139 aaronmk
$_$;
1745
1746
1747
--
1748 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1749
--
1750
1751
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1752
    LANGUAGE sql IMMUTABLE
1753
    AS $_$
1754
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1755
$_$;
1756
1757
1758
--
1759 12272 aaronmk
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1760
--
1761
1762
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1763
    LANGUAGE sql IMMUTABLE
1764
    AS $_$
1765
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1766
$_$;
1767
1768
1769
--
1770
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1771
--
1772
1773
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1774
usage:
1775
for *1* schema arg:
1776
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1777
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1778
';
1779
1780
1781
--
1782 12270 aaronmk
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1783
--
1784
1785
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1786
    LANGUAGE sql IMMUTABLE
1787
    AS $_$
1788
SELECT $$SET LOCAL search_path TO $$||$1
1789
$_$;
1790
1791
1792
--
1793 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1794
--
1795
1796
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1797
    LANGUAGE sql STRICT
1798
    AS $_$
1799 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1800 10113 aaronmk
$_$;
1801
1802
1803
--
1804
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1805
--
1806
1807 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1808
idempotent
1809
';
1810 10113 aaronmk
1811
1812
--
1813 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1814
--
1815
1816
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1817
    LANGUAGE plpgsql STRICT
1818
    AS $_$
1819
DECLARE
1820
	view_qual_name text = util.qual_name(view_);
1821
BEGIN
1822
	EXECUTE $$
1823
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1824
  RETURNS SETOF $$||view_||$$ AS
1825
$BODY1$
1826
SELECT * FROM $$||view_qual_name||$$
1827
ORDER BY sort_col
1828
LIMIT $1 OFFSET $2
1829
$BODY1$
1830
  LANGUAGE sql STABLE
1831
  COST 100
1832
  ROWS 1000
1833
$$;
1834
1835
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1836
END;
1837
$_$;
1838
1839
1840
--
1841 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1842
--
1843
1844
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1845
    LANGUAGE plpgsql STRICT
1846
    AS $_$
1847 10990 aaronmk
DECLARE
1848
	view_qual_name text = util.qual_name(view_);
1849
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1850 8325 aaronmk
BEGIN
1851
	EXECUTE $$
1852 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1853
  RETURNS integer AS
1854
$BODY1$
1855
SELECT $$||quote_ident(row_num_col)||$$
1856
FROM $$||view_qual_name||$$
1857
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1858
LIMIT 1
1859
$BODY1$
1860
  LANGUAGE sql STABLE
1861
  COST 100;
1862
$$;
1863
1864
	EXECUTE $$
1865 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1866
  RETURNS SETOF $$||view_||$$ AS
1867
$BODY1$
1868 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
1869
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1870
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1871
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1872 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
1873 8325 aaronmk
$BODY1$
1874
  LANGUAGE sql STABLE
1875
  COST 100
1876
  ROWS 1000
1877
$$;
1878 11010 aaronmk
1879
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1880
END;
1881
$_$;
1882
1883
1884
--
1885
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1886
--
1887
1888
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1889
    LANGUAGE plpgsql STRICT
1890
    AS $_$
1891
DECLARE
1892
	view_qual_name text = util.qual_name(view_);
1893
BEGIN
1894 8326 aaronmk
	EXECUTE $$
1895
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1896
  RETURNS SETOF $$||view_||$$
1897
  SET enable_sort TO 'off'
1898
  AS
1899
$BODY1$
1900 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
1901 8326 aaronmk
$BODY1$
1902
  LANGUAGE sql STABLE
1903
  COST 100
1904
  ROWS 1000
1905
;
1906
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1907
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1908
If you want to run EXPLAIN and get expanded output, use the regular subset
1909
function instead. (When a config param is set on a function, EXPLAIN produces
1910
just a function scan.)
1911
';
1912
$$;
1913 8325 aaronmk
END;
1914
$_$;
1915
1916
1917
--
1918 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1919
--
1920
1921 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
1922
creates subset function which turns off enable_sort
1923
';
1924 11010 aaronmk
1925
1926
--
1927 12271 aaronmk
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1928
--
1929
1930
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
1931
    LANGUAGE sql IMMUTABLE
1932
    AS $_$
1933
SELECT util.mk_set_search_path(util.schema_esc($1))
1934
$_$;
1935
1936
1937
--
1938 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
1939
--
1940
1941
CREATE FUNCTION name(table_ regclass) RETURNS text
1942
    LANGUAGE sql STABLE
1943
    AS $_$
1944
SELECT relname::text FROM pg_class WHERE oid = $1
1945
$_$;
1946
1947
1948
--
1949 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1950 8083 aaronmk
--
1951
1952
CREATE FUNCTION name(type regtype) RETURNS text
1953 8097 aaronmk
    LANGUAGE sql STABLE STRICT
1954 8083 aaronmk
    AS $_$
1955
SELECT typname::text FROM pg_type WHERE oid = $1
1956
$_$;
1957
1958
1959
--
1960 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1961
--
1962
1963
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1964
    LANGUAGE sql IMMUTABLE
1965
    AS $_$
1966 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1967 9958 aaronmk
$_$;
1968
1969
1970
--
1971 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1972
--
1973
1974
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1975 9957 aaronmk
    LANGUAGE sql IMMUTABLE
1976 9956 aaronmk
    AS $_$
1977
SELECT $1 IS NOT NULL
1978
$_$;
1979
1980
1981
--
1982 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1983
--
1984
1985
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1986
    LANGUAGE sql IMMUTABLE
1987
    AS $_$
1988
SELECT util.hstore($1, NULL) || '*=>*'
1989
$_$;
1990
1991
1992
--
1993
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1994
--
1995
1996 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
1997
for use with _map()
1998
';
1999 10373 aaronmk
2000
2001
--
2002 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2003 10984 aaronmk
--
2004
2005 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2006 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2007
    AS $_$
2008 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2009 10984 aaronmk
$_$;
2010
2011
2012
--
2013 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2014
--
2015
2016
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2017
    LANGUAGE sql IMMUTABLE
2018
    AS $_$
2019
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2020
$_$;
2021
2022
2023
--
2024 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2025
--
2026
2027
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2028 12267 aaronmk
    LANGUAGE sql STABLE STRICT
2029
    SET search_path TO pg_temp
2030 10988 aaronmk
    AS $_$
2031 12267 aaronmk
SELECT $1::text
2032 10988 aaronmk
$_$;
2033
2034
2035
--
2036 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2037
--
2038
2039
CREATE FUNCTION qual_name(type regtype) RETURNS text
2040
    LANGUAGE sql STABLE STRICT
2041
    SET search_path TO pg_temp
2042
    AS $_$
2043
SELECT $1::text
2044
$_$;
2045
2046
2047
--
2048
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2049
--
2050
2051
COMMENT ON FUNCTION qual_name(type regtype) IS '
2052
a type''s schema-qualified name
2053
';
2054
2055
2056
--
2057 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2058
--
2059
2060
CREATE FUNCTION qual_name(type unknown) RETURNS text
2061
    LANGUAGE sql STABLE STRICT
2062
    AS $_$
2063
SELECT util.qual_name($1::text::regtype)
2064
$_$;
2065
2066
2067
--
2068 12249 aaronmk
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2069
--
2070
2071
CREATE FUNCTION raise_notice(msg text) RETURNS void
2072
    LANGUAGE plpgsql IMMUTABLE STRICT
2073
    AS $$
2074
BEGIN
2075
	RAISE NOTICE '%', msg;
2076
END;
2077
$$;
2078
2079
2080
--
2081 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2082
--
2083
2084
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2085
    LANGUAGE plpgsql IMMUTABLE STRICT
2086
    AS $$
2087
BEGIN
2088
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2089
END;
2090
$$;
2091
2092
2093
--
2094 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2095
--
2096
2097
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2098
    LANGUAGE sql IMMUTABLE
2099
    AS $_$
2100
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2101
$_$;
2102
2103
2104
--
2105 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2106
--
2107
2108
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2109
    LANGUAGE sql
2110
    AS $_$
2111
SELECT util.drop_table($1);
2112
SELECT util.materialize_query($1, $2);
2113
$_$;
2114
2115
2116
--
2117
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2118
--
2119
2120
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2121
idempotent, but repeats action each time
2122
';
2123
2124
2125
--
2126 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2127
--
2128
2129 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2130 12247 aaronmk
    LANGUAGE sql
2131
    AS $_$
2132
SELECT util.drop_table($1);
2133
SELECT util.materialize_view($1, $2);
2134
$_$;
2135
2136
2137
--
2138 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2139 12247 aaronmk
--
2140
2141 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2142 12247 aaronmk
idempotent, but repeats action each time
2143
';
2144
2145
2146
--
2147 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2148 8137 aaronmk
--
2149
2150 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2151 8137 aaronmk
    LANGUAGE sql STRICT
2152
    AS $_$
2153 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2154 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2155 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
2156
SELECT NULL::void; -- don't fold away functions called in previous query
2157 8137 aaronmk
$_$;
2158
2159
2160
--
2161 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2162 8137 aaronmk
--
2163
2164 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2165
idempotent
2166
';
2167 8137 aaronmk
2168
2169
--
2170 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2171
--
2172
2173
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2174
    LANGUAGE sql STRICT
2175
    AS $_$
2176 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2177
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2178 10297 aaronmk
SELECT util.set_col_names($1, $2);
2179
$_$;
2180
2181
2182
--
2183
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2184
--
2185
2186 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2187
idempotent.
2188
alters the names table, so it will need to be repopulated after running this function.
2189
';
2190 10297 aaronmk
2191
2192
--
2193 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2194 8143 aaronmk
--
2195
2196
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2197
    LANGUAGE sql STRICT
2198
    AS $_$
2199 10152 aaronmk
SELECT util.drop_table($1);
2200 8183 aaronmk
SELECT util.mk_map_table($1);
2201 8143 aaronmk
$_$;
2202
2203
2204
--
2205 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207
2208
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2209
    LANGUAGE plpgsql STRICT
2210
    AS $_$
2211
DECLARE
2212
	result text = NULL;
2213
BEGIN
2214
	BEGIN
2215
		result = util.show_create_view(view_);
2216
		PERFORM util.eval($$DROP VIEW $$||view_);
2217
	EXCEPTION
2218
		WHEN undefined_table THEN NULL;
2219
	END;
2220
	RETURN result;
2221
END;
2222
$_$;
2223
2224
2225
--
2226 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2227
--
2228
2229
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2230
    LANGUAGE sql
2231
    AS $_$
2232 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2233 11660 aaronmk
$_$;
2234
2235
2236
--
2237 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2238
--
2239
2240
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2241
    LANGUAGE sql STABLE
2242
    AS $_$
2243
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2244
$_$;
2245
2246
2247
--
2248 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2249
--
2250
2251
CREATE FUNCTION schema(table_ regclass) RETURNS text
2252
    LANGUAGE sql STABLE
2253
    AS $_$
2254 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2255 12242 aaronmk
$_$;
2256
2257
2258
--
2259 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2260
--
2261
2262
CREATE FUNCTION schema(type regtype) RETURNS text
2263
    LANGUAGE sql STABLE
2264
    AS $_$
2265 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2266 10794 aaronmk
$_$;
2267
2268
2269
--
2270
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2271
--
2272
2273
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2274
    LANGUAGE sql STABLE
2275
    AS $_$
2276
SELECT util.schema(pg_typeof($1))
2277
$_$;
2278
2279
2280
--
2281 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2282
--
2283
2284
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2285
    LANGUAGE sql STABLE
2286
    AS $_$
2287
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2288
$_$;
2289
2290
2291
--
2292 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2293
--
2294
2295 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2296
a schema bundle is a group of schemas with a common prefix
2297
';
2298 12135 aaronmk
2299
2300
--
2301
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2302
--
2303
2304
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2305
    LANGUAGE sql
2306
    AS $_$
2307
SELECT util.schema_rename(old_schema,
2308
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2309
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2310
SELECT NULL::void; -- don't fold away functions called in previous query
2311
$_$;
2312
2313
2314
--
2315
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2316
--
2317
2318
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2319
    LANGUAGE plpgsql
2320
    AS $$
2321
BEGIN
2322
	-- don't schema_bundle_rm() the schema_bundle to keep!
2323
	IF replace = with_ THEN RETURN; END IF;
2324
2325
	PERFORM util.schema_bundle_rm(replace);
2326
	PERFORM util.schema_bundle_rename(with_, replace);
2327
END;
2328
$$;
2329
2330
2331
--
2332
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2333
--
2334
2335
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2336
    LANGUAGE sql
2337
    AS $_$
2338
SELECT util.schema_rm(schema)
2339
FROM util.schema_bundle_get_schemas($1) f (schema);
2340
SELECT NULL::void; -- don't fold away functions called in previous query
2341
$_$;
2342
2343
2344
--
2345 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2346 10795 aaronmk
--
2347
2348 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2349 10795 aaronmk
    LANGUAGE sql STABLE
2350
    AS $_$
2351
SELECT quote_ident(util.schema($1))
2352
$_$;
2353
2354
2355
--
2356 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2357
--
2358
2359
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2360
    LANGUAGE sql
2361
    AS $_$
2362
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2363
$_$;
2364
2365
2366
--
2367 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2368
--
2369
2370
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2371
    LANGUAGE plpgsql
2372
    AS $$
2373
BEGIN
2374
	-- don't schema_rm() the schema to keep!
2375
	IF replace = with_ THEN RETURN; END IF;
2376
2377
	PERFORM util.schema_rm(replace);
2378
	PERFORM util.schema_rename(with_, replace);
2379
END;
2380
$$;
2381
2382
2383
--
2384 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2385
--
2386
2387
CREATE FUNCTION schema_rm(schema text) RETURNS void
2388
    LANGUAGE sql
2389
    AS $_$
2390
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2391
$_$;
2392
2393
2394
--
2395 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2396
--
2397
2398
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2399
    LANGUAGE sql STRICT
2400
    AS $_$
2401
SELECT util.eval(
2402
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2403
$_$;
2404
2405
2406
--
2407 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2408 8153 aaronmk
--
2409
2410
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2411
    LANGUAGE plpgsql STRICT
2412
    AS $_$
2413
DECLARE
2414 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
2415
    new text[] = ARRAY(SELECT util.map_values(names));
2416 8153 aaronmk
BEGIN
2417
    old = old[1:array_length(new, 1)]; -- truncate to same length
2418 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2419
||$$ TO $$||quote_ident(value))
2420 10149 aaronmk
    FROM each(hstore(old, new))
2421
    WHERE value != key -- not same name
2422
    ;
2423 8153 aaronmk
END;
2424
$_$;
2425
2426
2427
--
2428 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2429 8153 aaronmk
--
2430
2431 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2432
idempotent
2433
';
2434 8153 aaronmk
2435
2436
--
2437 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2438
--
2439
2440
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2441
    LANGUAGE plpgsql STRICT
2442
    AS $_$
2443
DECLARE
2444
	row_ util.map;
2445
BEGIN
2446 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
2447
	BEGIN
2448
		PERFORM util.set_col_names(table_, names);
2449
	EXCEPTION
2450
		WHEN array_subscript_error THEN -- selective suppress
2451
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2452
				-- metadata cols not yet added
2453
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2454
			END IF;
2455
	END;
2456
2457 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2458 10145 aaronmk
	LOOP
2459 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
2460
			substring(row_."from" from 2));
2461 10145 aaronmk
	END LOOP;
2462
2463
	PERFORM util.set_col_names(table_, names);
2464
END;
2465
$_$;
2466
2467
2468
--
2469
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2470
--
2471
2472 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2473
idempotent.
2474
the metadata mappings must be *last* in the names table.
2475
';
2476 10145 aaronmk
2477
2478
--
2479 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2480 8107 aaronmk
--
2481
2482
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2483
    LANGUAGE plpgsql STRICT
2484
    AS $_$
2485
DECLARE
2486
    sql text = $$ALTER TABLE $$||table_||$$
2487
$$||NULLIF(array_to_string(ARRAY(
2488
    SELECT
2489
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2490
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2491
    FROM
2492
    (
2493
        SELECT
2494
          quote_ident(col_name) AS col_name_sql
2495 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
2496 8107 aaronmk
        , type AS target_type
2497
        FROM unnest(col_casts)
2498
    ) s
2499
    WHERE curr_type != target_type
2500
), '
2501
, '), '');
2502
BEGIN
2503 12251 aaronmk
    PERFORM util.debug_print_sql(sql);
2504 8107 aaronmk
    EXECUTE COALESCE(sql, '');
2505
END;
2506
$_$;
2507
2508
2509
--
2510 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2511 8107 aaronmk
--
2512
2513 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2514
idempotent
2515
';
2516 8107 aaronmk
2517
2518
--
2519 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2520
--
2521
2522
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2523
    LANGUAGE sql STABLE
2524
    AS $_$
2525 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2526
$$||util.show_grants_for($1)
2527 11651 aaronmk
$_$;
2528
2529
2530
--
2531 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2532
--
2533
2534
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2535
    LANGUAGE sql STABLE
2536
    AS $_$
2537 12269 aaronmk
SELECT string_agg(cmd, '')
2538 11655 aaronmk
FROM
2539
(
2540
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2541
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2542
$$ ELSE '' END) AS cmd
2543
	FROM util.grants_users() f (user_)
2544
) s
2545
$_$;
2546
2547
2548
--
2549 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2550 8144 aaronmk
--
2551
2552
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2553 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
2554 8144 aaronmk
    AS $_$
2555
DECLARE
2556
    hstore hstore;
2557
BEGIN
2558
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2559
        table_||$$))$$ INTO STRICT hstore;
2560
    RETURN hstore;
2561
END;
2562
$_$;
2563
2564
2565
--
2566 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2567
--
2568
2569
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2570
    LANGUAGE sql STABLE STRICT
2571
    AS $_$
2572
SELECT COUNT(*) > 0 FROM pg_constraint
2573
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2574
$_$;
2575
2576
2577
--
2578
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2579
--
2580
2581 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2582
gets whether a status flag is set by the presence of a table constraint
2583
';
2584 10184 aaronmk
2585
2586
--
2587 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2588
--
2589
2590
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2591
    LANGUAGE sql STRICT
2592
    AS $_$
2593
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2594
||quote_ident($2)||$$ CHECK (true)$$)
2595
$_$;
2596
2597
2598
--
2599
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2600
--
2601
2602 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2603
stores a status flag by the presence of a table constraint.
2604
idempotent.
2605
';
2606 10182 aaronmk
2607
2608
--
2609 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2610
--
2611
2612
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2613
    LANGUAGE sql STABLE STRICT
2614
    AS $_$
2615
SELECT util.table_flag__get($1, 'nulls_mapped')
2616
$_$;
2617
2618
2619
--
2620
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2621
--
2622
2623 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2624
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2625
';
2626 10185 aaronmk
2627
2628
--
2629 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2630
--
2631
2632
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2633
    LANGUAGE sql STRICT
2634
    AS $_$
2635
SELECT util.table_flag__set($1, 'nulls_mapped')
2636
$_$;
2637
2638
2639
--
2640
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2641
--
2642
2643 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2644
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2645
idempotent.
2646
';
2647 10183 aaronmk
2648
2649
--
2650 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2651 8088 aaronmk
--
2652
2653
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2654
    LANGUAGE plpgsql STRICT
2655
    AS $_$
2656
DECLARE
2657
    row record;
2658
BEGIN
2659 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2660 8088 aaronmk
    LOOP
2661
        IF row.global_name != row.name THEN
2662
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2663
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2664
        END IF;
2665
    END LOOP;
2666
END;
2667
$_$;
2668
2669
2670
--
2671 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2672 8088 aaronmk
--
2673
2674 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2675
idempotent
2676
';
2677 8088 aaronmk
2678
2679
--
2680 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2681
--
2682
2683
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2684
    LANGUAGE sql STRICT
2685
    AS $_$
2686 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2687 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
2688
$_$;
2689
2690
2691
--
2692
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2693
--
2694
2695 12235 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2696
trims table_ to include only columns in the original data.
2697
idempotent.
2698
';
2699 10365 aaronmk
2700
2701
--
2702 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2703 8142 aaronmk
--
2704
2705
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2706
    LANGUAGE plpgsql STRICT
2707
    AS $_$
2708
BEGIN
2709
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2710
END;
2711
$_$;
2712
2713
2714
--
2715 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2716 8142 aaronmk
--
2717
2718 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2719
idempotent
2720
';
2721 8142 aaronmk
2722
2723
--
2724 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2725
--
2726
2727
CREATE FUNCTION try_create(sql text) RETURNS void
2728
    LANGUAGE plpgsql STRICT
2729
    AS $$
2730
BEGIN
2731 10146 aaronmk
    PERFORM util.eval(sql);
2732 8199 aaronmk
EXCEPTION
2733 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2734 8199 aaronmk
    WHEN undefined_column THEN NULL;
2735
    WHEN duplicate_column THEN NULL;
2736
END;
2737
$$;
2738
2739
2740
--
2741
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2742
--
2743
2744 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
2745
idempotent
2746
';
2747 8199 aaronmk
2748
2749
--
2750 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2751
--
2752
2753
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2754
    LANGUAGE sql STRICT
2755
    AS $_$
2756
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2757
$_$;
2758
2759
2760
--
2761
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2762
--
2763
2764 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
2765
idempotent
2766
';
2767 8209 aaronmk
2768
2769
--
2770 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772
2773
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2774
    LANGUAGE sql IMMUTABLE
2775
    AS $_$
2776
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2777
$_$;
2778
2779
2780
--
2781 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2782
--
2783
2784 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
2785
a type''s NOT NULL qualifier
2786
';
2787 10161 aaronmk
2788
2789
--
2790 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2791
--
2792
2793 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2794
    LANGUAGE plpgsql STABLE
2795 8185 aaronmk
    AS $_$
2796
DECLARE
2797
    type regtype;
2798
BEGIN
2799 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2800
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2801 8185 aaronmk
    RETURN type;
2802
END;
2803
$_$;
2804
2805
2806
--
2807 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2808
--
2809
2810
CREATE AGGREGATE all_same(anyelement) (
2811
    SFUNC = all_same_transform,
2812
    STYPE = anyarray,
2813
    FINALFUNC = all_same_final
2814
);
2815
2816
2817
--
2818
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2819
--
2820
2821 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
2822
includes NULLs in comparison
2823
';
2824 9959 aaronmk
2825
2826
--
2827 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2828 2595 aaronmk
--
2829
2830
CREATE AGGREGATE join_strs(text, text) (
2831 4052 aaronmk
    SFUNC = join_strs_transform,
2832 4010 aaronmk
    STYPE = text
2833 2595 aaronmk
);
2834
2835
2836 8147 aaronmk
--
2837 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2838 8147 aaronmk
--
2839
2840
CREATE OPERATOR -> (
2841
    PROCEDURE = map_get,
2842
    LEFTARG = regclass,
2843
    RIGHTARG = text
2844
);
2845
2846
2847 10308 aaronmk
--
2848
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2849
--
2850
2851
CREATE OPERATOR => (
2852
    PROCEDURE = hstore,
2853 10357 aaronmk
    LEFTARG = text[],
2854 10608 aaronmk
    RIGHTARG = text
2855 10308 aaronmk
);
2856
2857
2858
--
2859 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2860 10308 aaronmk
--
2861
2862 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
2863
usage: array[''key1'', ...]::text[] => ''value''
2864
';
2865 10308 aaronmk
2866
2867 10391 aaronmk
--
2868 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2869
--
2870
2871
CREATE OPERATOR ?*>= (
2872
    PROCEDURE = is_populated_more_often_than,
2873
    LEFTARG = anyelement,
2874
    RIGHTARG = anyelement
2875
);
2876
2877
2878
--
2879 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2880
--
2881
2882
CREATE OPERATOR ?>= (
2883
    PROCEDURE = is_more_complete_than,
2884
    LEFTARG = anyelement,
2885
    RIGHTARG = anyelement
2886
);
2887
2888
2889 11005 aaronmk
--
2890
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2891
--
2892
2893
CREATE OPERATOR ||% (
2894
    PROCEDURE = concat_esc,
2895
    LEFTARG = text,
2896
    RIGHTARG = text
2897
);
2898
2899
2900
--
2901
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2902
--
2903
2904 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
2905
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
2906
';
2907 11005 aaronmk
2908
2909 2107 aaronmk
--
2910 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
2911 8140 aaronmk
--
2912
2913
CREATE TABLE map (
2914
    "from" text NOT NULL,
2915 8158 aaronmk
    "to" text,
2916
    filter text,
2917
    notes text
2918 8140 aaronmk
);
2919
2920
2921
--
2922 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2923
--
2924
2925
2926
2927
--
2928 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2929 8140 aaronmk
--
2930
2931
2932
2933
--
2934 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
2935 8140 aaronmk
--
2936
2937
ALTER TABLE ONLY map
2938 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2939 8140 aaronmk
2940
2941
--
2942 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
2943
--
2944
2945
ALTER TABLE ONLY map
2946
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2947
2948
2949
--
2950 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2951
--
2952
2953
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2954
2955
2956
--
2957 2136 aaronmk
-- PostgreSQL database dump complete
2958
--