Project

General

Profile

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