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