Project

General

Profile

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