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