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 12662 aaronmk
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
683 12655 aaronmk
--
684
685 12662 aaronmk
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
686 12655 aaronmk
    LANGUAGE sql
687
    AS $_$
688 12662 aaronmk
SELECT CASE WHEN util.freq_always_1($1, $2)
689 13097 aaronmk
THEN util.rm_freq($1, $2)
690 12685 aaronmk
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
691 12662 aaronmk
END
692 12655 aaronmk
$_$;
693
694
695
--
696 13134 aaronmk
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
697
--
698
699
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
700
    LANGUAGE plpgsql IMMUTABLE
701
    AS $$
702
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
703
return value, causing a type mismatch */
704
BEGIN
705
	-- will then be assignment-cast to return type via INOUT
706
	RETURN value::cstring;
707
END;
708
$$;
709
710
711
--
712
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
713
--
714
715
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
716
allows casting to an arbitrary type without eval()
717
718
usage:
719
SELECT util.cast(''value'', NULL::integer);
720
721
note that there does *not* need to be a cast from text to the output type,
722
because an INOUT cast is used instead
723
(http://www.postgresql.org/docs/9.3/static/sql-createcast.html#AEN69507)
724
725
ret_type_null: NULL::ret_type
726
';
727
728
729
--
730 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
731 8104 aaronmk
--
732
733
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
734 12446 aaronmk
    LANGUAGE sql STABLE
735 8104 aaronmk
    AS $_$
736
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
737
$_$;
738
739
740
--
741 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
742 8105 aaronmk
--
743
744
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
745
    LANGUAGE plpgsql STRICT
746
    AS $_$
747
BEGIN
748
    -- not yet clustered (ARRAY[] compares NULLs literally)
749 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
750 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
751
    END IF;
752
END;
753
$_$;
754
755
756
--
757 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
758 8105 aaronmk
--
759
760 12235 aaronmk
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
761
idempotent
762
';
763 8105 aaronmk
764
765
--
766 12683 aaronmk
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
767
--
768
769
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
770
    LANGUAGE sql IMMUTABLE
771
    AS $_$
772
SELECT value
773
FROM unnest($1) value
774
WHERE value IS NOT NULL
775
LIMIT 1
776
$_$;
777
778
779
--
780
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
781
--
782
783
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
784
uses:
785
* coalescing array elements or rows together
786
* forcing evaluation of all values of a COALESCE()
787
';
788
789
790
--
791 10986 aaronmk
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
792
--
793
794
CREATE FUNCTION col__min(col col_ref) RETURNS integer
795
    LANGUAGE sql STABLE
796
    AS $_$
797
SELECT util.eval2val($$
798
SELECT $$||quote_ident($1.name)||$$
799
FROM $$||$1.table_||$$
800
ORDER BY $$||quote_ident($1.name)||$$ ASC
801
LIMIT 1
802
$$, NULL::integer)
803
$_$;
804
805
806
--
807 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
808
--
809
810
CREATE FUNCTION col_comment(col col_ref) RETURNS text
811
    LANGUAGE plpgsql STABLE STRICT
812
    AS $$
813
DECLARE
814
	comment text;
815
BEGIN
816
	SELECT description
817
	FROM pg_attribute
818
	LEFT JOIN pg_description ON objoid = attrelid
819
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
820
	WHERE attrelid = col.table_ AND attname = col.name
821
	INTO STRICT comment
822
	;
823
	RETURN comment;
824
EXCEPTION
825
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
826
END;
827
$$;
828
829
830
--
831 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
832
--
833
834
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
835
    LANGUAGE plpgsql STABLE STRICT
836
    AS $$
837
DECLARE
838
	default_sql text;
839
BEGIN
840
	SELECT adsrc
841
	FROM pg_attribute
842
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
843
	WHERE attrelid = col.table_ AND attname = col.name
844
	INTO STRICT default_sql
845
	;
846
	RETURN default_sql;
847
EXCEPTION
848
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
849
END;
850
$$;
851
852
853
--
854 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
855
--
856
857
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
858
    LANGUAGE sql STABLE
859
    AS $_$
860
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
861
$_$;
862
863
864
--
865
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
866
--
867
868 12235 aaronmk
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
869
ret_type_null: NULL::ret_type
870
';
871 10134 aaronmk
872
873
--
874 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
875 8180 aaronmk
--
876
877
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
878
    LANGUAGE plpgsql STRICT
879
    AS $$
880
BEGIN
881 8183 aaronmk
    PERFORM util.col_type(col);
882 8180 aaronmk
    RETURN true;
883
EXCEPTION
884
    WHEN undefined_column THEN RETURN false;
885
END;
886
$$;
887
888
889
--
890 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
891 8084 aaronmk
--
892
893
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
894 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
895 8084 aaronmk
    AS $$
896
DECLARE
897 8183 aaronmk
    prefix text := util.name(type)||'.';
898 8084 aaronmk
BEGIN
899
    RETURN QUERY
900 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
901
        FROM util.col_names(type) f (name_);
902 8084 aaronmk
END;
903
$$;
904
905
906
--
907 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
908 8151 aaronmk
--
909
910
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
911 12446 aaronmk
    LANGUAGE sql STABLE
912 8151 aaronmk
    AS $_$
913
SELECT attname::text
914
FROM pg_attribute
915 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
916 8151 aaronmk
ORDER BY attnum
917
$_$;
918
919
920
--
921 11667 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
922
--
923
924
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
925
    LANGUAGE plpgsql STABLE STRICT
926
    AS $_$
927
BEGIN
928
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
929
END;
930
$_$;
931
932
933
--
934 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
935 8106 aaronmk
--
936
937
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
938 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
939
    AS $$
940
DECLARE
941
    type regtype;
942
BEGIN
943
    SELECT atttypid FROM pg_attribute
944
    WHERE attrelid = col.table_ AND attname = col.name
945
    INTO STRICT type
946
    ;
947
    RETURN type;
948
EXCEPTION
949 8171 aaronmk
    WHEN no_data_found THEN
950 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
951
            concat('undefined column: ', col.name);
952 8169 aaronmk
END;
953
$$;
954 8106 aaronmk
955
956
--
957 12368 aaronmk
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
958
--
959
960
CREATE FUNCTION comment(element oid) RETURNS text
961 12446 aaronmk
    LANGUAGE sql STABLE
962 12368 aaronmk
    AS $_$
963
SELECT description FROM pg_description WHERE objoid = $1
964
$_$;
965
966
967
--
968 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
969
--
970
971
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
972
    LANGUAGE sql IMMUTABLE
973
    AS $_$
974
SELECT util.esc_name__append($2, $1)
975
$_$;
976
977
978
--
979 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
980 8095 aaronmk
--
981
982
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
983 10388 aaronmk
    LANGUAGE sql IMMUTABLE
984 8095 aaronmk
    AS $_$
985
SELECT position($1 in $2) > 0 /*1-based offset*/
986
$_$;
987
988
989
--
990 12288 aaronmk
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
991
--
992
993
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
994
    LANGUAGE sql
995
    AS $_$
996
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
997
$_$;
998
999
1000
--
1001 12649 aaronmk
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1002
--
1003
1004
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1005
    LANGUAGE sql
1006
    AS $_$
1007
SELECT util.materialize_view($2, $1)
1008
$_$;
1009
1010
1011
--
1012 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
1013 8094 aaronmk
--
1014
1015
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
1016
    LANGUAGE plpgsql STRICT
1017
    AS $$
1018
BEGIN
1019 12595 aaronmk
	PERFORM util.eval(sql);
1020 8094 aaronmk
EXCEPTION
1021 12676 aaronmk
WHEN   duplicate_table
1022
	OR duplicate_object -- eg. constraint
1023
	OR duplicate_column
1024
	OR duplicate_function
1025
THEN NULL;
1026 12595 aaronmk
WHEN invalid_table_definition THEN
1027
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1028
	ELSE RAISE;
1029
	END IF;
1030 8094 aaronmk
END;
1031
$$;
1032
1033
1034
--
1035 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
1036 8094 aaronmk
--
1037
1038 12235 aaronmk
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
1039
idempotent
1040
';
1041 8094 aaronmk
1042
1043
--
1044 12378 aaronmk
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1045
--
1046
1047
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1048 12590 aaronmk
    LANGUAGE sql STABLE
1049 12378 aaronmk
    AS $$
1050
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1051
$$;
1052
1053
1054
--
1055 12668 aaronmk
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1056
--
1057
1058
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1059
    LANGUAGE sql IMMUTABLE
1060
    AS $_$
1061
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1062
$_$;
1063
1064
1065
--
1066 12433 aaronmk
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1067 12430 aaronmk
--
1068
1069 12433 aaronmk
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1070 12430 aaronmk
    LANGUAGE sql IMMUTABLE
1071
    AS $_$
1072 12534 aaronmk
SELECT util.raise('NOTICE', 'returns: '
1073 12433 aaronmk
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
1074 12430 aaronmk
SELECT $1;
1075
$_$;
1076
1077
1078
--
1079 12250 aaronmk
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1080
--
1081
1082
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1083
    LANGUAGE sql IMMUTABLE
1084
    AS $_$
1085
/* newline before so the query starts at the beginning of the line.
1086
newline after to visually separate queries from one another. */
1087 12534 aaronmk
SELECT util.raise('NOTICE', $$
1088 12474 aaronmk
$$||util.runnable_sql($1)||$$
1089 12464 aaronmk
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1090 12250 aaronmk
$_$;
1091
1092
1093
--
1094 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1095
--
1096
1097
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1098 12446 aaronmk
    LANGUAGE sql STABLE
1099 10364 aaronmk
    AS $_$
1100
SELECT util.eval2set($$
1101
SELECT col
1102
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1103
LEFT JOIN $$||$2||$$ ON "to" = col
1104
WHERE "from" IS NULL
1105
$$, NULL::text)
1106
$_$;
1107
1108
1109
--
1110
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1111
--
1112
1113 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1114
gets table_''s derived columns (all the columns not in the names table)
1115
';
1116 10364 aaronmk
1117
1118
--
1119 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1120 12044 aaronmk
--
1121
1122 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1123 12427 aaronmk
    LANGUAGE sql
1124 12044 aaronmk
    AS $_$
1125 12653 aaronmk
-- create a diff when the # of copies of a row differs between the tables
1126
SELECT util.to_freq($1);
1127
SELECT util.to_freq($2);
1128 12663 aaronmk
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1129 12653 aaronmk
1130
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1131 12298 aaronmk
$_$;
1132
1133
1134
--
1135
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1136
--
1137
1138
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1139
usage:
1140
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1141 12653 aaronmk
1142
col_type_null (*required*): NULL::shared_base_type
1143 12298 aaronmk
';
1144
1145
1146
--
1147 12491 aaronmk
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1148 12298 aaronmk
--
1149
1150 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
1151 12429 aaronmk
    LANGUAGE plpgsql
1152
    SET search_path TO pg_temp
1153 12298 aaronmk
    AS $_$
1154 12429 aaronmk
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1155
changes of search_path (schema elements are bound at inline time rather than
1156
runtime) */
1157
/* function option search_path is needed to limit the effects of
1158 12492 aaronmk
`SET LOCAL search_path` to the current function */
1159 12429 aaronmk
BEGIN
1160 12491 aaronmk
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1161 12429 aaronmk
1162 12565 aaronmk
	PERFORM util.mk_keys_func(pg_typeof($3));
1163 12429 aaronmk
	RETURN QUERY
1164 12554 aaronmk
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1165 12479 aaronmk
$$/* need to explicitly cast each side to the return type because this does not
1166 12284 aaronmk
happen automatically even when an implicit cast is available */
1167 12479 aaronmk
  left_::$$||util.typeof($3)||$$
1168
, right_::$$||util.typeof($3)
1169 12496 aaronmk
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1170
the *same* base type, *even though* this is optional when using a custom %== */
1171 12553 aaronmk
, util._if($4, $$true/*= CROSS JOIN*/$$,
1172
$$ left_::$$||util.typeof($3)||$$
1173 12496 aaronmk
%== right_::$$||util.typeof($3)||$$
1174
	-- refer to EXPLAIN output for expansion of %==$$
1175 12657 aaronmk
)
1176
,     $$         left_::$$||util.typeof($3)||$$
1177
IS DISTINCT FROM right_::$$||util.typeof($3)
1178
), $3)
1179 12429 aaronmk
	;
1180
END;
1181 12044 aaronmk
$_$;
1182
1183
1184
--
1185 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: -
1186 12280 aaronmk
--
1187
1188 12491 aaronmk
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1189 12280 aaronmk
col_type_null (*required*): NULL::col_type
1190 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
1191
	displayed side-by-side
1192 12282 aaronmk
1193 12498 aaronmk
to match up rows using a subset of the columns, create a custom keys() function
1194
which returns this subset as a record:
1195
-- note that OUT parameters for the returned fields are *not* needed
1196
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1197
  RETURNS record AS
1198
$BODY$
1199
SELECT ($1.key_field_0, $1.key_field_1)
1200
$BODY$
1201
  LANGUAGE sql IMMUTABLE
1202
  COST 100;
1203
1204
1205 12282 aaronmk
to run EXPLAIN on the FULL JOIN query:
1206
# run this function
1207
# look for a NOTICE containing the expanded query that it ran
1208
# run EXPLAIN on this expanded query
1209 12280 aaronmk
';
1210
1211
1212
--
1213 12653 aaronmk
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1214
--
1215
1216
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1217
    LANGUAGE sql
1218
    AS $_$
1219
SELECT * FROM util.diff($1::text, $2::text, $3,
1220
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1221
$_$;
1222
1223
1224
--
1225
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1226
--
1227
1228
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1229
helper function used by diff(regclass, regclass)
1230
1231
usage:
1232
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1233
1234
col_type_null (*required*): NULL::shared_base_type
1235
';
1236
1237
1238
--
1239 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1240
--
1241
1242
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1243 12446 aaronmk
    LANGUAGE sql
1244 8200 aaronmk
    AS $_$
1245
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1246
$_$;
1247
1248
1249
--
1250
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1251
--
1252
1253 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1254
idempotent
1255
';
1256 8200 aaronmk
1257
1258
--
1259 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1260 10362 aaronmk
--
1261
1262 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1263 12446 aaronmk
    LANGUAGE sql
1264 10362 aaronmk
    AS $_$
1265
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1266 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1267 10362 aaronmk
$_$;
1268
1269
1270
--
1271 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1272 10362 aaronmk
--
1273
1274 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1275 12235 aaronmk
idempotent
1276
';
1277 10362 aaronmk
1278
1279
--
1280 12660 aaronmk
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1281
--
1282
1283
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1284
    LANGUAGE sql
1285
    AS $_$
1286 12686 aaronmk
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1287
SELECT NULL::void; -- don't fold away functions called in previous query
1288 12660 aaronmk
$_$;
1289
1290
1291
--
1292
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1293
--
1294
1295
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1296
idempotent
1297
';
1298
1299
1300
--
1301 12587 aaronmk
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1302 12331 aaronmk
--
1303
1304 12587 aaronmk
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1305 12331 aaronmk
    LANGUAGE sql
1306
    AS $_$
1307 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1308
included in the debug SQL */
1309
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1310 12331 aaronmk
$_$;
1311
1312
1313
--
1314 12343 aaronmk
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1315
--
1316
1317 12364 aaronmk
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1318 12343 aaronmk
    LANGUAGE sql
1319
    AS $_$
1320 12347 aaronmk
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1321 12343 aaronmk
||util._if($3, $$ CASCADE$$, ''::text))
1322
$_$;
1323
1324
1325
--
1326 12364 aaronmk
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1327 12343 aaronmk
--
1328
1329 12364 aaronmk
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1330 12343 aaronmk
idempotent
1331
';
1332
1333
1334
--
1335 12413 aaronmk
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1336
--
1337
1338
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1339
    LANGUAGE sql
1340
    AS $_$
1341 12502 aaronmk
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1342 12413 aaronmk
$_$;
1343
1344
1345
--
1346
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1347
--
1348
1349
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1350
    LANGUAGE sql
1351
    AS $_$
1352 12668 aaronmk
SELECT util.debug_print_func_call(util.quote_func_call(
1353
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1354
util.quote_typed($3)))
1355 12667 aaronmk
;
1356 12413 aaronmk
SELECT util.drop_relation(relation, $3)
1357
FROM util.show_relations_like($1, $2) relation
1358
;
1359
SELECT NULL::void; -- don't fold away functions called in previous query
1360
$_$;
1361
1362
1363
--
1364 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1365 10150 aaronmk
--
1366
1367 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1368 12446 aaronmk
    LANGUAGE sql
1369 10150 aaronmk
    AS $_$
1370 12347 aaronmk
SELECT util.drop_relation('TABLE', $1, $2)
1371 10150 aaronmk
$_$;
1372
1373
1374
--
1375 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1376 10150 aaronmk
--
1377
1378 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1379 12235 aaronmk
idempotent
1380
';
1381 10150 aaronmk
1382
1383
--
1384 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1385 12229 aaronmk
--
1386
1387 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1388 12446 aaronmk
    LANGUAGE sql
1389 12229 aaronmk
    AS $_$
1390 12347 aaronmk
SELECT util.drop_relation('VIEW', $1, $2)
1391 12229 aaronmk
$_$;
1392
1393
1394
--
1395 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1396 12229 aaronmk
--
1397
1398 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1399 12235 aaronmk
idempotent
1400
';
1401 12229 aaronmk
1402
1403
--
1404 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1405
--
1406
1407
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1408
    LANGUAGE sql IMMUTABLE
1409
    AS $_$
1410
SELECT util.array_fill($1, 0)
1411
$_$;
1412
1413
1414
--
1415
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1416
--
1417
1418 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1419
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1420
';
1421 10322 aaronmk
1422
1423
--
1424 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1425 8086 aaronmk
--
1426
1427
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1428 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1429 8086 aaronmk
    AS $_$
1430 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1431 8086 aaronmk
$_$;
1432
1433
1434
--
1435 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1436
--
1437
1438
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1439
    LANGUAGE sql IMMUTABLE
1440
    AS $_$
1441
SELECT regexp_replace($2, '("?)$', $1||'\1')
1442
$_$;
1443
1444
1445
--
1446 12531 aaronmk
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1447 9824 aaronmk
--
1448
1449 12531 aaronmk
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1450 12558 aaronmk
    LANGUAGE plpgsql
1451 9824 aaronmk
    AS $$
1452
BEGIN
1453 12531 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1454 12251 aaronmk
	EXECUTE sql;
1455 9824 aaronmk
END;
1456
$$;
1457
1458
1459
--
1460 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1461
--
1462
1463
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1464
    LANGUAGE plpgsql
1465
    AS $$
1466
BEGIN
1467 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1468 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1469
END;
1470
$$;
1471
1472
1473
--
1474
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1475
--
1476
1477 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1478
col_type_null (*required*): NULL::col_type
1479
';
1480 12181 aaronmk
1481
1482
--
1483 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1484
--
1485
1486
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1487
    LANGUAGE plpgsql
1488
    AS $$
1489
BEGIN
1490
	PERFORM util.debug_print_sql(sql);
1491
	RETURN QUERY EXECUTE sql;
1492
END;
1493
$$;
1494
1495
1496
--
1497 12458 aaronmk
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1498 10363 aaronmk
--
1499
1500 12458 aaronmk
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1501 10363 aaronmk
    LANGUAGE plpgsql
1502
    AS $$
1503
BEGIN
1504 12458 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1505 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1506
END;
1507
$$;
1508
1509
1510
--
1511 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1512 10128 aaronmk
--
1513
1514 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1515 12514 aaronmk
    LANGUAGE plpgsql STABLE
1516 10128 aaronmk
    AS $$
1517
DECLARE
1518
	ret_val ret_type_null%TYPE;
1519
BEGIN
1520 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1521 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1522
	RETURN ret_val;
1523
END;
1524
$$;
1525
1526
1527
--
1528 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1529 10128 aaronmk
--
1530
1531 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1532
ret_type_null: NULL::ret_type
1533
';
1534 10128 aaronmk
1535
1536
--
1537 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1538
--
1539
1540
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1541
    LANGUAGE sql
1542
    AS $_$
1543 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1544 10131 aaronmk
$_$;
1545
1546
1547
--
1548
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1549
--
1550
1551 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1552
ret_type_null: NULL::ret_type
1553
';
1554 10131 aaronmk
1555
1556
--
1557 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1558
--
1559
1560
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1561
    LANGUAGE sql
1562
    AS $_$
1563
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1564
$_$;
1565
1566
1567
--
1568
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1569
--
1570
1571 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1572
sql: can be NULL, which will be passed through
1573
ret_type_null: NULL::ret_type
1574
';
1575 10133 aaronmk
1576
1577
--
1578 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1579 8182 aaronmk
--
1580
1581
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1582 12446 aaronmk
    LANGUAGE sql STABLE
1583 8182 aaronmk
    AS $_$
1584
SELECT col_name
1585
FROM unnest($2) s (col_name)
1586 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1587 8182 aaronmk
$_$;
1588
1589
1590
--
1591 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1592
--
1593
1594
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1595
    LANGUAGE sql
1596
    AS $_$
1597 12459 aaronmk
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1598 11830 aaronmk
$_$;
1599
1600
1601
--
1602 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1603
--
1604
1605
CREATE FUNCTION explain2notice(sql text) RETURNS void
1606 12449 aaronmk
    LANGUAGE sql
1607
    AS $_$
1608 12534 aaronmk
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1609 12449 aaronmk
$_$;
1610 12448 aaronmk
1611
1612
--
1613
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1614
--
1615
1616
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1617
    LANGUAGE sql
1618
    AS $_$
1619 12464 aaronmk
-- newline before and after to visually separate it from other debug info
1620 12756 aaronmk
SELECT COALESCE($$
1621 12464 aaronmk
EXPLAIN:
1622 12756 aaronmk
$$||util.fold_explain_msg(util.explain2str($1))||$$
1623
$$, '')
1624 11833 aaronmk
$_$;
1625
1626
1627
--
1628 12452 aaronmk
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1629
--
1630
1631
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1632
    LANGUAGE sql
1633
    AS $_$
1634
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1635
$_$;
1636
1637
1638
--
1639 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1640
--
1641
1642
CREATE FUNCTION explain2str(sql text) RETURNS text
1643
    LANGUAGE sql
1644
    AS $_$
1645
SELECT util.join_strs(explain, $$
1646
$$) FROM util.explain($1)
1647
$_$;
1648
1649
1650 11835 aaronmk
SET default_tablespace = '';
1651
1652
SET default_with_oids = false;
1653
1654 11832 aaronmk
--
1655 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1656 11831 aaronmk
--
1657
1658 11835 aaronmk
CREATE TABLE explain (
1659
    line text NOT NULL
1660
);
1661
1662
1663
--
1664
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1665
--
1666
1667
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1668 11831 aaronmk
    LANGUAGE sql
1669
    AS $_$
1670 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1671
$$||quote_nullable($1)||$$
1672 11831 aaronmk
)$$)
1673
$_$;
1674
1675
1676
--
1677 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1678
--
1679
1680 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1681
usage:
1682 11836 aaronmk
PERFORM util.explain2table($$
1683
query
1684 12235 aaronmk
$$);
1685
';
1686 11836 aaronmk
1687
1688
--
1689 12450 aaronmk
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1690
--
1691
1692
CREATE FUNCTION first_word(str text) RETURNS text
1693
    LANGUAGE sql IMMUTABLE
