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