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 12474 aaronmk
$$||util.runnable_sql($1)||$$
992 12464 aaronmk
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
993 12250 aaronmk
$_$;
994
995
996
--
997 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
998
--
999
1000
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1001 12446 aaronmk
    LANGUAGE sql STABLE
1002 10364 aaronmk
    AS $_$
1003
SELECT util.eval2set($$
1004
SELECT col
1005
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1006
LEFT JOIN $$||$2||$$ ON "to" = col
1007
WHERE "from" IS NULL
1008
$$, NULL::text)
1009
$_$;
1010
1011
1012
--
1013
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1014
--
1015
1016 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1017
gets table_''s derived columns (all the columns not in the names table)
1018
';
1019 10364 aaronmk
1020
1021
--
1022 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1023 12044 aaronmk
--
1024
1025 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1026 12427 aaronmk
    LANGUAGE sql
1027 12044 aaronmk
    AS $_$
1028 12300 aaronmk
SELECT * FROM util.diff($1::text, $2::text, $3,
1029 12491 aaronmk
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1030 12298 aaronmk
$_$;
1031
1032
1033
--
1034
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1035
--
1036
1037
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1038
col_type_null (*required*): NULL::shared_base_type
1039
usage:
1040
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1041
';
1042
1043
1044
--
1045 12491 aaronmk
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1046 12298 aaronmk
--
1047
1048 12491 aaronmk
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1049 12429 aaronmk
    LANGUAGE plpgsql
1050
    SET search_path TO pg_temp
1051 12298 aaronmk
    AS $_$
1052 12429 aaronmk
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1053
changes of search_path (schema elements are bound at inline time rather than
1054
runtime) */
1055
/* function option search_path is needed to limit the effects of
1056 12492 aaronmk
`SET LOCAL search_path` to the current function */
1057 12429 aaronmk
BEGIN
1058 12491 aaronmk
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1059 12429 aaronmk
1060
	RETURN QUERY
1061 12479 aaronmk
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2, $4,
1062
$$/* need to explicitly cast each side to the return type because this does not
1063 12284 aaronmk
happen automatically even when an implicit cast is available */
1064 12479 aaronmk
  left_::$$||util.typeof($3)||$$
1065
, right_::$$||util.typeof($3)
1066
), $3)
1067 12429 aaronmk
	;
1068
END;
1069 12044 aaronmk
$_$;
1070
1071
1072
--
1073 12491 aaronmk
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1074 12280 aaronmk
--
1075
1076 12491 aaronmk
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1077 12280 aaronmk
col_type_null (*required*): NULL::col_type
1078 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
1079
	displayed side-by-side
1080 12282 aaronmk
1081
to run EXPLAIN on the FULL JOIN query:
1082
# run this function
1083
# look for a NOTICE containing the expanded query that it ran
1084
# run EXPLAIN on this expanded query
1085 12280 aaronmk
';
1086
1087
1088
--
1089 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1090
--
1091
1092
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1093 12446 aaronmk
    LANGUAGE sql
1094 8200 aaronmk
    AS $_$
1095
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1096
$_$;
1097
1098
1099
--
1100
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1101
--
1102
1103 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1104
idempotent
1105
';
1106 8200 aaronmk
1107
1108
--
1109 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1110 10362 aaronmk
--
1111
1112 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1113 12446 aaronmk
    LANGUAGE sql
1114 10362 aaronmk
    AS $_$
1115
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1116 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1117 10362 aaronmk
$_$;
1118
1119
1120
--
1121 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1122 10362 aaronmk
--
1123
1124 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1125 12235 aaronmk
idempotent
1126
';
1127 10362 aaronmk
1128
1129
--
1130 12331 aaronmk
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1131
--
1132
1133
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1134
    LANGUAGE sql
1135
    AS $_$
1136 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1137
included in the debug SQL */
1138
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1139 12331 aaronmk
$_$;
1140
1141
1142
--
1143 12343 aaronmk
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1144
--
1145
1146 12364 aaronmk
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1147 12343 aaronmk
    LANGUAGE sql
1148
    AS $_$
1149 12347 aaronmk
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1150 12343 aaronmk
||util._if($3, $$ CASCADE$$, ''::text))
1151
$_$;
1152
1153
1154
--
1155 12364 aaronmk
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1156 12343 aaronmk
--
1157
1158 12364 aaronmk
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1159 12343 aaronmk
idempotent
1160
';
1161
1162
1163
--
1164 12413 aaronmk
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1165
--
1166
1167
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1168
    LANGUAGE sql
1169
    AS $_$
1170
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1171
$3)
1172
$_$;
1173
1174
1175
--
1176
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1177
--
1178
1179
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1180
    LANGUAGE sql
1181
    AS $_$
1182
SELECT util.drop_relation(relation, $3)
1183
FROM util.show_relations_like($1, $2) relation
1184
;
1185
SELECT NULL::void; -- don't fold away functions called in previous query
1186
$_$;
1187
1188
1189
--
1190 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1191 10150 aaronmk
--
1192
1193 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1194 12446 aaronmk
    LANGUAGE sql
1195 10150 aaronmk
    AS $_$
1196 12347 aaronmk
SELECT util.drop_relation('TABLE', $1, $2)
1197 10150 aaronmk
$_$;
1198
1199
1200
--
1201 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1202 10150 aaronmk
--
1203
1204 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1205 12235 aaronmk
idempotent
1206
';
1207 10150 aaronmk
1208
1209
--
1210 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1211 12229 aaronmk
--
1212
1213 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1214 12446 aaronmk
    LANGUAGE sql
1215 12229 aaronmk
    AS $_$
1216 12347 aaronmk
SELECT util.drop_relation('VIEW', $1, $2)
1217 12229 aaronmk
$_$;
1218
1219
1220
--
1221 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1222 12229 aaronmk
--
1223
1224 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1225 12235 aaronmk
idempotent
1226
';
1227 12229 aaronmk
1228
1229
--
1230 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1231
--
1232
1233
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1234
    LANGUAGE sql IMMUTABLE
1235
    AS $_$
1236
SELECT util.array_fill($1, 0)
1237
$_$;
1238
1239
1240
--
1241
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1242
--
1243
1244 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1245
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1246
';
1247 10322 aaronmk
1248
1249
--
1250 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1251 8086 aaronmk
--
1252
1253
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1254 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1255 8086 aaronmk
    AS $_$
1256 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1257 8086 aaronmk
$_$;
1258
1259
1260
--
1261 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263
1264
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1265
    LANGUAGE sql IMMUTABLE
1266
    AS $_$
1267
SELECT regexp_replace($2, '("?)$', $1||'\1')
1268
$_$;
1269
1270
1271
--
1272 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1273
--
1274
1275
CREATE FUNCTION eval(sql text) RETURNS void
1276
    LANGUAGE plpgsql STRICT
1277
    AS $$
1278
BEGIN
1279 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1280
	EXECUTE sql;
1281 9824 aaronmk
END;
1282
$$;
1283
1284
1285
--
1286 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1287
--
1288
1289
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1290
    LANGUAGE plpgsql
1291
    AS $$
1292
BEGIN
1293 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1294 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1295
END;
1296
$$;
1297
1298
1299
--
1300
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1301
--
1302
1303 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1304
col_type_null (*required*): NULL::col_type
1305
';
1306 12181 aaronmk
1307
1308
--
1309 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1310
--
1311
1312
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1313
    LANGUAGE plpgsql