1694
    AS $_$
1695 12461 aaronmk
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1696 12450 aaronmk
$_$;
1697
1698
1699
--
1700 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1701
--
1702
1703
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1704 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1705 10323 aaronmk
    AS $_$
1706 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1707
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1708
) END
1709 10323 aaronmk
$_$;
1710
1711
1712
--
1713
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1714
--
1715
1716 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1717
ensures that an array will always have proper non-NULL dimensions
1718
';
1719 10323 aaronmk
1720
1721
--
1722 12755 aaronmk
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1723
--
1724
1725
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1726
    LANGUAGE sql IMMUTABLE
1727
    AS $_$
1728
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1729
$_$;
1730
1731
1732
--
1733 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1734
--
1735
1736
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1737
    LANGUAGE plpgsql
1738
    AS $_$
1739
DECLARE
1740
	PG_EXCEPTION_DETAIL text;
1741
	recreate_users_cmd text = util.save_drop_views(users);
1742
BEGIN
1743
	PERFORM util.eval(cmd);
1744
	PERFORM util.eval(recreate_users_cmd);
1745
EXCEPTION
1746
WHEN dependent_objects_still_exist THEN
1747
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1748
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1749
	users = array(SELECT * FROM util.regexp_matches_group(
1750
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1751
	IF util.is_empty(users) THEN RAISE; END IF;
1752
	PERFORM util.force_recreate(cmd, users);
1753
END;
1754
$_$;
1755
1756
1757
--
1758
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1759
--
1760
1761 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1762
idempotent
1763 11695 aaronmk
1764 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1765
';
1766 11695 aaronmk
1767
1768
--
1769 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1770
--
1771
1772
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1773
    LANGUAGE plpgsql STRICT
1774
    AS $_$
1775
DECLARE
1776
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1777
$$||query;
1778
BEGIN
1779
	EXECUTE mk_view;
1780
EXCEPTION
1781
WHEN invalid_table_definition THEN
1782 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1783
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1784
	THEN
1785 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1786
		EXECUTE mk_view;
1787
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1788
	END IF;
1789
END;
1790
$_$;
1791
1792
1793
--
1794
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1795
--
1796
1797 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1798
idempotent
1799
';
1800 8321 aaronmk
1801
1802
--
1803 12654 aaronmk
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1804
--
1805
1806
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1807
    LANGUAGE sql STABLE
1808
    AS $_$
1809
SELECT util.eval2val(
1810
$$SELECT NOT EXISTS( -- there is no row that is != 1
1811
	SELECT NULL
1812
	FROM $$||$1||$$
1813
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1814
	LIMIT 1
1815
)
1816
$$, NULL::boolean)
1817
$_$;
1818
1819
1820
--
1821 12661 aaronmk
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1822
--
1823
1824
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1825
    LANGUAGE sql STABLE
1826
    AS $_$
1827
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1828
$_$;
1829
1830
1831
--
1832 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1833
--
1834
1835
CREATE FUNCTION grants_users() RETURNS SETOF text
1836
    LANGUAGE sql IMMUTABLE
1837
    AS $$
1838
VALUES ('bien_read'), ('public_')
1839
$$;
1840
1841
1842
--
1843 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1844 8085 aaronmk
--
1845
1846
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1847 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1848 8085 aaronmk
    AS $_$
1849
SELECT substring($2 for length($1)) = $1
1850
$_$;
1851
1852
1853
--
1854 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856
1857
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1858
    LANGUAGE sql STABLE
1859
    AS $_$
1860
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1861
$_$;
1862
1863
1864
--
1865 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1866
--
1867
1868
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1869
    LANGUAGE sql IMMUTABLE
1870
    AS $_$
1871 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1872 10307 aaronmk
$_$;
1873
1874
1875
--
1876
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1877
--
1878
1879 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1880
avoids repeating the same value for each key
1881
';
1882 10307 aaronmk
1883
1884
--
1885 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1886
--
1887
1888
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1889
    LANGUAGE sql IMMUTABLE
1890
    AS $_$
1891 12222 aaronmk
SELECT COALESCE($1, $2)
1892 12218 aaronmk
$_$;
1893
1894
1895
--
1896
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1897
--
1898
1899 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1900
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1901
';
1902 12218 aaronmk
1903
1904
--
1905 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1906
--
1907
1908
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1909
    LANGUAGE sql
1910
    AS $_$
1911
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1912
$_$;
1913
1914
1915
--
1916 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1917
--
1918
1919
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1920 12446 aaronmk
    LANGUAGE sql STABLE
1921 10137 aaronmk
    AS $_$
1922 12789 aaronmk
SELECT COALESCE(util.col_comment($1) LIKE '
1923
constant
1924
%', false)
1925 10137 aaronmk
$_$;
1926
1927
1928
--
1929 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1930
--
1931
1932
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1933
    LANGUAGE sql IMMUTABLE
1934
    AS $_$
1935
SELECT util.array_length($1) = 0
1936
$_$;
1937
1938
1939
--
1940 12457 aaronmk
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1941
--
1942
1943
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1944
    LANGUAGE sql IMMUTABLE
1945
    AS $_$
1946
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1947
$_$;
1948
1949
1950
--
1951 12451 aaronmk
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1952
--
1953
1954
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1955
    LANGUAGE sql IMMUTABLE
1956
    AS $_$
1957
SELECT upper(util.first_word($1)) = ANY(
1958
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1959
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1960
)
1961
$_$;
1962
1963
1964
--
1965 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1966
--
1967
1968
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1969
    LANGUAGE sql IMMUTABLE
1970
    AS $_$
1971
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1972
$_$;
1973
1974
1975
--
1976 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1977
--
1978
1979
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1980
    LANGUAGE sql IMMUTABLE
1981
    AS $_$
1982
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1983
$_$;
1984
1985
1986
--
1987 12480 aaronmk
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1988
--
1989
1990
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1991
    LANGUAGE sql IMMUTABLE
1992
    AS $_$
1993
SELECT upper(util.first_word($1)) = 'SET'
1994
$_$;
1995
1996
1997
--
1998 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1999
--
2000
2001
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2002 12332 aaronmk
    LANGUAGE sql STABLE
2003 12330 aaronmk
    AS $_$
2004
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2005
$_$;
2006
2007
2008
--
2009 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2010
--
2011
2012
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2013 12332 aaronmk
    LANGUAGE sql STABLE
2014 12329 aaronmk
    AS $_$
2015
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2016
$_$;
2017
2018
2019
--
2020 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2021 4009 aaronmk
--
2022
2023 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2024 12444 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
2025 4009 aaronmk
    AS $_$
2026 4054 aaronmk
SELECT $1 || $3 || $2
2027 2595 aaronmk
$_$;
2028
2029
2030
--
2031 12444 aaronmk
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2032
--
2033
2034
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2035
must be declared STRICT to use the special handling of STRICT aggregating functions
2036
';
2037
2038
2039
--
2040 12436 aaronmk
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2041
--
2042
2043
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2044
    LANGUAGE sql IMMUTABLE
2045
    AS $_$
2046
SELECT $1 -- compare on the entire value
2047
$_$;
2048
2049
2050
--
2051 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2052 10985 aaronmk
--
2053
2054 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2055 10985 aaronmk
    LANGUAGE sql IMMUTABLE
2056
    AS $_$
2057 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2058 10985 aaronmk
$_$;
2059
2060
2061
--
2062 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2063
--
2064
2065
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2066
    LANGUAGE sql IMMUTABLE
2067
    AS $_$
2068
SELECT ltrim($1, $$
2069
$$)
2070
$_$;
2071
2072
2073
--
2074 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2075
--
2076
2077
CREATE FUNCTION map_filter_insert() RETURNS trigger
2078
    LANGUAGE plpgsql
2079
    AS $$
2080
BEGIN
2081
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2082
	RETURN new;
2083
END;
2084
$$;
2085
2086
2087
--
2088 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2089 8146 aaronmk
--
2090
2091
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2092
    LANGUAGE plpgsql STABLE STRICT
2093
    AS $_$
2094
DECLARE
2095
    value text;
2096
BEGIN
2097
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2098 8149 aaronmk
        INTO value USING key;
2099 8146 aaronmk
    RETURN value;
2100
END;
2101
$_$;
2102
2103
2104
--
2105 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2106 10325 aaronmk
--
2107
2108 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2109 10353 aaronmk
    LANGUAGE sql IMMUTABLE
2110 10325 aaronmk
    AS $_$
2111 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
2112 10325 aaronmk
$_$;
2113
2114
2115
--
2116 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2117
--
2118
2119 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
2120
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
2121 10359 aaronmk
2122
[1] inlining of function calls, which is different from constant folding
2123
[2] _map()''s profiling query
2124
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2125
and map_nulls()''s profiling query
2126
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2127 10375 aaronmk
both take ~920 ms.
2128 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.
2129
';
2130 10359 aaronmk
2131
2132
--
2133 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2134 8150 aaronmk
--
2135
2136
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2137
    LANGUAGE plpgsql STABLE STRICT
2138
    AS $_$
2139
BEGIN
2140
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2141
END;
2142
$_$;
2143
2144
2145
--
2146 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2147
--
2148
2149 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2150 12228 aaronmk
    LANGUAGE sql
2151
    AS $_$
2152 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2153 12321 aaronmk
$$||util.ltrim_nl($2));
2154
-- make sure the created table has the correct estimated row count
2155
SELECT util.analyze_($1);
2156 12470 aaronmk
2157
SELECT util.append_comment($1, '
2158
contents generated from:
2159
'||util.ltrim_nl($2)||';
2160
');
2161 12228 aaronmk
$_$;
2162
2163
2164
--
2165 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2166 12228 aaronmk
--
2167
2168 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2169 12235 aaronmk
idempotent
2170
';
2171 12228 aaronmk
2172
2173
--
2174 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2175
--
2176
2177 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2178 12234 aaronmk
    LANGUAGE sql
2179
    AS $_$
2180
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2181
$_$;
2182
2183
2184
--
2185 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2186 12234 aaronmk
--
2187
2188 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2189 12235 aaronmk
idempotent
2190
';
2191 12234 aaronmk
2192
2193
--
2194 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2195
--
2196
2197
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2198 12446 aaronmk
    LANGUAGE sql
2199 8190 aaronmk
    AS $_$
2200 10135 aaronmk
SELECT util.create_if_not_exists($$
2201
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2202 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2203 10135 aaronmk
||quote_literal($2)||$$;
2204 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2205
constant
2206
';
2207 10135 aaronmk
$$)
2208 8190 aaronmk
$_$;
2209
2210
2211
--
2212
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2213
--
2214
2215 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2216
idempotent
2217
';
2218 8190 aaronmk
2219
2220
--
2221 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2222 8187 aaronmk
--
2223
2224 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2225 8187 aaronmk
    LANGUAGE plpgsql STRICT
2226
    AS $_$
2227
DECLARE
2228
    type regtype = util.typeof(expr, col.table_::text::regtype);
2229
    col_name_sql text = quote_ident(col.name);
2230
BEGIN
2231 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2232
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2233 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2234
$$||expr||$$;
2235
$$);
2236
END;
2237
$_$;
2238
2239
2240
--
2241 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2242 8188 aaronmk
--
2243
2244 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2245
idempotent
2246
';
2247 8188 aaronmk
2248
2249
--
2250 12554 aaronmk
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2251 12475 aaronmk
--
2252
2253 12554 aaronmk
CREATE FUNCTION mk_diff_query(left_ text, right_ text, 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
2254 12475 aaronmk
    LANGUAGE sql IMMUTABLE
2255
    AS $_$
2256
SELECT
2257 12478 aaronmk
$$SELECT
2258 12554 aaronmk
$$||$3||$$
2259 12555 aaronmk
FROM      $$||$1||$$ left_
2260 12554 aaronmk
FULL JOIN $$||$2||$$ right_
2261
ON $$||$4||$$
2262
WHERE $$||$5||$$
2263 12475 aaronmk
ORDER BY left_, right_
2264
$$
2265
$_$;
2266
2267
2268
--
2269 12564 aaronmk
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2270
--
2271
2272
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2273 12591 aaronmk
    LANGUAGE sql
2274 12564 aaronmk
    AS $_$
2275 12570 aaronmk
-- keys()
2276 12564 aaronmk
SELECT util.mk_keys_func($1, ARRAY(
2277
SELECT col FROM util.typed_cols($1) col
2278
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2279 12570 aaronmk
));
2280
2281 12571 aaronmk
-- values_()
2282 12570 aaronmk
SELECT util.mk_keys_func($1, COALESCE(
2283
	NULLIF(ARRAY(
2284
	SELECT col FROM util.typed_cols($1) col
2285
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2286
	), ARRAY[]::util.col_cast[])
2287
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2288 12571 aaronmk
, 'values_');
2289 12564 aaronmk
$_$;
2290
2291
2292
--
2293 12569 aaronmk
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2294 12561 aaronmk
--
2295
2296 12569 aaronmk
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2297 12591 aaronmk
    LANGUAGE sql
2298 12561 aaronmk
    AS $_$
2299 12567 aaronmk
SELECT util.create_if_not_exists($$
2300 12577 aaronmk
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2301
($$||util.mk_typed_cols_list($2)||$$);
2302 12671 aaronmk
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2303
autogenerated
2304
';
2305 12594 aaronmk
$$);
2306 12577 aaronmk
2307 12594 aaronmk
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2308
$_$;
2309
2310
2311
--
2312
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2313
--
2314
2315
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2316
    LANGUAGE sql
2317
    AS $_$
2318
SELECT util.create_if_not_exists($$
2319 12581 aaronmk
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2320 12577 aaronmk
||util.qual_name($1)||$$)
2321 12594 aaronmk
  RETURNS $$||util.qual_name($2)||$$ AS
2322 12561 aaronmk
$BODY1$
2323 12577 aaronmk
SELECT ROW($$||
2324 12594 aaronmk
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2325
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2326 12561 aaronmk
$BODY1$
2327
  LANGUAGE sql IMMUTABLE
2328
  COST 100;
2329 12594 aaronmk
$$);
2330 12561 aaronmk
$_$;
2331
2332
2333
--
2334 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2335 8139 aaronmk
--
2336
2337
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2338 12446 aaronmk
    LANGUAGE sql
2339 8139 aaronmk
    AS $_$
2340 8183 aaronmk
SELECT util.create_if_not_exists($$
2341 8141 aaronmk
CREATE TABLE $$||$1||$$
2342 8139 aaronmk
(
2343 8183 aaronmk
    LIKE util.map INCLUDING ALL
2344 10110 aaronmk
);
2345
2346
CREATE TRIGGER map_filter_insert
2347
  BEFORE INSERT
2348
  ON $$||$1||$$
2349
  FOR EACH ROW
2350
  EXECUTE PROCEDURE util.map_filter_insert();
2351 8141 aaronmk
$$)
2352 8139 aaronmk
$_$;
2353
2354
2355
--
2356 12725 aaronmk
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2357
--
2358
2359
CREATE FUNCTION mk_not_null(text) RETURNS text
2360
    LANGUAGE sql IMMUTABLE
2361
    AS $_$
2362
SELECT COALESCE($1, '<NULL>')
2363
$_$;
2364
2365
2366
--
2367 12556 aaronmk
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2368
--
2369
2370
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2371
    LANGUAGE sql IMMUTABLE
2372
    AS $_$
2373 12559 aaronmk
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2374
util.qual_name((unnest).type), ''), '')
2375 12556 aaronmk
FROM unnest($1)
2376
$_$;
2377
2378
2379
--
2380 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382
2383
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2384
    LANGUAGE sql IMMUTABLE
2385
    AS $_$
2386 12486 aaronmk
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2387 12236 aaronmk
$_$;
2388
2389
2390
--
2391 12486 aaronmk
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2392
--
2393
2394
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2395
auto-appends util to the search_path to enable use of util operators
2396
';
2397
2398
2399
--
2400 12467 aaronmk
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2401
--
2402
2403
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2404
    LANGUAGE sql IMMUTABLE
2405
    AS $_$
2406
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2407
$_$;
2408
2409
2410
--
2411 12466 aaronmk
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2412 12270 aaronmk
--
2413
2414 12466 aaronmk
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2415 12270 aaronmk
    LANGUAGE sql IMMUTABLE
2416
    AS $_$
2417 12432 aaronmk
/* debug_print_return_value() needed because this function is used with EXECUTE
2418
rather than util.eval() (in order to affect the calling function), so the
2419
search_path would not otherwise be printed */
2420 12487 aaronmk
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2421
||$$ search_path TO $$||$1
2422 12270 aaronmk
$_$;
2423
2424
2425
--
2426 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2427
--
2428
2429
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2430 12446 aaronmk
    LANGUAGE sql
2431 10113 aaronmk
    AS $_$
2432 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2433 10113 aaronmk
$_$;
2434
2435
2436
--
2437
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2438
--
2439
2440 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2441
idempotent
2442
';
2443 10113 aaronmk
2444
2445
--
2446 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2447
--
2448
2449
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2450
    LANGUAGE plpgsql STRICT
2451
    AS $_$
2452
DECLARE
2453
	view_qual_name text = util.qual_name(view_);
2454
BEGIN
2455
	EXECUTE $$
2456
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2457
  RETURNS SETOF $$||view_||$$ AS
2458
$BODY1$
2459
SELECT * FROM $$||view_qual_name||$$
2460
ORDER BY sort_col
2461
LIMIT $1 OFFSET $2
2462
$BODY1$
2463
  LANGUAGE sql STABLE
2464
  COST 100
2465
  ROWS 1000
2466
$$;
2467
2468
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2469
END;
2470
$_$;
2471
2472
2473
--
2474 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2475
--
2476
2477
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2478
    LANGUAGE plpgsql STRICT
2479
    AS $_$
2480 10990 aaronmk
DECLARE
2481
	view_qual_name text = util.qual_name(view_);
2482
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2483 8325 aaronmk
BEGIN
2484
	EXECUTE $$
2485 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2486
  RETURNS integer AS
2487
$BODY1$
2488
SELECT $$||quote_ident(row_num_col)||$$
2489
FROM $$||view_qual_name||$$
2490
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2491
LIMIT 1
2492
$BODY1$
2493
  LANGUAGE sql STABLE
2494
  COST 100;
2495
$$;
2496
2497
	EXECUTE $$
2498 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2499
  RETURNS SETOF $$||view_||$$ AS
2500
$BODY1$
2501 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
2502
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2503
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2504
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2505 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
2506 8325 aaronmk
$BODY1$
2507
  LANGUAGE sql STABLE
2508
  COST 100
2509
  ROWS 1000
2510
$$;
2511 11010 aaronmk
2512
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2513
END;
2514
$_$;
2515
2516
2517
--
2518
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2519
--
2520
2521
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2522
    LANGUAGE plpgsql STRICT
2523
    AS $_$
2524
DECLARE
2525
	view_qual_name text = util.qual_name(view_);
2526
BEGIN
2527 8326 aaronmk
	EXECUTE $$
2528
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2529
  RETURNS SETOF $$||view_||$$
2530
  SET enable_sort TO 'off'
2531
  AS
2532
$BODY1$
2533 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2534 8326 aaronmk
$BODY1$
2535
  LANGUAGE sql STABLE
2536
  COST 100
2537
  ROWS 1000
2538
;
2539
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2540
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2541
If you want to run EXPLAIN and get expanded output, use the regular subset
2542
function instead. (When a config param is set on a function, EXPLAIN produces
2543
just a function scan.)
2544
';
2545
$$;
2546 8325 aaronmk
END;
2547
$_$;
2548
2549
2550
--
2551 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2552
--
2553
2554 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2555
creates subset function which turns off enable_sort
2556
';
2557 11010 aaronmk
2558
2559
--
2560 12576 aaronmk
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2561
--
2562
2563
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2564
    LANGUAGE sql IMMUTABLE
2565
    AS $_$
2566 12579 aaronmk
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2567 12576 aaronmk
util.qual_name((unnest).type), ', '), '')
2568
FROM unnest($1)
2569
$_$;
2570
2571
2572
--
2573 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2574
--
2575
2576
CREATE FUNCTION name(table_ regclass) RETURNS text
2577
    LANGUAGE sql STABLE
