Project

General

Profile

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