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