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