2578
    AS $_$
2579
SELECT relname::text FROM pg_class WHERE oid = $1
2580
$_$;
2581
2582
2583
--
2584 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2585 8083 aaronmk
--
2586
2587
CREATE FUNCTION name(type regtype) RETURNS text
2588 12446 aaronmk
    LANGUAGE sql STABLE
2589 8083 aaronmk
    AS $_$
2590
SELECT typname::text FROM pg_type WHERE oid = $1
2591
$_$;
2592
2593
2594
--
2595 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2596 12355 aaronmk
--
2597
2598 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2599 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2600
    AS $_$
2601 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2602 12355 aaronmk
$_$;
2603
2604
2605
--
2606 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2607
--
2608
2609
CREATE FUNCTION namedatalen() RETURNS integer
2610
    LANGUAGE sql IMMUTABLE
2611
    AS $$
2612
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2613
$$;
2614
2615
2616
--
2617 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2618
--
2619
2620
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2621
    LANGUAGE sql IMMUTABLE
2622
    AS $_$
2623 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2624 9958 aaronmk
$_$;
2625
2626
2627
--
2628 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2629
--
2630
2631
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2632 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2633 9956 aaronmk
    AS $_$
2634
SELECT $1 IS NOT NULL
2635
$_$;
2636
2637
2638
--
2639 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2640
--
2641
2642
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2643
    LANGUAGE sql IMMUTABLE