1314
    AS $$
1315
BEGIN
1316
	PERFORM util.debug_print_sql(sql);
1317
	RETURN QUERY EXECUTE sql;
1318
END;
1319
$$;
1320
1321
1322
--
1323 12458 aaronmk
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1324 10363 aaronmk
--
1325
1326 12458 aaronmk
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1327 10363 aaronmk
    LANGUAGE plpgsql
1328
    AS $$
1329
BEGIN
1330 12458 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1331 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1332
END;
1333
$$;
1334
1335
1336
--
1337 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1338 10128 aaronmk
--
1339
1340 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1341 10128 aaronmk
    LANGUAGE plpgsql
1342
    AS $$
1343
DECLARE
1344
	ret_val ret_type_null%TYPE;
1345
BEGIN
1346 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1347 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1348
	RETURN ret_val;
1349
END;
1350
$$;
1351
1352
1353
--
1354 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1355 10128 aaronmk
--
1356
1357 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1358
ret_type_null: NULL::ret_type
1359
';
1360 10128 aaronmk
1361
1362
--
1363 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1364
--
1365
1366
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1367
    LANGUAGE sql
1368
    AS $_$
1369 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1370 10131 aaronmk
$_$;
1371
1372
1373
--
1374
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1375
--
1376
1377 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1378
ret_type_null: NULL::ret_type
1379
';
1380 10131 aaronmk
1381
1382
--
1383 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385
1386
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1387
    LANGUAGE sql
1388
    AS $_$
1389
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1390
$_$;
1391
1392
1393
--
1394
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1395
--
1396
1397 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1398
sql: can be NULL, which will be passed through
1399
ret_type_null: NULL::ret_type
1400
';
1401 10133 aaronmk
1402
1403
--
1404 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1405 8182 aaronmk
--
1406
1407
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1408 12446 aaronmk
    LANGUAGE sql STABLE
1409 8182 aaronmk
    AS $_$
1410
SELECT col_name
1411
FROM unnest($2) s (col_name)
1412 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1413 8182 aaronmk
$_$;
1414
1415
1416
--
1417 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1418
--
1419
1420
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1421
    LANGUAGE sql
1422
    AS $_$
1423 12459 aaronmk
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1424 11830 aaronmk
$_$;
1425
1426
1427
--
1428 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1429
--
1430
1431
CREATE FUNCTION explain2notice(sql text) RETURNS void
1432 12449 aaronmk
    LANGUAGE sql
1433
    AS $_$
1434
SELECT util.raise_notice(util.explain2notice_msg($1))
1435
$_$;
1436 12448 aaronmk
1437
1438
--
1439
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1440
--
1441
1442
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1443
    LANGUAGE sql
1444
    AS $_$
1445 12464 aaronmk
-- newline before and after to visually separate it from other debug info
1446
SELECT $$
1447
EXPLAIN:
1448
$$||util.explain2str($1)||$$
1449
$$
1450 11833 aaronmk
$_$;
1451
1452
1453
--
1454 12452 aaronmk
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1455
--
1456
1457
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1458
    LANGUAGE sql
1459
    AS $_$
1460
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1461
$_$;
1462
1463
1464
--
1465 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1466
--
1467
1468
CREATE FUNCTION explain2str(sql text) RETURNS text
1469
    LANGUAGE sql
1470
    AS $_$
1471
SELECT util.join_strs(explain, $$
1472
$$) FROM util.explain($1)
1473
$_$;
1474
1475
1476 11835 aaronmk
SET default_tablespace = '';
1477
1478
SET default_with_oids = false;
1479
1480 11832 aaronmk
--
1481 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1482 11831 aaronmk
--
1483
1484 11835 aaronmk
CREATE TABLE explain (
1485
    line text NOT NULL
1486
);
1487
1488
1489
--
1490
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1491
--
1492
1493
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1494 11831 aaronmk
    LANGUAGE sql
1495
    AS $_$
1496 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1497
$$||quote_nullable($1)||$$
1498 11831 aaronmk
)$$)
1499
$_$;
1500
1501
1502
--
1503 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1504
--
1505
1506 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1507
usage:
1508 11836 aaronmk
PERFORM util.explain2table($$
1509
query
1510 12235 aaronmk
$$);
1511
';
1512 11836 aaronmk
1513
1514
--
1515 12450 aaronmk
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1516
--
1517
1518
CREATE FUNCTION first_word(str text) RETURNS text
1519
    LANGUAGE sql IMMUTABLE
1520
    AS $_$
1521 12461 aaronmk
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1522 12450 aaronmk
$_$;
1523
1524
1525
--
1526 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1527
--
1528
1529
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1530 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1531 10323 aaronmk
    AS $_$
1532 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1533
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1534
) END
1535 10323 aaronmk
$_$;
1536
1537
1538
--
1539
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1540
--
1541
1542 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1543
ensures that an array will always have proper non-NULL dimensions
1544
';
1545 10323 aaronmk
1546
1547
--
1548 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1549
--
1550
1551
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1552
    LANGUAGE plpgsql
1553
    AS $_$
1554
DECLARE
1555
	PG_EXCEPTION_DETAIL text;
1556
	recreate_users_cmd text = util.save_drop_views(users);
1557
BEGIN
1558
	PERFORM util.eval(cmd);
1559
	PERFORM util.eval(recreate_users_cmd);
