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