2644
    AS $_$
2645
SELECT util.hstore($1, NULL) || '*=>*'
2646
$_$;
2647
2648
2649
--
2650
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2651
--
2652
2653 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2654
for use with _map()
2655
';
2656 10373 aaronmk
2657
2658
--
2659 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2660 10984 aaronmk
--
2661
2662 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2663 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2664
    AS $_$
2665 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2666 10984 aaronmk
$_$;
2667
2668
2669
--
2670 12659 aaronmk
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2671
--
2672
2673
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2674
    LANGUAGE sql STABLE
2675
    AS $_$
2676
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2677
$_$;
2678
2679
2680
--
2681 12651 aaronmk
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2682
--
2683
2684
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2685
    LANGUAGE sql
2686
    AS $_$
2687
SELECT util.eval($$INSERT INTO $$||$1||$$
2688
$$||util.ltrim_nl($2));
2689
-- make sure the created table has the correct estimated row count
2690
SELECT util.analyze_($1);
2691
$_$;
2692
2693
2694
--
2695 12575 aaronmk
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2696
--
2697
2698
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2699
    LANGUAGE sql IMMUTABLE
2700
    AS $_$
2701
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2702
$_$;
2703
2704
2705
--
2706 12494 aaronmk
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2707
--
2708
2709
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2710
    LANGUAGE sql