1560
EXCEPTION
1561
WHEN dependent_objects_still_exist THEN
1562
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1563
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1564
	users = array(SELECT * FROM util.regexp_matches_group(
1565
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1566
	IF util.is_empty(users) THEN RAISE; END IF;
1567
	PERFORM util.force_recreate(cmd, users);
1568
END;
1569
$_$;
1570
1571
1572
--
1573
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1574
--
1575
1576 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1577
idempotent
1578 11695 aaronmk
1579 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1580
';
1581 11695 aaronmk
1582
1583
--
1584 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1585
--
1586
1587
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1588
    LANGUAGE plpgsql STRICT
1589
    AS $_$
1590
DECLARE
1591
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1592
$$||query;
1593
BEGIN
1594
	EXECUTE mk_view;
1595
EXCEPTION
1596
WHEN invalid_table_definition THEN
1597 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1598
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1599
	THEN
1600 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1601
		EXECUTE mk_view;
1602
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1603
	END IF;
1604
END;
1605
$_$;
1606
1607
1608
--
1609
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1610
--
1611
1612 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1613
idempotent
1614
';
1615 8321 aaronmk
1616
1617
--
1618 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1619
--
1620
1621
CREATE FUNCTION grants_users() RETURNS SETOF text
1622
    LANGUAGE sql IMMUTABLE
1623
    AS $$
1624
VALUES ('bien_read'), ('public_')
1625
$$;
1626
1627
1628
--
1629 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1630 8085 aaronmk
--
1631
1632
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1633 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1634 8085 aaronmk
    AS $_$
1635
SELECT substring($2 for length($1)) = $1
1636
$_$;
1637
1638
1639
--
1640 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1641
--
1642
1643
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1644
    LANGUAGE sql STABLE
1645
    AS $_$
1646
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1647
$_$;
1648
1649
1650
--
1651 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1652
--
1653
1654
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1655
    LANGUAGE sql IMMUTABLE
1656
    AS $_$
1657 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1658 10307 aaronmk
$_$;
1659
1660
1661
--
1662
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1663
--
1664
1665 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1666
avoids repeating the same value for each key
1667
';
1668 10307 aaronmk
1669
1670
--
1671 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1672
--
1673
1674
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1675
    LANGUAGE sql IMMUTABLE
1676
    AS $_$
1677 12222 aaronmk
SELECT COALESCE($1, $2)
1678 12218 aaronmk
$_$;
1679
1680
1681
--
1682
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1683
--
1684
1685 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1686
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1687
';
1688 12218 aaronmk
1689
1690
--
1691 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1692
--
1693
1694
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1695
    LANGUAGE sql
1696
    AS $_$
1697
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1698
$_$;
1699
1700
1701
--
1702 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1703
--
1704
1705
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1706 12446 aaronmk
    LANGUAGE sql STABLE
1707 10137 aaronmk
    AS $_$
1708
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1709
$_$;
1710
1711
1712
--
1713 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1714
--
1715
1716
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1717
    LANGUAGE sql IMMUTABLE
1718
    AS $_$
1719
SELECT util.array_length($1) = 0
1720
$_$;
1721
1722
1723
--
1724 12457 aaronmk
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1725
--
1726
1727
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1728
    LANGUAGE sql IMMUTABLE
1729
    AS $_$
1730
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1731
$_$;
1732
1733
1734
--
1735 12451 aaronmk
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1736
--
1737
1738
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1739
    LANGUAGE sql IMMUTABLE
1740
    AS $_$
1741
SELECT upper(util.first_word($1)) = ANY(
1742
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1743
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1744
)
1745
$_$;
1746
1747
1748
--
1749 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1750
--
1751
1752
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1753
    LANGUAGE sql IMMUTABLE
1754
    AS $_$
1755
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1756
$_$;
1757
1758
1759
--
1760 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1761
--
1762
1763
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1764
    LANGUAGE sql IMMUTABLE
1765
    AS $_$
1766
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1767
$_$;
1768
1769
1770
--
1771 12480 aaronmk
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1772
--
1773
1774
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1775
    LANGUAGE sql IMMUTABLE
1776
    AS $_$
1777
SELECT upper(util.first_word($1)) = 'SET'
1778
$_$;
1779
1780
1781
--
1782 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1783
--
1784
1785
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1786 12332 aaronmk
    LANGUAGE sql STABLE
1787 12330 aaronmk
    AS $_$
1788
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1789
$_$;
1790
1791
1792
--
1793 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1794
--
1795
1796
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1797 12332 aaronmk
    LANGUAGE sql STABLE
1798 12329 aaronmk
    AS $_$
1799
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1800
$_$;
1801
1802
1803
--
1804 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1805 4009 aaronmk
--
1806
1807 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1808 12444 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1809 4009 aaronmk
    AS $_$
1810 4054 aaronmk
SELECT $1 || $3 || $2
1811 2595 aaronmk
$_$;
1812
1813
1814
--
1815 12444 aaronmk
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1816
--
1817
1818
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1819
must be declared STRICT to use the special handling of STRICT aggregating functions
1820
';
1821
1822
1823
--
1824 12436 aaronmk
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1825
--
1826
1827
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1828
    LANGUAGE sql IMMUTABLE
1829
    AS $_$
1830
SELECT $1 -- compare on the entire value
1831
$_$;
1832
1833
1834
--
1835 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1836 10985 aaronmk
--
1837
1838 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1839 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1840
    AS $_$
1841 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1842 10985 aaronmk
$_$;
1843
1844
1845
--
1846 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1847
--
1848
1849
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1850
    LANGUAGE sql IMMUTABLE
1851
    AS $_$
1852
SELECT ltrim($1, $$
1853
$$)
1854
$_$;
1855
1856
1857
--
1858 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1859
--
1860
1861
CREATE FUNCTION map_filter_insert() RETURNS trigger
1862
    LANGUAGE plpgsql
1863
    AS $$
1864
BEGIN
1865
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1866
	RETURN new;
1867
END;
1868
$$;
1869
1870
1871
--
1872 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1873 8146 aaronmk
--
1874
1875
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1876
    LANGUAGE plpgsql STABLE STRICT
1877
    AS $_$
1878
DECLARE
1879
    value text;
1880
BEGIN
1881
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1882 8149 aaronmk
        INTO value USING key;
1883 8146 aaronmk
    RETURN value;
1884
END;
1885
$_$;
1886
1887
1888
--
1889 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1890 10325 aaronmk
--
1891
1892 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1893 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1894 10325 aaronmk
    AS $_$
1895 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1896 10325 aaronmk
$_$;
1897
1898
1899
--
1900 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1901
--
1902
1903 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1904
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1905 10359 aaronmk
1906
[1] inlining of function calls, which is different from constant folding
1907
[2] _map()''s profiling query
1908
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1909
and map_nulls()''s profiling query
1910
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1911 10375 aaronmk
both take ~920 ms.
1912 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.
1913
';
1914 10359 aaronmk
1915
1916
--
1917 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1918 8150 aaronmk
--
1919
1920
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1921
    LANGUAGE plpgsql STABLE STRICT
1922
    AS $_$
1923
BEGIN
1924
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1925
END;
1926
$_$;
1927
1928
1929
--
1930 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1931
--
1932
1933 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1934 12228 aaronmk
    LANGUAGE sql
1935
    AS $_$
1936 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1937 12321 aaronmk
$$||util.ltrim_nl($2));
1938
-- make sure the created table has the correct estimated row count
1939
SELECT util.analyze_($1);
1940 12470 aaronmk
1941
SELECT util.append_comment($1, '
1942
contents generated from:
1943
'||util.ltrim_nl($2)||';
1944
');
1945 12228 aaronmk
$_$;
1946
1947
1948
--
1949 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1950 12228 aaronmk
--
1951
1952 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1953 12235 aaronmk
idempotent
1954
';
1955 12228 aaronmk
1956
1957
--
1958 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1959
--
1960
1961 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1962 12234 aaronmk
    LANGUAGE sql
1963
    AS $_$
1964
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1965
$_$;
1966
1967
1968
--
1969 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1970 12234 aaronmk
--
1971
1972 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1973 12235 aaronmk
idempotent
1974
';
1975 12234 aaronmk
1976
1977
--
1978 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1979
--
1980
1981
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1982 12446 aaronmk
    LANGUAGE sql
1983 8190 aaronmk
    AS $_$
1984 10135 aaronmk
SELECT util.create_if_not_exists($$
1985
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1986 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1987 10135 aaronmk
||quote_literal($2)||$$;
1988 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1989
constant
1990
';
1991 10135 aaronmk
$$)
1992 8190 aaronmk
$_$;
1993
1994
1995
--
1996
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1997
--
1998
1999 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2000
idempotent
2001
';
2002 8190 aaronmk
2003
2004
--
2005 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2006 8187 aaronmk
--
2007
2008 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2009 8187 aaronmk
    LANGUAGE plpgsql STRICT
2010
    AS $_$
2011
DECLARE
2012
    type regtype = util.typeof(expr, col.table_::text::regtype);
2013
    col_name_sql text = quote_ident(col.name);
2014
BEGIN
2015 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2016
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2017 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2018
$$||expr||$$;
2019
$$);
2020
END;
2021
$_$;
2022
2023
2024
--
2025 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2026 8188 aaronmk
--
2027
2028 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2029
idempotent
2030
';
2031 8188 aaronmk
2032
2033
--
2034 12478 aaronmk
-- Name: mk_diff_query(text, text, boolean, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2035 12475 aaronmk
--
2036
2037 12478 aaronmk
CREATE FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean DEFAULT false, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2038 12475 aaronmk
    LANGUAGE sql IMMUTABLE
2039
    AS $_$
2040
SELECT
2041 12478 aaronmk
$$SELECT
2042
$$||$4||$$
2043 12475 aaronmk
FROM $$||$1||$$ left_
2044
$$||util._if($3, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
2045
$$||util._if($3, ''::text,
2046 12478 aaronmk
$$ON $$||$5||$$
2047 12475 aaronmk
$$)||
2048 12478 aaronmk
$$WHERE $$||$6||$$
2049 12475 aaronmk
ORDER BY left_, right_
2050
$$
2051
$_$;
2052
2053
2054
--
2055 12478 aaronmk
-- Name: FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean, cols text, join_cond text, filter text); Type: COMMENT; Schema: util; Owner: -
2056 12475 aaronmk
--
2057
2058 12478 aaronmk
COMMENT ON FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean, cols text, join_cond text, filter text) IS '
2059 12475 aaronmk
single_row: whether the tables consist of a single row, which should be
2060
	displayed side-by-side
2061
';
2062
2063
2064
--
2065 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2066 8139 aaronmk
--
2067
2068
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2069 12446 aaronmk
    LANGUAGE sql
2070 8139 aaronmk
    AS $_$
2071 8183 aaronmk
SELECT util.create_if_not_exists($$
2072 8141 aaronmk
CREATE TABLE $$||$1||$$
2073 8139 aaronmk
(
2074 8183 aaronmk
    LIKE util.map INCLUDING ALL
2075 10110 aaronmk
);
2076
2077
CREATE TRIGGER map_filter_insert
2078
  BEFORE INSERT
2079
  ON $$||$1||$$
2080
  FOR EACH ROW
2081
  EXECUTE PROCEDURE util.map_filter_insert();
2082 8141 aaronmk
$$)
2083 8139 aaronmk
$_$;
2084
2085
2086
--
2087 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089
2090
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2091
    LANGUAGE sql IMMUTABLE
2092
    AS $_$
2093 12486 aaronmk
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2094 12236 aaronmk
$_$;
2095
2096
2097
--
2098 12486 aaronmk
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2099
--
2100
2101
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2102
auto-appends util to the search_path to enable use of util operators
2103
';
2104
2105
2106
--
2107 12467 aaronmk
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2108
--
2109
2110
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2111
    LANGUAGE sql IMMUTABLE
2112
    AS $_$
2113
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2114
$_$;
2115
2116
2117
--
2118 12466 aaronmk
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2119 12270 aaronmk
--
2120
2121 12466 aaronmk
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2122 12270 aaronmk
    LANGUAGE sql IMMUTABLE
2123
    AS $_$
2124 12432 aaronmk
/* debug_print_return_value() needed because this function is used with EXECUTE
2125
rather than util.eval() (in order to affect the calling function), so the
2126
search_path would not otherwise be printed */
2127 12487 aaronmk
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2128
||$$ search_path TO $$||$1
2129 12270 aaronmk
$_$;
2130
2131
2132
--
2133 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2134
--
2135
2136
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2137 12446 aaronmk
    LANGUAGE sql
2138 10113 aaronmk
    AS $_$
2139 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2140 10113 aaronmk
$_$;
2141
2142
2143
--
2144
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2145
--
2146
2147 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2148
idempotent
2149
';
2150 10113 aaronmk
2151
2152
--
2153 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2154
--
2155
2156
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2157
    LANGUAGE plpgsql STRICT
2158
    AS $_$
2159
DECLARE
2160
	view_qual_name text = util.qual_name(view_);
2161
BEGIN
2162
	EXECUTE $$
2163
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2164
  RETURNS SETOF $$||view_||$$ AS
2165
$BODY1$
2166
SELECT * FROM $$||view_qual_name||$$
2167
ORDER BY sort_col
2168
LIMIT $1 OFFSET $2
2169
$BODY1$
2170
  LANGUAGE sql STABLE
2171
  COST 100
2172
  ROWS 1000
2173
$$;
2174
2175
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2176
END;
2177
$_$;
2178
2179
2180
--
2181 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2182
--
2183
2184
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2185
    LANGUAGE plpgsql STRICT
2186
    AS $_$
2187 10990 aaronmk
DECLARE
2188
	view_qual_name text = util.qual_name(view_);
2189
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2190 8325 aaronmk
BEGIN
2191
	EXECUTE $$
2192 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2193
  RETURNS integer AS
2194
$BODY1$
2195
SELECT $$||quote_ident(row_num_col)||$$
2196
FROM $$||view_qual_name||$$
2197
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2198
LIMIT 1
2199
$BODY1$
2200
  LANGUAGE sql STABLE
2201
  COST 100;
2202
$$;
2203
2204
	EXECUTE $$
2205 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2206
  RETURNS SETOF $$||view_||$$ AS
2207
$BODY1$
2208 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
2209
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2210
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2211
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2212 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
2213 8325 aaronmk
$BODY1$
2214
  LANGUAGE sql STABLE
2215
  COST 100
2216
  ROWS 1000
2217
$$;
2218 11010 aaronmk
2219
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2220
END;
2221
$_$;
2222
2223
2224
--
2225
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2226
--
2227
2228
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2229
    LANGUAGE plpgsql STRICT
2230
    AS $_$
2231
DECLARE
2232
	view_qual_name text = util.qual_name(view_);
2233
BEGIN
2234 8326 aaronmk
	EXECUTE $$
2235
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2236
  RETURNS SETOF $$||view_||$$
2237
  SET enable_sort TO 'off'
2238
  AS
2239
$BODY1$
2240 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2241 8326 aaronmk
$BODY1$
2242
  LANGUAGE sql STABLE
2243
  COST 100
2244
  ROWS 1000
2245
;
2246
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2247
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2248
If you want to run EXPLAIN and get expanded output, use the regular subset
2249
function instead. (When a config param is set on a function, EXPLAIN produces
2250
just a function scan.)
2251
';
2252
$$;
2253 8325 aaronmk
END;
2254
$_$;
2255
2256
2257
--
2258 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2259
--
2260
2261 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2262
creates subset function which turns off enable_sort
2263
';
2264 11010 aaronmk
2265
2266
--
2267 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2268
--
2269
2270
CREATE FUNCTION name(table_ regclass) RETURNS text
2271
    LANGUAGE sql STABLE
2272
    AS $_$
2273
SELECT relname::text FROM pg_class WHERE oid = $1
2274
$_$;
2275
2276
2277
--
2278 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2279 8083 aaronmk
--
2280
2281
CREATE FUNCTION name(type regtype) RETURNS text
2282 12446 aaronmk
    LANGUAGE sql STABLE
2283 8083 aaronmk
    AS $_$
2284
SELECT typname::text FROM pg_type WHERE oid = $1
2285
$_$;
2286
2287
2288
--
2289 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2290 12355 aaronmk
--
2291
2292 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2293 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2294
    AS $_$
2295 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2296 12355 aaronmk
$_$;
2297
2298
2299
--
2300 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2301
--
2302
2303
CREATE FUNCTION namedatalen() RETURNS integer
2304
    LANGUAGE sql IMMUTABLE
2305
    AS $$
2306
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2307
$$;
2308
2309
2310
--
2311 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2312
--
2313
2314
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2315
    LANGUAGE sql IMMUTABLE
2316
    AS $_$
2317 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2318 9958 aaronmk
$_$;
2319
2320
2321
--
2322 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2323
--
2324
2325
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2326 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2327 9956 aaronmk
    AS $_$
2328
SELECT $1 IS NOT NULL
2329
$_$;
2330
2331
2332
--
2333 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2334
--
2335
2336
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2337
    LANGUAGE sql IMMUTABLE
2338
    AS $_$
2339
SELECT util.hstore($1, NULL) || '*=>*'
2340
$_$;
2341
2342
2343
--
2344
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2345
--
2346
2347 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2348
for use with _map()
2349
';
2350 10373 aaronmk
2351
2352
--
2353 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2354 10984 aaronmk
--
2355
2356 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2357 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2358
    AS $_$
2359 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2360 10984 aaronmk
$_$;
2361
2362
2363
--
2364 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2365
--
2366
2367
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2368
    LANGUAGE sql IMMUTABLE
2369
    AS $_$
2370
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2371
$_$;
2372
2373
2374
--
2375 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2376
--
2377
2378
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2379 12446 aaronmk
    LANGUAGE sql STABLE
2380 12267 aaronmk
    SET search_path TO pg_temp
2381 10988 aaronmk
    AS $_$
2382 12267 aaronmk
SELECT $1::text
2383 10988 aaronmk
$_$;
2384
2385
2386
--
2387 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2388
--
2389
2390
CREATE FUNCTION qual_name(type regtype) RETURNS text
2391 12446 aaronmk
    LANGUAGE sql STABLE
2392 12267 aaronmk
    SET search_path TO pg_temp
2393
    AS $_$
2394
SELECT $1::text
2395
$_$;
2396
2397
2398
--
2399
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2400
--
2401
2402
COMMENT ON FUNCTION qual_name(type regtype) IS '
2403
a type''s schema-qualified name
2404
';
2405
2406
2407
--
2408 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2409
--
2410
2411
CREATE FUNCTION qual_name(type unknown) RETURNS text
2412 12446 aaronmk
    LANGUAGE sql STABLE
2413 12268 aaronmk
    AS $_$
2414
SELECT util.qual_name($1::text::regtype)
2415
$_$;
2416
2417
2418
--
2419 12376 aaronmk
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2420
--
2421
2422
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2423
    LANGUAGE sql IMMUTABLE
2424
    AS $_$
2425
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2426
$_$;
2427
2428
2429
--
2430
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2431
--
2432
2433
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2434
    LANGUAGE sql IMMUTABLE
2435
    AS $_$
2436
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2437
$_$;
2438
2439
2440
--
2441 12371 aaronmk
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2442
--
2443
2444
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2445
    LANGUAGE sql IMMUTABLE
2446
    AS $_$
2447 12437 aaronmk
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2448 12371 aaronmk
$_$;
2449
2450
2451
--
2452 12311 aaronmk
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2453
--
2454
2455
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2456 12441 aaronmk
    LANGUAGE sql IMMUTABLE
2457 12311 aaronmk
    AS $_$
2458
SELECT util.raise_notice('ERROR:  '||$1)
2459
$_$;
2460
2461
2462
--
2463 12249 aaronmk
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2464
--
2465
2466
CREATE FUNCTION raise_notice(msg text) RETURNS void
2467
    LANGUAGE plpgsql IMMUTABLE STRICT
2468
    AS $$
2469
BEGIN
2470
	RAISE NOTICE '%', msg;
2471
END;
2472
$$;
2473
2474
2475
--
2476 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2477
--
2478
2479
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2480
    LANGUAGE plpgsql IMMUTABLE STRICT
2481
    AS $$
2482
BEGIN
2483
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2484
END;
2485
$$;
2486
2487
2488
--
2489 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2490
--
2491
2492
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2493
    LANGUAGE sql IMMUTABLE
2494
    AS $_$
2495
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2496
$_$;
2497
2498
2499
--
2500 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2501
--
2502
2503
CREATE FUNCTION regexp_quote(str text) RETURNS text
2504
    LANGUAGE sql IMMUTABLE
2505
    AS $_$
2506
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2507
$_$;
2508
2509
2510
--
2511 12375 aaronmk
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2512
--
2513
2514
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2515
    LANGUAGE sql IMMUTABLE
2516
    AS $_$
2517
SELECT (CASE WHEN right($1, 1) = ')'
2518 12377 aaronmk
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2519 12375 aaronmk
$_$;
2520
2521
2522
--
2523 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2524
--
2525
2526
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2527
    LANGUAGE sql STABLE
2528
    AS $_$
2529
SELECT util.relation_type(util.relation_type_char($1))
2530
$_$;
2531
2532
2533
--
2534 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2535 12339 aaronmk
--
2536
2537 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2538 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2539
    AS $_$
2540
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2541
$_$;
2542
2543
2544
--
2545 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2546
--
2547
2548
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2549
    LANGUAGE sql STABLE
2550
    AS $_$
2551
SELECT relkind FROM pg_class WHERE oid = $1
2552
$_$;
2553
2554
2555
--
2556 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2557
--
2558
2559
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2560
    LANGUAGE sql
2561
    AS $_$
2562
/* can't have in_table/out_table inherit from *each other*, because inheritance
2563
also causes the rows of the parent table to be included in the child table.
2564
instead, they need to inherit from a common, empty table. */
2565 12382 aaronmk
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2566
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2567 12293 aaronmk
SELECT util.inherit($2, $4);
2568
SELECT util.inherit($3, $4);
2569
2570
SELECT util.rematerialize_query($1, $$
2571
SELECT * FROM util.diff(
2572 12419 aaronmk
  $$||util.quote_typed($2)||$$
2573
, $$||util.quote_typed($3)||$$
2574 12293 aaronmk
, NULL::$$||$4||$$)
2575
$$);
2576 12303 aaronmk
2577
/* the table unfortunately cannot be *materialized* in human-readable form,
2578
because this would create column name collisions between the two sides */
2579 12370 aaronmk
SELECT util.append_comment($1, '
2580 12303 aaronmk
to view this table in human-readable form (with each side''s tuple column
2581
expanded to its component fields):
2582
SELECT (left_).*, (right_).* FROM '||$1||';
2583
');
2584 12293 aaronmk
$_$;
2585
2586
2587
--
2588
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2589
--
2590
2591
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2592
type_table (*required*): table to create as the shared base type
2593
';
2594
2595
2596
--
2597 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2598
--
2599
2600
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2601
    LANGUAGE sql
2602
    AS $_$
2603
SELECT util.drop_table($1);
2604
SELECT util.materialize_query($1, $2);
2605
$_$;
2606
2607
2608
--
2609
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2610
--
2611
2612
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2613
idempotent, but repeats action each time
2614
';
2615
2616
2617
--
2618 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2619
--
2620
2621 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2622 12247 aaronmk
    LANGUAGE sql
2623
    AS $_$
2624
SELECT util.drop_table($1);
2625
SELECT util.materialize_view($1, $2);
2626
$_$;
2627
2628
2629
--
2630 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2631 12247 aaronmk
--
2632
2633 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2634 12247 aaronmk
idempotent, but repeats action each time
2635
';
2636
2637
2638
--
2639 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2640 8137 aaronmk
--
2641
2642 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2643 12446 aaronmk
    LANGUAGE sql
2644 8137 aaronmk
    AS $_$
2645 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2646 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2647 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
2648
SELECT NULL::void; -- don't fold away functions called in previous query
2649 8137 aaronmk
$_$;
2650
2651
2652
--
2653 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2654 8137 aaronmk
--
2655
2656 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2657
idempotent
2658
';
2659 8137 aaronmk
2660
2661
--
2662 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2663
--
2664
2665
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2666
    LANGUAGE sql
2667
    AS $_$
2668 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2669
included in the debug SQL */
2670
SELECT util.rename_relation(util.qual_name($1), $2)
2671 12349 aaronmk
$_$;
2672
2673
2674
--
2675
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2676
--
2677
2678 12364 aaronmk
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2679 12349 aaronmk
    LANGUAGE sql
2680
    AS $_$
2681
/* 'ALTER TABLE can be used with views too'
2682
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2683 12363 aaronmk
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2684
||quote_ident($2))
2685 12349 aaronmk
$_$;
2686
2687
2688
--
2689 12364 aaronmk
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2690 12349 aaronmk
--
2691
2692 12364 aaronmk
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2693 12349 aaronmk
idempotent
2694
';
2695
2696
2697
--
2698 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2699 12350 aaronmk
--
2700
2701 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2702 12350 aaronmk
    LANGUAGE sql IMMUTABLE
2703
    AS $_$
2704 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2705 12350 aaronmk
$_$;
2706
2707
2708
--
2709 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2710
--
2711
2712
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2713
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
2714
';
2715
2716
2717
--
2718 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2719
--
2720
2721
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2722 12446 aaronmk
    LANGUAGE sql
2723 10297 aaronmk
    AS $_$
2724 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2725
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2726 10297 aaronmk
SELECT util.set_col_names($1, $2);
2727
$_$;
2728
2729
2730
--
2731
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2732
--
2733
2734 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2735
idempotent.
2736
alters the names table, so it will need to be repopulated after running this function.
2737
';
2738 10297 aaronmk
2739
2740
--
2741 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2742 8143 aaronmk
--
2743
2744
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2745 12446 aaronmk
    LANGUAGE sql
2746 8143 aaronmk
    AS $_$
2747 10152 aaronmk
SELECT util.drop_table($1);
2748 8183 aaronmk
SELECT util.mk_map_table($1);
2749 8143 aaronmk
$_$;
2750
2751
2752
--
2753 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2754
--
2755
2756
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2757
    LANGUAGE sql IMMUTABLE
2758
    AS $_$
2759
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2760
$_$;
2761
2762
2763
--
2764 12473 aaronmk
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2765
--
2766
2767
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2768
    LANGUAGE sql IMMUTABLE
2769
    AS $_$
2770 12481 aaronmk
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
2771
ELSE util.mk_set_search_path(for_printing := true)||$$;
2772
$$ END)||$1
2773 12473 aaronmk
$_$;
2774
2775
2776
--
2777 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2778
--
2779
2780
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2781
    LANGUAGE plpgsql STRICT
2782
    AS $_$
2783
DECLARE
2784
	result text = NULL;
2785
BEGIN
2786
	BEGIN
2787
		result = util.show_create_view(view_);
2788
		PERFORM util.eval($$DROP VIEW $$||view_);
2789
	EXCEPTION
2790
		WHEN undefined_table THEN NULL;
2791
	END;
2792
	RETURN result;
2793
END;
2794
$_$;
2795
2796
2797
--
2798 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2799
--
2800
2801
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2802
    LANGUAGE sql
2803
    AS $_$
2804 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2805 11660 aaronmk
$_$;
2806
2807
2808
--
2809 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2810
--
2811
2812
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2813
    LANGUAGE sql STABLE
2814
    AS $_$
2815
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2816
$_$;
2817
2818
2819
--
2820 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2821
--
2822
2823
CREATE FUNCTION schema(table_ regclass) RETURNS text
2824
    LANGUAGE sql STABLE
2825
    AS $_$
2826 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2827 12242 aaronmk
$_$;
2828
2829
2830
--
2831 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2832
--
2833
2834
CREATE FUNCTION schema(type regtype) RETURNS text
2835
    LANGUAGE sql STABLE
2836
    AS $_$
2837 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2838 10794 aaronmk
$_$;
2839
2840
2841
--
2842
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2843
--
2844
2845
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2846
    LANGUAGE sql STABLE
2847
    AS $_$
2848
SELECT util.schema(pg_typeof($1))
2849
$_$;
2850
2851
2852
--
2853 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2854
--
2855
2856
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2857
    LANGUAGE sql STABLE
2858
    AS $_$
2859
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2860
$_$;
2861
2862
2863
--
2864 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2865
--
2866
2867 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2868
a schema bundle is a group of schemas with a common prefix
2869
';
2870 12135 aaronmk
2871
2872
--
2873
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2874
--
2875
2876
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2877
    LANGUAGE sql
2878
    AS $_$
2879
SELECT util.schema_rename(old_schema,
2880
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2881
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2882
SELECT NULL::void; -- don't fold away functions called in previous query
2883
$_$;
2884
2885
2886
--
2887
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2888
--
2889
2890
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2891
    LANGUAGE plpgsql
2892
    AS $$
2893
BEGIN
2894
	-- don't schema_bundle_rm() the schema_bundle to keep!
2895
	IF replace = with_ THEN RETURN; END IF;
2896
2897
	PERFORM util.schema_bundle_rm(replace);
2898
	PERFORM util.schema_bundle_rename(with_, replace);
2899
END;
2900
$$;
2901
2902
2903
--
2904
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2905
--
2906
2907
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2908
    LANGUAGE sql
2909
    AS $_$
2910
SELECT util.schema_rm(schema)
2911
FROM util.schema_bundle_get_schemas($1) f (schema);
2912
SELECT NULL::void; -- don't fold away functions called in previous query
2913
$_$;
2914
2915
2916
--
2917 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2918 10795 aaronmk
--
2919
2920 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2921 10795 aaronmk
    LANGUAGE sql STABLE
2922
    AS $_$
2923
SELECT quote_ident(util.schema($1))
2924
$_$;
2925
2926
2927
--
2928 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2929
--
2930
2931
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2932 12334 aaronmk
    LANGUAGE sql IMMUTABLE
2933 12324 aaronmk
    AS $_$
2934
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2935
$_$;
2936
2937
2938
--
2939 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2940
--
2941
2942
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2943
    LANGUAGE sql STABLE
2944
    AS $_$
2945
SELECT oid FROM pg_namespace WHERE nspname = $1
2946
$_$;
2947
2948
2949
--
2950 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2951
--
2952
2953
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2954
    LANGUAGE sql
2955
    AS $_$
2956
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2957
$_$;
2958
2959
2960
--
2961 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2962
--
2963
2964
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2965
    LANGUAGE plpgsql
2966
    AS $$
2967
BEGIN
2968
	-- don't schema_rm() the schema to keep!
2969
	IF replace = with_ THEN RETURN; END IF;
2970
2971
	PERFORM util.schema_rm(replace);
2972
	PERFORM util.schema_rename(with_, replace);
2973
END;
2974
$$;
2975
2976
2977
--
2978 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2979
--
2980
2981
CREATE FUNCTION schema_rm(schema text) RETURNS void
2982
    LANGUAGE sql
2983
    AS $_$
2984
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2985
$_$;
2986
2987
2988
--
2989 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2990
--
2991
2992
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2993 12446 aaronmk
    LANGUAGE sql
2994 9825 aaronmk
    AS $_$
2995
SELECT util.eval(
2996
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2997
$_$;
2998
2999
3000
--
3001 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3002 8153 aaronmk
--
3003
3004
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3005
    LANGUAGE plpgsql STRICT
3006
    AS $_$
3007
DECLARE
3008 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
3009
    new text[] = ARRAY(SELECT util.map_values(names));
3010 8153 aaronmk
BEGIN
3011
    old = old[1:array_length(new, 1)]; -- truncate to same length
3012 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3013
||$$ TO $$||quote_ident(value))
3014 10149 aaronmk
    FROM each(hstore(old, new))
3015
    WHERE value != key -- not same name
3016
    ;
3017 8153 aaronmk
END;
3018
$_$;
3019
3020
3021
--
3022 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3023 8153 aaronmk
--
3024
3025 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3026
idempotent
3027
';
3028 8153 aaronmk
3029
3030
--
3031 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3032
--
3033
3034
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3035
    LANGUAGE plpgsql STRICT
3036
    AS $_$
3037
DECLARE
3038
	row_ util.map;
3039
BEGIN
3040 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
3041
	BEGIN
3042
		PERFORM util.set_col_names(table_, names);
3043
	EXCEPTION
3044
		WHEN array_subscript_error THEN -- selective suppress
3045
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3046
				-- metadata cols not yet added
3047
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
3048
			END IF;
3049
	END;
3050
3051 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3052 10145 aaronmk
	LOOP
3053 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
3054
			substring(row_."from" from 2));
3055 10145 aaronmk
	END LOOP;
3056
3057
	PERFORM util.set_col_names(table_, names);
3058
END;
3059
$_$;
3060
3061
3062
--
3063
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3064
--
3065
3066 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3067
idempotent.
3068
the metadata mappings must be *last* in the names table.
3069
';
3070 10145 aaronmk
3071
3072
--
3073 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3074 8107 aaronmk
--
3075
3076
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3077
    LANGUAGE plpgsql STRICT
3078
    AS $_$
3079
DECLARE
3080
    sql text = $$ALTER TABLE $$||table_||$$
3081
$$||NULLIF(array_to_string(ARRAY(
3082
    SELECT
3083
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3084
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3085
    FROM
3086
    (
3087
        SELECT
3088
          quote_ident(col_name) AS col_name_sql
3089 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
3090 8107 aaronmk
        , type AS target_type
3091
        FROM unnest(col_casts)
3092
    ) s
3093
    WHERE curr_type != target_type
3094
), '
3095
, '), '');
3096
BEGIN
3097 12251 aaronmk
    PERFORM util.debug_print_sql(sql);
3098 8107 aaronmk
    EXECUTE COALESCE(sql, '');
3099
END;
3100
$_$;
3101
3102
3103
--
3104 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3105 8107 aaronmk
--
3106
3107 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3108
idempotent
3109
';
3110 8107 aaronmk
3111
3112
--
3113 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3114
--
3115
3116
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3117 12446 aaronmk
    LANGUAGE sql
3118 12302 aaronmk
    AS $_$
3119
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3120
$_$;
3121
3122
3123
--
3124 12482 aaronmk
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3125
--
3126
3127
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3128
    LANGUAGE sql
3129
    AS $_$
3130
SELECT util.eval(util.mk_set_search_path($1, $2))
3131
$_$;
3132
3133
3134
--
3135 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3136
--
3137
3138
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3139
    LANGUAGE sql STABLE
3140
    AS $_$
3141 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3142
$$||util.show_grants_for($1)
3143 11651 aaronmk
$_$;
3144
3145
3146
--
3147 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3148
--
3149
3150
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3151
    LANGUAGE sql STABLE
3152
    AS $_$
3153 12269 aaronmk
SELECT string_agg(cmd, '')
3154 11655 aaronmk
FROM
3155
(
3156
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3157
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3158
$$ ELSE '' END) AS cmd
3159
	FROM util.grants_users() f (user_)
3160
) s
3161
$_$;
3162
3163
3164
--
3165 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3166
--
3167
3168
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3169
    LANGUAGE sql STABLE
3170
    AS $_$
3171
SELECT oid FROM pg_class
3172
WHERE relkind = ANY($3) AND relname ~ $1
3173
AND util.schema_matches(util.schema(relnamespace), $2)
3174
ORDER BY relname
3175
$_$;
3176
3177
3178
--
3179 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3180
--
3181
3182 12385 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3183 12305 aaronmk
    LANGUAGE sql STABLE
3184
    AS $_$
3185 12385 aaronmk
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3186 12305 aaronmk
$_$;
3187
3188
3189
--
3190 12384 aaronmk
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3191
--
3192
3193
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3194
    LANGUAGE sql IMMUTABLE
3195
    AS $_$
3196
SELECT '^'||util.regexp_quote($1)||'$'
3197
$_$;
3198
3199
3200
--
3201 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3202 8144 aaronmk
--
3203
3204
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3205 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
3206 8144 aaronmk
    AS $_$
3207
DECLARE
3208
    hstore hstore;
3209
BEGIN
3210
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3211
        table_||$$))$$ INTO STRICT hstore;
3212
    RETURN hstore;
3213
END;
3214
$_$;
3215
3216
3217
--
3218 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3219
--
3220
3221
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3222 12446 aaronmk
    LANGUAGE sql STABLE
3223 10184 aaronmk
    AS $_$
3224
SELECT COUNT(*) > 0 FROM pg_constraint
3225
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3226
$_$;
3227
3228
3229
--
3230
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3231
--
3232
3233 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3234
gets whether a status flag is set by the presence of a table constraint
3235
';
3236 10184 aaronmk
3237
3238
--
3239 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3240
--
3241
3242
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3243 12446 aaronmk
    LANGUAGE sql
3244 10182 aaronmk
    AS $_$
3245
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3246
||quote_ident($2)||$$ CHECK (true)$$)
3247
$_$;
3248
3249
3250
--
3251
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3252
--
3253
3254 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3255
stores a status flag by the presence of a table constraint.
3256
idempotent.
3257
';
3258 10182 aaronmk
3259
3260
--
3261 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3262
--
3263
3264
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3265 12446 aaronmk
    LANGUAGE sql STABLE
3266 10185 aaronmk
    AS $_$
3267
SELECT util.table_flag__get($1, 'nulls_mapped')
3268
$_$;
3269
3270
3271
--
3272
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3273
--
3274
3275 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3276
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3277
';
3278 10185 aaronmk
3279
3280
--
3281 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3282
--
3283
3284
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3285 12446 aaronmk
    LANGUAGE sql
3286 10183 aaronmk
    AS $_$
3287
SELECT util.table_flag__set($1, 'nulls_mapped')
3288
$_$;
3289
3290
3291
--
3292
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3293
--
3294
3295 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3296
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3297
idempotent.
3298
';
3299 10183 aaronmk
3300
3301
--
3302 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3303 8088 aaronmk
--
3304
3305
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3306
    LANGUAGE plpgsql STRICT
3307
    AS $_$
3308
DECLARE
3309
    row record;
3310
BEGIN
3311 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3312 8088 aaronmk
    LOOP
3313
        IF row.global_name != row.name THEN
3314
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3315
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3316
        END IF;
3317
    END LOOP;
3318
END;
3319
$_$;
3320
3321
3322
--
3323 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3324 8088 aaronmk
--
3325
3326 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3327
idempotent
3328
';
3329 8088 aaronmk
3330
3331
--
3332 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3333
--
3334
3335
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3336 12446 aaronmk
    LANGUAGE sql
3337 10365 aaronmk
    AS $_$
3338 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3339 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3340
$_$;
3341
3342
3343
--
3344
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3345
--
3346
3347 12235 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3348
trims table_ to include only columns in the original data.
3349
idempotent.
3350
';
3351 10365 aaronmk
3352
3353
--
3354 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3355 8142 aaronmk
--
3356
3357
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3358
    LANGUAGE plpgsql STRICT
3359
    AS $_$
3360
BEGIN
3361
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3362
END;
3363
$_$;
3364
3365
3366
--
3367 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3368 8142 aaronmk
--
3369
3370 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3371
idempotent
3372
';
3373 8142 aaronmk
3374
3375
--
3376 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3377
--
3378
3379
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3380
    LANGUAGE sql IMMUTABLE
3381
    AS $_$
3382 12361 aaronmk
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3383 12362 aaronmk
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3384 12357 aaronmk
$_$;
3385
3386
3387
--
3388 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3389
--
3390
3391
CREATE FUNCTION try_create(sql text) RETURNS void
3392
    LANGUAGE plpgsql STRICT
3393
    AS $$
3394
BEGIN
3395 10146 aaronmk
    PERFORM util.eval(sql);
3396 8199 aaronmk
EXCEPTION
3397 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3398 8199 aaronmk
    WHEN undefined_column THEN NULL;
3399
    WHEN duplicate_column THEN NULL;
3400
END;
3401
$$;
3402
3403
3404
--
3405
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3406
--
3407
3408 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
3409
idempotent
3410
';
3411 8199 aaronmk
3412
3413
--
3414 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3415
--
3416
3417
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3418 12446 aaronmk
    LANGUAGE sql
3419 8209 aaronmk
    AS $_$
3420
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3421
$_$;
3422
3423
3424
--
3425
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3426
--
3427
3428 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3429
idempotent
3430
';
3431 8209 aaronmk
3432
3433
--
3434 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3435
--
3436
3437
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3438
    LANGUAGE sql IMMUTABLE
3439
    AS $_$
3440
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3441
$_$;
3442
3443
3444
--
3445 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3446
--
3447
3448 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3449
a type''s NOT NULL qualifier
3450
';
3451 10161 aaronmk
3452
3453
--
3454 12438 aaronmk
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3455
--
3456
3457
CREATE FUNCTION typeof(value anyelement) RETURNS text
3458
    LANGUAGE sql IMMUTABLE
3459
    AS $_$
3460
SELECT util.qual_name(pg_typeof($1))
3461
$_$;
3462
3463
3464
--
3465 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3466
--
3467
3468 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3469
    LANGUAGE plpgsql STABLE
3470 8185 aaronmk
    AS $_$
3471
DECLARE
3472
    type regtype;
3473
BEGIN
3474 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3475
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3476 8185 aaronmk
    RETURN type;
3477
END;
3478
$_$;
3479
3480
3481
--
3482 12490 aaronmk
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3483 12483 aaronmk
--
3484
3485 12490 aaronmk
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3486 12483 aaronmk
    LANGUAGE sql
3487
    AS $_$
3488 12488 aaronmk
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3489 12483 aaronmk
$_$;
3490
3491
3492
--
3493 12490 aaronmk
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3494 12488 aaronmk
--
3495
3496 12490 aaronmk
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3497 12488 aaronmk
auto-appends util to the search_path to enable use of util operators
3498
';
3499
3500
3501
--
3502 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3503
--
3504
3505
CREATE AGGREGATE all_same(anyelement) (
3506
    SFUNC = all_same_transform,
3507
    STYPE = anyarray,
3508
    FINALFUNC = all_same_final
3509
);
3510
3511
3512
--
3513
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3514
--
3515
3516 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
3517
includes NULLs in comparison
3518
';
3519 9959 aaronmk
3520
3521
--
3522 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3523 2595 aaronmk
--
3524
3525
CREATE AGGREGATE join_strs(text, text) (
3526 4052 aaronmk
    SFUNC = join_strs_transform,
3527 4010 aaronmk
    STYPE = text
3528 2595 aaronmk
);
3529
3530
3531 8147 aaronmk
--
3532 12423 aaronmk
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3533
--
3534
3535
CREATE OPERATOR %== (
3536
    PROCEDURE = "%==",
3537
    LEFTARG = anyelement,
3538
    RIGHTARG = anyelement
3539
);
3540
3541
3542
--
3543
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3544
--
3545
3546
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3547
returns whether the map-keys of the compared values are the same
3548
(mnemonic: % is the Perl symbol for a hash map)
3549
3550
should be overridden for types that store both keys and values
3551
3552
used in a FULL JOIN to select which columns to join on
3553
';
3554
3555
3556
--
3557 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3558 8147 aaronmk
--
3559
3560
CREATE OPERATOR -> (
3561
    PROCEDURE = map_get,
3562
    LEFTARG = regclass,
3563
    RIGHTARG = text
3564
);
3565
3566
3567 10308 aaronmk
--
3568
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3569
--
3570
3571
CREATE OPERATOR => (
3572
    PROCEDURE = hstore,
3573 10357 aaronmk
    LEFTARG = text[],
3574 10608 aaronmk
    RIGHTARG = text
3575 10308 aaronmk
);
3576
3577
3578
--
3579 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3580 10308 aaronmk
--
3581
3582 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
3583
usage: array[''key1'', ...]::text[] => ''value''
3584
';
3585 10308 aaronmk
3586
3587 10391 aaronmk
--
3588 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3589
--
3590
3591
CREATE OPERATOR ?*>= (
3592
    PROCEDURE = is_populated_more_often_than,
3593
    LEFTARG = anyelement,
3594
    RIGHTARG = anyelement
3595
);
3596
3597
3598
--
3599 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3600
--
3601
3602
CREATE OPERATOR ?>= (
3603
    PROCEDURE = is_more_complete_than,
3604
    LEFTARG = anyelement,
3605
    RIGHTARG = anyelement
3606
);
3607
3608
3609 11005 aaronmk
--
3610
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3611
--
3612
3613
CREATE OPERATOR ||% (
3614
    PROCEDURE = concat_esc,
3615
    LEFTARG = text,
3616
    RIGHTARG = text
3617
);
3618
3619
3620
--
3621
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3622
--
3623
3624 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
3625
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3626
';
3627 11005 aaronmk
3628
3629 2107 aaronmk
--
3630 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
3631 8140 aaronmk
--
3632
3633
CREATE TABLE map (
3634
    "from" text NOT NULL,
3635 8158 aaronmk
    "to" text,
3636
    filter text,
3637
    notes text
3638 8140 aaronmk
);
3639
3640
3641
--
3642 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3643
--
3644
3645
3646
3647
--
3648 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3649 8140 aaronmk
--
3650
3651
3652
3653
--
3654 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3655 8140 aaronmk
--
3656
3657
ALTER TABLE ONLY map
3658 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3659 8140 aaronmk
3660
3661
--
3662 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3663
--
3664
3665
ALTER TABLE ONLY map
3666
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3667
3668
3669
--
3670 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3671
--
3672
3673
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3674
3675
3676
--
3677 2136 aaronmk
-- PostgreSQL database dump complete
3678
--