Project

General

Profile

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