2711
    AS $_$
2712
SELECT util.set_comment($1, concat($2, util.comment($1)))
2713
$_$;
2714
2715
2716
--
2717
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2718
--
2719
2720
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2721
comment: must start and end with a newline
2722
';
2723
2724
2725
--
2726 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2727
--
2728
2729
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2730
    LANGUAGE sql IMMUTABLE
2731
    AS $_$
2732
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2733
$_$;
2734
2735
2736
--
2737 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2738
--
2739
2740
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2741 12446 aaronmk
    LANGUAGE sql STABLE
2742 12267 aaronmk
    SET search_path TO pg_temp
2743 10988 aaronmk
    AS $_$
2744 12267 aaronmk
SELECT $1::text
2745 10988 aaronmk
$_$;
2746
2747
2748
--
2749 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2750
--
2751
2752
CREATE FUNCTION qual_name(type regtype) RETURNS text
2753 12446 aaronmk
    LANGUAGE sql STABLE
2754 12267 aaronmk
    SET search_path TO pg_temp
2755
    AS $_$
2756
SELECT $1::text
2757
$_$;
2758
2759
2760
--
2761
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2762
--
2763
2764
COMMENT ON FUNCTION qual_name(type regtype) IS '
2765
a type''s schema-qualified name
2766
';
2767
2768
2769
--
2770 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772
2773
CREATE FUNCTION qual_name(type unknown) RETURNS text
2774 12446 aaronmk
    LANGUAGE sql STABLE
2775 12268 aaronmk
    AS $_$
2776
SELECT util.qual_name($1::text::regtype)
2777
$_$;
2778
2779
2780
--
2781 12376 aaronmk
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2782
--
2783
2784
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2785
    LANGUAGE sql IMMUTABLE
2786
    AS $_$
2787
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2788
$_$;
2789
2790
2791
--
2792
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2793
--
2794
2795
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2796
    LANGUAGE sql IMMUTABLE
2797
    AS $_$
2798
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2799
$_$;
2800
2801
2802
--
2803 12371 aaronmk
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2804
--
2805
2806
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2807
    LANGUAGE sql IMMUTABLE
2808
    AS $_$
2809 12437 aaronmk
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2810 12371 aaronmk
$_$;
2811
2812
2813
--
2814 12530 aaronmk
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2815
--
2816
2817
CREATE FUNCTION raise(type text, msg text) RETURNS void
2818
    LANGUAGE sql IMMUTABLE
2819 12560 aaronmk
    AS $_X$
2820 12530 aaronmk
SELECT util.eval($$
2821
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2822
  RETURNS void AS
2823 12560 aaronmk
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2824
$__BODY1$
2825 12530 aaronmk
BEGIN
2826
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2827
END;
2828 12560 aaronmk
$__BODY1$
2829 12530 aaronmk
  LANGUAGE plpgsql IMMUTABLE
2830
  COST 100;
2831 12532 aaronmk
$$, verbose_ := false);
2832 12530 aaronmk
2833 12532 aaronmk
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2834 12560 aaronmk
$_X$;
2835 12530 aaronmk
2836
2837
--
2838 12533 aaronmk
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2839
--
2840
2841
COMMENT ON FUNCTION raise(type text, msg text) IS '
2842
type: a log level from
2843
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2844
or a condition name from
2845
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2846
';
2847
2848
2849
--
2850 12536 aaronmk
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2851 12311 aaronmk
--
2852
2853 12536 aaronmk
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2854 12441 aaronmk
    LANGUAGE sql IMMUTABLE
