Project

General

Profile

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