2855 12311 aaronmk
    AS $_$
2856 12536 aaronmk
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2857 12311 aaronmk
$_$;
2858
2859
2860
--
2861 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2862
--
2863
2864
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2865
    LANGUAGE plpgsql IMMUTABLE STRICT
2866
    AS $$
2867
BEGIN
2868
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2869
END;
2870
$$;
2871
2872
2873
--
2874 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2875
--
2876
2877
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2878
    LANGUAGE sql IMMUTABLE
2879
    AS $_$
2880
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2881
$_$;
2882
2883
2884
--
2885 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2886
--
2887
2888
CREATE FUNCTION regexp_quote(str text) RETURNS text
2889
    LANGUAGE sql IMMUTABLE
2890
    AS $_$
2891
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2892
$_$;
2893
2894
2895
--
2896 12375 aaronmk
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2897
--
2898
2899
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2900
    LANGUAGE sql IMMUTABLE
2901
    AS $_$
2902
SELECT (CASE WHEN right($1, 1) = ')'
2903 12377 aaronmk
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2904 12375 aaronmk
$_$;
2905
2906
2907
--
2908 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2909
--
2910
2911
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2912
    LANGUAGE sql STABLE
2913
    AS $_$
2914
SELECT util.relation_type(util.relation_type_char($1))
2915
$_$;
2916
2917
2918
--
2919 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2920 12339 aaronmk
--
2921
2922 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2923 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2924
    AS $_$
2925 12593 aaronmk
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2926 12339 aaronmk
$_$;
2927
2928
2929
--
2930 12588 aaronmk
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2931
--
2932
2933
CREATE FUNCTION relation_type(type regtype) RETURNS text
2934
    LANGUAGE sql IMMUTABLE
2935
    AS $$
2936
SELECT 'TYPE'::text
2937
$$;
2938
2939
2940
--
2941 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2942
--
2943
2944
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2945
    LANGUAGE sql STABLE
2946
    AS $_$
2947
SELECT relkind FROM pg_class WHERE oid = $1
2948
$_$;
2949
2950
2951
--
2952 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2953
--
2954
2955
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2956
    LANGUAGE sql
2957
    AS $_$
2958
/* can't have in_table/out_table inherit from *each other*, because inheritance
2959
also causes the rows of the parent table to be included in the child table.
2960
instead, they need to inherit from a common, empty table. */
2961 12382 aaronmk
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2962
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2963 13098 aaronmk
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
2964 12293 aaronmk
SELECT util.inherit($2, $4);
2965
SELECT util.inherit($3, $4);
2966
2967
SELECT util.rematerialize_query($1, $$
2968
SELECT * FROM util.diff(
2969 12419 aaronmk
  $$||util.quote_typed($2)||$$
2970
, $$||util.quote_typed($3)||$$
2971 12293 aaronmk
, NULL::$$||$4||$$)
2972
$$);
2973 12303 aaronmk
2974
/* the table unfortunately cannot be *materialized* in human-readable form,
2975
because this would create column name collisions between the two sides */
2976 12495 aaronmk
SELECT util.prepend_comment($1, '
2977 12303 aaronmk
to view this table in human-readable form (with each side''s tuple column
2978
expanded to its component fields):
2979 12572 aaronmk
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2980 13092 aaronmk
2981
to display NULL values that are extra or missing:
2982
SELECT * FROM '||$1||';
2983 12303 aaronmk
');
2984 12293 aaronmk
$_$;
2985
2986
2987
--
2988
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2989
--
2990
2991
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2992
type_table (*required*): table to create as the shared base type
2993
';
2994
2995
2996
--
2997 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2998
--
2999
3000
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3001
    LANGUAGE sql
3002
    AS $_$
3003
SELECT util.drop_table($1);
3004
SELECT util.materialize_query($1, $2);
3005
$_$;
3006
3007
3008
--
3009
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3010
--
3011
3012
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3013
idempotent, but repeats action each time
3014
';
3015
3016
3017
--
3018 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3019
--
3020
3021 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3022 12247 aaronmk
    LANGUAGE sql
3023
    AS $_$
3024
SELECT util.drop_table($1);
3025
SELECT util.materialize_view($1, $2);
3026
$_$;
3027
3028
3029
--
3030 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3031 12247 aaronmk
--
3032
3033 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3034 12247 aaronmk
idempotent, but repeats action each time
3035
';
3036
3037
3038
--
3039 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3040 8137 aaronmk
--
3041
3042 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3043 12446 aaronmk
    LANGUAGE sql
3044 8137 aaronmk
    AS $_$
3045 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3046 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3047 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
3048
SELECT NULL::void; -- don't fold away functions called in previous query
3049 8137 aaronmk
$_$;
3050
3051
3052
--
3053 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3054 8137 aaronmk
--
3055
3056 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3057
idempotent
3058
';
3059 8137 aaronmk
3060
3061
--
3062 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3063
--
3064
3065
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3066
    LANGUAGE sql
3067
    AS $_$
3068 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3069
included in the debug SQL */
3070
SELECT util.rename_relation(util.qual_name($1), $2)
3071 12349 aaronmk
$_$;
3072
3073
3074
--
3075
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3076
--
3077
3078 12364 aaronmk
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3079 12349 aaronmk
    LANGUAGE sql
3080
    AS $_$
3081
/* 'ALTER TABLE can be used with views too'
3082
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3083 12363 aaronmk
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3084
||quote_ident($2))
3085 12349 aaronmk
$_$;
3086
3087
3088
--
3089 12364 aaronmk
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3090 12349 aaronmk
--
3091
3092 12364 aaronmk
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3093 12349 aaronmk
idempotent
3094
';
3095
3096
3097
--
3098 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3099 12350 aaronmk
--
3100
3101 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3102 12350 aaronmk
    LANGUAGE sql IMMUTABLE
3103
    AS $_$
3104 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3105 12350 aaronmk
$_$;
3106
3107
3108
--
3109 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3110
--
3111
3112
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3113
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
3114
';
3115
3116
3117
--
3118 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3119
--
3120
3121
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3122 12446 aaronmk
    LANGUAGE sql
3123 10297 aaronmk
    AS $_$
3124 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3125
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3126 10297 aaronmk
SELECT util.set_col_names($1, $2);
3127
$_$;
3128
3129
3130
--
3131
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3132
--
3133
3134 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3135
idempotent.
3136
alters the names table, so it will need to be repopulated after running this function.
3137
';
3138 10297 aaronmk
3139
3140
--
3141 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3142 8143 aaronmk
--
3143
3144
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3145 12446 aaronmk
    LANGUAGE sql
3146 8143 aaronmk
    AS $_$
3147 10152 aaronmk
SELECT util.drop_table($1);
3148 8183 aaronmk
SELECT util.mk_map_table($1);
3149 8143 aaronmk
$_$;
3150
3151
3152
--
3153 13096 aaronmk
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3154
--
3155
3156
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3157
    LANGUAGE sql
3158
    AS $_$
3159
SELECT util.drop_column($1, $2, force := true)
3160
$_$;
3161
3162
3163
--
3164 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3165
--
3166
3167
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3168
    LANGUAGE sql IMMUTABLE
3169
    AS $_$
3170
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3171
$_$;
3172
3173
3174
--
3175 12473 aaronmk
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3176
--
3177
3178
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3179
    LANGUAGE sql IMMUTABLE
3180
    AS $_$
3181 12481 aaronmk
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3182
ELSE util.mk_set_search_path(for_printing := true)||$$;
3183
$$ END)||$1
3184 12473 aaronmk
$_$;
3185
3186
3187
--
3188 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3189
--
3190
3191
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3192
    LANGUAGE plpgsql STRICT
3193
    AS $_$
3194
DECLARE
3195
	result text = NULL;
3196
BEGIN
3197
	BEGIN
3198
		result = util.show_create_view(view_);
3199
		PERFORM util.eval($$DROP VIEW $$||view_);
3200
	EXCEPTION
3201
		WHEN undefined_table THEN NULL;
3202
	END;
3203
	RETURN result;
3204
END;
3205
$_$;
3206
3207
3208
--
3209 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3210
--
3211
3212
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3213
    LANGUAGE sql
3214
    AS $_$
3215 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3216 11660 aaronmk
$_$;
3217
3218
3219
--
3220 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3221
--
3222
3223
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3224
    LANGUAGE sql STABLE
3225
    AS $_$
3226
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3227
$_$;
3228
3229
3230
--
3231 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3232
--
3233
3234
CREATE FUNCTION schema(table_ regclass) RETURNS text
3235
    LANGUAGE sql STABLE
3236
    AS $_$
3237 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3238 12242 aaronmk
$_$;
3239
3240
3241
--
3242 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3243
--
3244
3245
CREATE FUNCTION schema(type regtype) RETURNS text
3246
    LANGUAGE sql STABLE
3247
    AS $_$
3248 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3249 10794 aaronmk
$_$;
3250
3251
3252
--
3253
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3254
--
3255
3256
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3257
    LANGUAGE sql STABLE
3258
    AS $_$
3259
SELECT util.schema(pg_typeof($1))
3260
$_$;
3261
3262
3263
--
3264 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3265
--
3266
3267
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3268
    LANGUAGE sql STABLE
3269
    AS $_$
3270
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3271
$_$;
3272
3273
3274
--
3275 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3276
--
3277
3278 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3279
a schema bundle is a group of schemas with a common prefix
3280
';
3281 12135 aaronmk
3282
3283
--
3284
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3285
--
3286
3287
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3288
    LANGUAGE sql
3289
    AS $_$
3290
SELECT util.schema_rename(old_schema,
3291
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3292
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3293
SELECT NULL::void; -- don't fold away functions called in previous query
3294
$_$;
3295
3296
3297
--
3298
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3299
--
3300
3301
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3302
    LANGUAGE plpgsql
3303
    AS $$
3304
BEGIN
3305
	-- don't schema_bundle_rm() the schema_bundle to keep!
3306
	IF replace = with_ THEN RETURN; END IF;
3307
3308
	PERFORM util.schema_bundle_rm(replace);
3309
	PERFORM util.schema_bundle_rename(with_, replace);
3310
END;
3311
$$;
3312
3313
3314
--
3315
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3316
--
3317
3318
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3319
    LANGUAGE sql
3320
    AS $_$
3321
SELECT util.schema_rm(schema)
3322
FROM util.schema_bundle_get_schemas($1) f (schema);
3323
SELECT NULL::void; -- don't fold away functions called in previous query
3324
$_$;
3325
3326
3327
--
3328 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3329 10795 aaronmk
--
3330
3331 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3332 10795 aaronmk
    LANGUAGE sql STABLE
3333
    AS $_$
3334
SELECT quote_ident(util.schema($1))
3335
$_$;
3336
3337
3338
--
3339 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3340
--
3341
3342
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3343 12334 aaronmk
    LANGUAGE sql IMMUTABLE
3344 12324 aaronmk
    AS $_$
3345
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3346
$_$;
3347
3348
3349
--
3350 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3351
--
3352
3353
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3354
    LANGUAGE sql STABLE
3355
    AS $_$
3356
SELECT oid FROM pg_namespace WHERE nspname = $1
3357
$_$;
3358
3359
3360
--
3361 12504 aaronmk
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3362
--
3363
3364
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3365
    LANGUAGE sql IMMUTABLE
3366
    AS $_$
3367
SELECT util.schema_regexp(schema_anchor := $1)
3368
$_$;
3369
3370
3371
--
3372 12501 aaronmk
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3373
--
3374
3375
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3376
    LANGUAGE sql IMMUTABLE
3377
    AS $_$
3378
SELECT util.str_equality_regexp(util.schema($1))
3379
$_$;
3380
3381
3382
--
3383 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3384
--
3385
3386
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3387
    LANGUAGE sql
3388
    AS $_$
3389
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3390
$_$;
3391
3392
3393
--
3394 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3395
--
3396
3397
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3398
    LANGUAGE plpgsql
3399
    AS $$
3400
BEGIN
3401
	-- don't schema_rm() the schema to keep!
3402
	IF replace = with_ THEN RETURN; END IF;
3403
3404
	PERFORM util.schema_rm(replace);
3405
	PERFORM util.schema_rename(with_, replace);
3406
END;
3407
$$;
3408
3409
3410
--
3411 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3412
--
3413
3414
CREATE FUNCTION schema_rm(schema text) RETURNS void
3415
    LANGUAGE sql
3416
    AS $_$
3417
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3418
$_$;
3419
3420
3421
--
3422 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3423
--
3424
3425
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3426 12446 aaronmk
    LANGUAGE sql
3427 9825 aaronmk
    AS $_$
3428
SELECT util.eval(
3429
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3430
$_$;
3431
3432
3433
--
3434 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3435 8153 aaronmk
--
3436
3437
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3438
    LANGUAGE plpgsql STRICT
3439
    AS $_$
3440
DECLARE
3441 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
3442
    new text[] = ARRAY(SELECT util.map_values(names));
3443 8153 aaronmk
BEGIN
3444
    old = old[1:array_length(new, 1)]; -- truncate to same length
3445 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3446
||$$ TO $$||quote_ident(value))
3447 10149 aaronmk
    FROM each(hstore(old, new))
3448
    WHERE value != key -- not same name
3449
    ;
3450 8153 aaronmk
END;
3451
$_$;
3452
3453
3454
--
3455 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3456 8153 aaronmk
--
3457
3458 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3459
idempotent
3460
';
3461 8153 aaronmk
3462
3463
--
3464 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3465
--
3466
3467
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3468
    LANGUAGE plpgsql STRICT
3469
    AS $_$
3470
DECLARE
3471
	row_ util.map;
3472
BEGIN
3473 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
3474
	BEGIN
3475
		PERFORM util.set_col_names(table_, names);
3476
	EXCEPTION
3477
		WHEN array_subscript_error THEN -- selective suppress
3478
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3479
				-- metadata cols not yet added
3480 12568 aaronmk
			ELSE RAISE;
3481 10715 aaronmk
			END IF;
3482
	END;
3483
3484 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3485 10145 aaronmk
	LOOP
3486 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
3487
			substring(row_."from" from 2));
3488 10145 aaronmk
	END LOOP;
3489
3490
	PERFORM util.set_col_names(table_, names);
3491
END;
3492
$_$;
3493
3494
3495
--
3496
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3497
--
3498
3499 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3500
idempotent.
3501
the metadata mappings must be *last* in the names table.
3502
';
3503 10145 aaronmk
3504
3505
--
3506 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3507 8107 aaronmk
--
3508
3509
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3510 12733 aaronmk
    LANGUAGE sql
3511 8107 aaronmk
    AS $_$
3512 12734 aaronmk
SELECT util.eval(COALESCE(
3513
$$ALTER TABLE $$||$1||$$
3514 12732 aaronmk
$$||(
3515
	SELECT
3516
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3517
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3518
, $$)
3519
	FROM
3520
	(
3521
		SELECT
3522
		  quote_ident(col_name) AS col_name_sql
3523 12733 aaronmk
		, util.col_type(($1, col_name)) AS curr_type
3524 12732 aaronmk
		, type AS target_type
3525 12733 aaronmk
		FROM unnest($2)
3526 12732 aaronmk
	) s
3527
	WHERE curr_type != target_type
3528 12734 aaronmk
), ''))
3529 8107 aaronmk
$_$;
3530
3531
3532
--
3533 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3534 8107 aaronmk
--
3535
3536 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3537
idempotent
3538
';
3539 8107 aaronmk
3540
3541
--
3542 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3543
--
3544
3545
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3546 12446 aaronmk
    LANGUAGE sql
3547 12302 aaronmk
    AS $_$
3548
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3549
$_$;
3550
3551
3552
--
3553 12482 aaronmk
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3554
--
3555
3556
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3557
    LANGUAGE sql
3558
    AS $_$
3559
SELECT util.eval(util.mk_set_search_path($1, $2))
3560
$_$;
3561
3562
3563
--
3564 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3565
--
3566
3567
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3568
    LANGUAGE sql STABLE
3569
    AS $_$
3570 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3571
$$||util.show_grants_for($1)
3572 11651 aaronmk
$_$;
3573
3574
3575
--
3576 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3577
--
3578
3579
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3580
    LANGUAGE sql STABLE
3581
    AS $_$
3582 12269 aaronmk
SELECT string_agg(cmd, '')
3583 11655 aaronmk
FROM
3584
(
3585
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3586
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3587
$$ ELSE '' END) AS cmd
3588
	FROM util.grants_users() f (user_)
3589
) s
3590
$_$;
3591
3592
3593
--
3594 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3595
--
3596
3597 12670 aaronmk
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['c'::text, 'r'::text, 'v'::text]) RETURNS SETOF regclass
3598 12325 aaronmk
    LANGUAGE sql STABLE
3599
    AS $_$
3600
SELECT oid FROM pg_class
3601
WHERE relkind = ANY($3) AND relname ~ $1
3602
AND util.schema_matches(util.schema(relnamespace), $2)
3603
ORDER BY relname
3604
$_$;
3605
3606
3607
--
3608 12592 aaronmk
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3609
--
3610
3611
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3612
    LANGUAGE sql STABLE
3613
    AS $_$
3614
SELECT oid
3615
FROM pg_type
3616
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3617
ORDER BY typname
3618
$_$;
3619
3620
3621
--
3622 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3623
--
3624
3625 12385 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3626 12305 aaronmk
    LANGUAGE sql STABLE
3627
    AS $_$
3628 12385 aaronmk
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3629 12305 aaronmk
$_$;
3630
3631
3632
--
3633 12384 aaronmk
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3634
--
3635
3636
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3637
    LANGUAGE sql IMMUTABLE
3638
    AS $_$
3639
SELECT '^'||util.regexp_quote($1)||'$'
3640
$_$;
3641
3642
3643
--
3644 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3645 8144 aaronmk
--
3646
3647
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3648 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
3649 8144 aaronmk
    AS $_$
3650
DECLARE
3651
    hstore hstore;
3652
BEGIN
3653
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3654
        table_||$$))$$ INTO STRICT hstore;
3655
    RETURN hstore;
3656
END;
3657
$_$;
3658
3659
3660
--
3661 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3662
--
3663
3664
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3665 12446 aaronmk
    LANGUAGE sql STABLE
3666 10184 aaronmk
    AS $_$
3667
SELECT COUNT(*) > 0 FROM pg_constraint
3668
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3669
$_$;
3670
3671
3672
--
3673
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3674
--
3675
3676 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3677
gets whether a status flag is set by the presence of a table constraint
3678
';
3679 10184 aaronmk
3680
3681
--
3682 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3683
--
3684
3685
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3686 12446 aaronmk
    LANGUAGE sql
3687 10182 aaronmk
    AS $_$
3688
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3689
||quote_ident($2)||$$ CHECK (true)$$)
3690
$_$;
3691
3692
3693
--
3694
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3695
--
3696
3697 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3698
stores a status flag by the presence of a table constraint.
3699
idempotent.
3700
';
3701 10182 aaronmk
3702
3703
--
3704 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3705
--
3706
3707
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3708 12446 aaronmk
    LANGUAGE sql STABLE
3709 10185 aaronmk
    AS $_$
3710
SELECT util.table_flag__get($1, 'nulls_mapped')
3711
$_$;
3712
3713
3714
--
3715
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3716
--
3717
3718 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3719
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3720
';
3721 10185 aaronmk
3722
3723
--
3724 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3725
--
3726
3727
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3728 12446 aaronmk
    LANGUAGE sql
3729 10183 aaronmk
    AS $_$
3730
SELECT util.table_flag__set($1, 'nulls_mapped')
3731
$_$;
3732
3733
3734
--
3735
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3736
--
3737
3738 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3739
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3740
idempotent.
3741
';
3742 10183 aaronmk
3743
3744
--
3745 12652 aaronmk
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3746
--
3747
3748
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3749
    LANGUAGE sql
3750
    AS $_$
3751
-- save data before truncating main table
3752
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3753
3754
-- repopulate main table w/ copies column
3755
SELECT util.truncate($1);
3756
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3757
SELECT util.populate_table($1, $$
3758
SELECT (table_).*, copies
3759
FROM (
3760
	SELECT table_, COUNT(*) AS copies
3761
	FROM pg_temp.__copy table_
3762
	GROUP BY table_
3763
) s
3764
$$);
3765
3766
-- delete temp table so it doesn't stay around until end of connection
3767
SELECT util.drop_table('pg_temp.__copy');
3768
$_$;
3769
3770
3771
--
3772 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3773 8088 aaronmk
--
3774
3775
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3776
    LANGUAGE plpgsql STRICT
3777
    AS $_$
3778
DECLARE
3779
    row record;
3780
BEGIN
3781 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3782 8088 aaronmk
    LOOP
3783
        IF row.global_name != row.name THEN
3784
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3785
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3786
        END IF;
3787
    END LOOP;
3788
END;
3789
$_$;
3790
3791
3792
--
3793 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3794 8088 aaronmk
--
3795
3796 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3797
idempotent
3798
';
3799 8088 aaronmk
3800
3801
--
3802 12874 aaronmk
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3803 10365 aaronmk
--
3804
3805 12874 aaronmk
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
3806 12446 aaronmk
    LANGUAGE sql
3807 10365 aaronmk
    AS $_$
3808 12874 aaronmk
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
3809 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3810
$_$;
3811
3812
3813
--
3814 12874 aaronmk
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
3815 10365 aaronmk
--
3816
3817 12874 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
3818
trims table_ to include only columns in the original data
3819
3820
by default, cascadingly drops dependent columns so that they don''t prevent
3821
trim() from succeeding. note that this requires the dependent columns to then be
3822
manually re-created.
3823
3824
idempotent
3825 12235 aaronmk
';
3826 10365 aaronmk
3827
3828
--
3829 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3830 8142 aaronmk
--
3831
3832
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3833
    LANGUAGE plpgsql STRICT
3834
    AS $_$
3835
BEGIN
3836
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3837
END;
3838
$_$;
3839
3840
3841
--
3842 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3843 8142 aaronmk
--
3844
3845 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3846
idempotent
3847
';
3848 8142 aaronmk
3849
3850
--
3851 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3852
--
3853
3854
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3855
    LANGUAGE sql IMMUTABLE
3856
    AS $_$
3857 12361 aaronmk
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3858 12362 aaronmk
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3859 12357 aaronmk
$_$;
3860
3861
3862
--
3863 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3864
--
3865
3866
CREATE FUNCTION try_create(sql text) RETURNS void
3867
    LANGUAGE plpgsql STRICT
3868
    AS $$
3869
BEGIN
3870 12658 aaronmk
	PERFORM util.eval(sql);
3871 8199 aaronmk
EXCEPTION
3872 12676 aaronmk
WHEN   not_null_violation
3873
		/* trying to add NOT NULL column to parent table, which cascades to
3874
		child table whose values for the new column will be NULL */
3875
	OR wrong_object_type -- trying to alter a view's columns
3876
	OR undefined_column
3877
	OR duplicate_column
3878
THEN NULL;
3879 12684 aaronmk
WHEN datatype_mismatch THEN
3880
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
3881
	ELSE RAISE; -- rethrow
3882
	END IF;
3883 8199 aaronmk
END;
3884
$$;
3885
3886
3887
--
3888
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3889
--
3890
3891 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
3892
idempotent
3893
';
3894 8199 aaronmk
3895
3896
--
3897 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3898
--
3899
3900
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3901 12446 aaronmk
    LANGUAGE sql
3902 8209 aaronmk
    AS $_$
3903
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3904
$_$;
3905
3906
3907
--
3908
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3909
--
3910
3911 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3912
idempotent
3913
';
3914 8209 aaronmk
3915
3916
--
3917 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3918
--
3919
3920
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3921
    LANGUAGE sql IMMUTABLE
3922
    AS $_$
3923
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3924
$_$;
3925
3926
3927
--
3928 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3929
--
3930
3931 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3932
a type''s NOT NULL qualifier
3933
';
3934 10161 aaronmk
3935
3936
--
3937 12562 aaronmk
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3938
--
3939
3940
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3941 12590 aaronmk
    LANGUAGE sql STABLE
3942 12562 aaronmk
    AS $_$
3943
SELECT (attname::text, atttypid)::util.col_cast
3944
FROM pg_attribute
3945
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3946
ORDER BY attnum
3947
$_$;
3948
3949
3950
--
3951 12438 aaronmk
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3952
--
3953
3954
CREATE FUNCTION typeof(value anyelement) RETURNS text
3955
    LANGUAGE sql IMMUTABLE
3956
    AS $_$
3957
SELECT util.qual_name(pg_typeof($1))
3958
$_$;
3959
3960
3961
--
3962 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3963
--
3964
3965 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3966
    LANGUAGE plpgsql STABLE
3967 8185 aaronmk
    AS $_$
3968
DECLARE
3969
    type regtype;
3970
BEGIN
3971 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3972
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3973 8185 aaronmk
    RETURN type;
3974
END;
3975
$_$;
3976
3977
3978
--
3979 12490 aaronmk
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3980 12483 aaronmk
--
3981
3982 12490 aaronmk
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3983 12483 aaronmk
    LANGUAGE sql
3984
    AS $_$
3985 12488 aaronmk
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3986 12483 aaronmk
$_$;
3987
3988
3989
--
3990 12490 aaronmk
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3991 12488 aaronmk
--
3992
3993 12490 aaronmk
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3994 12488 aaronmk
auto-appends util to the search_path to enable use of util operators
3995
';
3996
3997
3998
--
3999 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4000
--
4001
4002
CREATE AGGREGATE all_same(anyelement) (
4003
    SFUNC = all_same_transform,
4004
    STYPE = anyarray,
4005
    FINALFUNC = all_same_final
4006
);
4007
4008
4009
--
4010
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4011
--
4012
4013 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
4014
includes NULLs in comparison
4015
';
4016 9959 aaronmk
4017
4018
--
4019 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4020 2595 aaronmk
--
4021
4022
CREATE AGGREGATE join_strs(text, text) (
4023 4052 aaronmk
    SFUNC = join_strs_transform,
4024 4010 aaronmk
    STYPE = text
4025 2595 aaronmk
);
4026
4027
4028 8147 aaronmk
--
4029 12423 aaronmk
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4030
--
4031
4032
CREATE OPERATOR %== (
4033
    PROCEDURE = "%==",
4034
    LEFTARG = anyelement,
4035
    RIGHTARG = anyelement
4036
);
4037
4038
4039
--
4040
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4041
--
4042
4043
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4044
returns whether the map-keys of the compared values are the same
4045
(mnemonic: % is the Perl symbol for a hash map)
4046
4047
should be overridden for types that store both keys and values
4048
4049
used in a FULL JOIN to select which columns to join on
4050
';
4051
4052
4053
--
4054 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4055 8147 aaronmk
--
4056
4057
CREATE OPERATOR -> (
4058
    PROCEDURE = map_get,
4059
    LEFTARG = regclass,
4060
    RIGHTARG = text
4061
);
4062
4063
4064 10308 aaronmk
--
4065
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4066
--
4067
4068
CREATE OPERATOR => (
4069
    PROCEDURE = hstore,
4070 10357 aaronmk
    LEFTARG = text[],
4071 10608 aaronmk
    RIGHTARG = text
4072 10308 aaronmk
);
4073
4074
4075
--
4076 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4077 10308 aaronmk
--
4078
4079 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
4080
usage: array[''key1'', ...]::text[] => ''value''
4081
';
4082 10308 aaronmk
4083
4084 10391 aaronmk
--
4085 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4086
--
4087
4088
CREATE OPERATOR ?*>= (
4089
    PROCEDURE = is_populated_more_often_than,
4090
    LEFTARG = anyelement,
4091
    RIGHTARG = anyelement
4092
);
4093
4094
4095
--
4096 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4097
--
4098
4099
CREATE OPERATOR ?>= (
4100
    PROCEDURE = is_more_complete_than,
4101
    LEFTARG = anyelement,
4102
    RIGHTARG = anyelement
4103
);
4104
4105
4106 11005 aaronmk
--
4107
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4108
--
4109
4110
CREATE OPERATOR ||% (
4111
    PROCEDURE = concat_esc,
4112
    LEFTARG = text,
4113
    RIGHTARG = text
4114
);
4115
4116
4117
--
4118
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4119
--
4120
4121 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
4122
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4123
';
4124 11005 aaronmk
4125
4126 2107 aaronmk
--
4127 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
4128 8140 aaronmk
--
4129
4130
CREATE TABLE map (
4131
    "from" text NOT NULL,
4132 8158 aaronmk
    "to" text,
4133
    filter text,
4134
    notes text
4135 8140 aaronmk
);
4136
4137
4138
--
4139 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4140
--
4141
4142
4143
4144
--
4145 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4146 8140 aaronmk
--
4147
4148
4149
4150
--
4151 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
4152 8140 aaronmk
--
4153
4154
ALTER TABLE ONLY map
4155 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4156 8140 aaronmk
4157
4158
--
4159 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
4160
--
4161
4162
ALTER TABLE ONLY map
4163
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4164
4165
4166
--
4167 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4168
--
4169
4170
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4171
4172
4173
--
4174 2136 aaronmk
-- PostgreSQL database dump complete
4175
--