Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET lock_timeout = 0;
7
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11

    
12
--
13
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
CREATE SCHEMA util;
17

    
18

    
19
--
20
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
21
--
22

    
23
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

    
26
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

    
29

    
30
SET search_path = util, pg_catalog;
31

    
32
--
33
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34
--
35

    
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40

    
41

    
42
--
43
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44
--
45

    
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50

    
51

    
52
--
53
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54
--
55

    
56
CREATE TYPE compass_dir AS ENUM (
57
    'N',
58
    'E',
59
    'S',
60
    'W'
61
);
62

    
63

    
64
--
65
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66
--
67

    
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72

    
73

    
74
--
75
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

    
78
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
79
    LANGUAGE sql IMMUTABLE
80
    AS $_$
81
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
82
$_$;
83

    
84

    
85
--
86
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
87
--
88

    
89
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
90
    LANGUAGE sql IMMUTABLE
91
    AS $_$
92
SELECT bool_and(value)
93
FROM
94
(VALUES
95
      ($1)
96
    , ($2)
97
    , ($3)
98
    , ($4)
99
    , ($5)
100
)
101
AS v (value)
102
$_$;
103

    
104

    
105
--
106
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
107
--
108

    
109
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
110
_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.
111
';
112

    
113

    
114
--
115
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
116
--
117

    
118
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
119
    LANGUAGE sql IMMUTABLE
120
    AS $_$
121
SELECT avg(value)
122
FROM
123
(VALUES
124
      ($1)
125
    , ($2)
126
    , ($3)
127
    , ($4)
128
    , ($5)
129
)
130
AS v (value)
131
$_$;
132

    
133

    
134
--
135
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
136
--
137

    
138
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
139
    LANGUAGE sql IMMUTABLE STRICT
140
    AS $_$
141
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)
142
FROM 
143
(
144
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
145
    UNION ALL
146
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
147
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
148
)
149
matches (g)
150
$_$;
151

    
152

    
153
--
154
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
155
--
156

    
157
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
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
161
FROM
162
(VALUES
163
      ($1)
164
    , ($2/60)
165
    , ($3/60/60)
166
)
167
AS v (value)
168
$_$;
169

    
170

    
171
--
172
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
173
--
174

    
175
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
176
    LANGUAGE sql IMMUTABLE
177
    AS $_$
178
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
179
$_$;
180

    
181

    
182
--
183
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
184
--
185

    
186
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
187
    LANGUAGE sql IMMUTABLE
188
    AS $_$
189
SELECT $1 = $2
190
$_$;
191

    
192

    
193
--
194
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
195
--
196

    
197
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
198
    LANGUAGE sql IMMUTABLE
199
    AS $_$
200
-- Fix dates after threshold date
201
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
202
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
203
$_$;
204

    
205

    
206
--
207
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
208
--
209

    
210
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
211
    LANGUAGE sql IMMUTABLE
212
    AS $_$
213
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
214
$_$;
215

    
216

    
217
--
218
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
219
--
220

    
221
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
222
    LANGUAGE sql IMMUTABLE
223
    AS $_$
224
SELECT util._if($1 != '', $2, $3)
225
$_$;
226

    
227

    
228
--
229
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
230
--
231

    
232
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
233
    LANGUAGE sql IMMUTABLE
234
    AS $_$
235
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
236
$_$;
237

    
238

    
239
--
240
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
241
--
242

    
243
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
244
    LANGUAGE sql IMMUTABLE
245
    AS $_$
246
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
247
$_$;
248

    
249

    
250
--
251
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
252
--
253

    
254
CREATE FUNCTION _label(label text, value text) RETURNS text
255
    LANGUAGE sql IMMUTABLE
256
    AS $_$
257
SELECT coalesce($1 || ': ', '') || $2
258
$_$;
259

    
260

    
261
--
262
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
263
--
264

    
265
CREATE FUNCTION _lowercase(value text) RETURNS text
266
    LANGUAGE sql IMMUTABLE
267
    AS $_$
268
SELECT lower($1)
269
$_$;
270

    
271

    
272
--
273
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
274
--
275

    
276
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
277
    LANGUAGE plpgsql IMMUTABLE STRICT
278
    AS $$
279
DECLARE
280
    result value%TYPE := util._map(map, value::text)::unknown;
281
BEGIN
282
    RETURN result;
283
END;
284
$$;
285

    
286

    
287
--
288
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
289
--
290

    
291
CREATE FUNCTION _map(map hstore, value text) RETURNS text
292
    LANGUAGE plpgsql IMMUTABLE STRICT
293
    AS $$
294
DECLARE
295
    match text := map -> value;
296
BEGIN
297
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
298
        match := map -> '*'; -- use default entry
299
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
300
        END IF;
301
    END IF;
302
    
303
    -- Interpret result
304
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
305
    ELSIF match = '*' THEN RETURN value;
306
    ELSE RETURN match;
307
    END IF;
308
END;
309
$$;
310

    
311

    
312
--
313
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
314
--
315

    
316
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
317
    LANGUAGE sql IMMUTABLE
318
    AS $_$
319
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
320
$_$;
321

    
322

    
323
--
324
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
325
--
326

    
327
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
328
    LANGUAGE sql IMMUTABLE
329
    AS $_$
330
SELECT util.join_strs(value, '; ')
331
FROM
332
(
333
    SELECT *
334
    FROM
335
    (
336
        SELECT
337
        DISTINCT ON (value)
338
        *
339
        FROM
340
        (VALUES
341
              (1, $1)
342
            , (2, $2)
343
            , (3, $3)
344
            , (4, $4)
345
            , (5, $5)
346
            , (6, $6)
347
            , (7, $7)
348
            , (8, $8)
349
            , (9, $9)
350
            , (10, $10)
351
        )
352
        AS v (sort_order, value)
353
        WHERE value IS NOT NULL
354
    )
355
    AS v
356
    ORDER BY sort_order
357
)
358
AS v
359
$_$;
360

    
361

    
362
--
363
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
364
--
365

    
366
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
367
    LANGUAGE sql IMMUTABLE
368
    AS $_$
369
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
370
$_$;
371

    
372

    
373
--
374
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
375
--
376

    
377
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
378
    LANGUAGE sql IMMUTABLE
379
    AS $_$
380
SELECT util.join_strs(value, ' ')
381
FROM
382
(
383
    SELECT *
384
    FROM
385
    (
386
        SELECT
387
        DISTINCT ON (value)
388
        *
389
        FROM
390
        (VALUES
391
              (1, $1)
392
            , (2, $2)
393
            , (3, $3)
394
            , (4, $4)
395
            , (5, $5)
396
            , (6, $6)
397
            , (7, $7)
398
            , (8, $8)
399
            , (9, $9)
400
            , (10, $10)
401
        )
402
        AS v (sort_order, value)
403
        WHERE value IS NOT NULL
404
    )
405
    AS v
406
    ORDER BY sort_order
407
)
408
AS v
409
$_$;
410

    
411

    
412
--
413
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
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
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
420
$_$;
421

    
422

    
423
--
424
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
425
--
426

    
427
CREATE FUNCTION _not(value boolean) RETURNS boolean
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT NOT $1
431
$_$;
432

    
433

    
434
--
435
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
436
--
437

    
438
CREATE FUNCTION _now() RETURNS timestamp with time zone
439
    LANGUAGE sql STABLE
440
    AS $$
441
SELECT now()
442
$$;
443

    
444

    
445
--
446
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
447
--
448

    
449
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
450
    LANGUAGE sql IMMUTABLE
451
    AS $_$
452
SELECT util."_nullIf"($1, $2, $3::util.datatype)
453
$_$;
454

    
455

    
456
--
457
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
458
--
459

    
460
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
461
    LANGUAGE plpgsql IMMUTABLE
462
    AS $$
463
DECLARE
464
    type util.datatype NOT NULL := type; -- add NOT NULL
465
BEGIN
466
    IF type = 'str' THEN RETURN nullif(value::text, "null");
467
    -- Invalid value is ignored, but invalid null value generates error
468
    ELSIF type = 'float' THEN
469
        DECLARE
470
            -- Outside the try block so that invalid null value generates error
471
            "null" double precision := "null"::double precision;
472
        BEGIN
473
            RETURN nullif(value::double precision, "null");
474
        EXCEPTION
475
            WHEN data_exception THEN RETURN value; -- ignore invalid value
476
        END;
477
    END IF;
478
END;
479
$$;
480

    
481

    
482
--
483
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
484
--
485

    
486
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
487
    LANGUAGE sql IMMUTABLE
488
    AS $_$
489
SELECT bool_or(value)
490
FROM
491
(VALUES
492
      ($1)
493
    , ($2)
494
    , ($3)
495
    , ($4)
496
    , ($5)
497
)
498
AS v (value)
499
$_$;
500

    
501

    
502
--
503
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
504
--
505

    
506
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
507
_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.
508
';
509

    
510

    
511
--
512
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
513
--
514

    
515
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
516
    LANGUAGE sql IMMUTABLE
517
    AS $_$
518
SELECT $2 - $1
519
$_$;
520

    
521

    
522
--
523
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
524
--
525

    
526
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
527
    LANGUAGE sql IMMUTABLE
528
    AS $_$
529
SELECT regexp_split_to_table($1, $2)
530
$_$;
531

    
532

    
533
--
534
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
535
--
536

    
537
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
538
    LANGUAGE sql STABLE STRICT
539
    AS $_$
540
SELECT util.derived_cols($1, $2)
541
UNION
542
SELECT util.eval2set($$
543
SELECT col
544
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
545
JOIN $$||$2||$$ ON "to" = col
546
WHERE "from" LIKE ':%'
547
$$, NULL::text)
548
$_$;
549

    
550

    
551
--
552
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
553
--
554

    
555
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
556
gets table_''s added columns (all the columns not in the original data)
557
';
558

    
559

    
560
--
561
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
562
--
563

    
564
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
565
    LANGUAGE sql IMMUTABLE
566
    AS $_$
567
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
568
$_$;
569

    
570

    
571
--
572
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
573
--
574

    
575
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
576
    LANGUAGE plpgsql IMMUTABLE
577
    AS $$
578
DECLARE
579
	value_cmp         state%TYPE = ARRAY[value];
580
	state             state%TYPE = COALESCE(state, value_cmp);
581
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
582
BEGIN
583
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
584
END;
585
$$;
586

    
587

    
588
--
589
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
590
--
591

    
592
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
593
    LANGUAGE sql
594
    AS $_$
595
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
596
$_$;
597

    
598

    
599
--
600
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
604
    LANGUAGE sql IMMUTABLE
605
    AS $_$
606
SELECT pg_catalog.array_fill($1, ARRAY[$2])
607
$_$;
608

    
609

    
610
--
611
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
612
--
613

    
614
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT util.array_length($1, 1)
618
$_$;
619

    
620

    
621
--
622
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
623
--
624

    
625
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
626
    LANGUAGE sql IMMUTABLE
627
    AS $_$
628
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
629
$_$;
630

    
631

    
632
--
633
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
634
--
635

    
636
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
637
returns 0 instead of NULL for empty arrays
638
';
639

    
640

    
641
--
642
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
643
--
644

    
645
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
646
    LANGUAGE sql STABLE STRICT
647
    AS $_$
648
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
649
$_$;
650

    
651

    
652
--
653
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
654
--
655

    
656
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
657
    LANGUAGE plpgsql STRICT
658
    AS $_$
659
BEGIN
660
    -- not yet clustered (ARRAY[] compares NULLs literally)
661
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
662
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
663
    END IF;
664
END;
665
$_$;
666

    
667

    
668
--
669
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
670
--
671

    
672
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
673
idempotent
674
';
675

    
676

    
677
--
678
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
679
--
680

    
681
CREATE FUNCTION col__min(col col_ref) RETURNS integer
682
    LANGUAGE sql STABLE
683
    AS $_$
684
SELECT util.eval2val($$
685
SELECT $$||quote_ident($1.name)||$$
686
FROM $$||$1.table_||$$
687
ORDER BY $$||quote_ident($1.name)||$$ ASC
688
LIMIT 1
689
$$, NULL::integer)
690
$_$;
691

    
692

    
693
--
694
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
695
--
696

    
697
CREATE FUNCTION col_comment(col col_ref) RETURNS text
698
    LANGUAGE plpgsql STABLE STRICT
699
    AS $$
700
DECLARE
701
	comment text;
702
BEGIN
703
	SELECT description
704
	FROM pg_attribute
705
	LEFT JOIN pg_description ON objoid = attrelid
706
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
707
	WHERE attrelid = col.table_ AND attname = col.name
708
	INTO STRICT comment
709
	;
710
	RETURN comment;
711
EXCEPTION
712
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
713
END;
714
$$;
715

    
716

    
717
--
718
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
719
--
720

    
721
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
722
    LANGUAGE plpgsql STABLE STRICT
723
    AS $$
724
DECLARE
725
	default_sql text;
726
BEGIN
727
	SELECT adsrc
728
	FROM pg_attribute
729
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
730
	WHERE attrelid = col.table_ AND attname = col.name
731
	INTO STRICT default_sql
732
	;
733
	RETURN default_sql;
734
EXCEPTION
735
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
736
END;
737
$$;
738

    
739

    
740
--
741
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
742
--
743

    
744
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
745
    LANGUAGE sql STABLE
746
    AS $_$
747
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
748
$_$;
749

    
750

    
751
--
752
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
753
--
754

    
755
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
756
ret_type_null: NULL::ret_type
757
';
758

    
759

    
760
--
761
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
762
--
763

    
764
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
765
    LANGUAGE plpgsql STRICT
766
    AS $$
767
BEGIN
768
    PERFORM util.col_type(col);
769
    RETURN true;
770
EXCEPTION
771
    WHEN undefined_column THEN RETURN false;
772
END;
773
$$;
774

    
775

    
776
--
777
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
778
--
779

    
780
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
781
    LANGUAGE plpgsql STABLE STRICT
782
    AS $$
783
DECLARE
784
    prefix text := util.name(type)||'.';
785
BEGIN
786
    RETURN QUERY
787
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
788
        FROM util.col_names(type) f (name_);
789
END;
790
$$;
791

    
792

    
793
--
794
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
795
--
796

    
797
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
798
    LANGUAGE sql STABLE STRICT
799
    AS $_$
800
SELECT attname::text
801
FROM pg_attribute
802
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
803
ORDER BY attnum
804
$_$;
805

    
806

    
807
--
808
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
809
--
810

    
811
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
812
    LANGUAGE plpgsql STABLE STRICT
813
    AS $_$
814
BEGIN
815
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
816
END;
817
$_$;
818

    
819

    
820
--
821
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
822
--
823

    
824
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
825
    LANGUAGE plpgsql STABLE STRICT
826
    AS $$
827
DECLARE
828
    type regtype;
829
BEGIN
830
    SELECT atttypid FROM pg_attribute
831
    WHERE attrelid = col.table_ AND attname = col.name
832
    INTO STRICT type
833
    ;
834
    RETURN type;
835
EXCEPTION
836
    WHEN no_data_found THEN
837
        RAISE undefined_column USING MESSAGE =
838
            concat('undefined column: ', col.name);
839
END;
840
$$;
841

    
842

    
843
--
844
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
845
--
846

    
847
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
848
    LANGUAGE sql IMMUTABLE
849
    AS $_$
850
SELECT util.esc_name__append($2, $1)
851
$_$;
852

    
853

    
854
--
855
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
856
--
857

    
858
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
859
    LANGUAGE sql IMMUTABLE
860
    AS $_$
861
SELECT position($1 in $2) > 0 /*1-based offset*/
862
$_$;
863

    
864

    
865
--
866
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
867
--
868

    
869
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
870
    LANGUAGE sql
871
    AS $_$
872
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
873
$_$;
874

    
875

    
876
--
877
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
878
--
879

    
880
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
881
    LANGUAGE plpgsql STRICT
882
    AS $$
883
BEGIN
884
    PERFORM util.eval(sql);
885
EXCEPTION
886
    WHEN duplicate_table  THEN NULL;
887
    WHEN duplicate_object THEN NULL; -- e.g. constraint
888
    WHEN duplicate_column THEN NULL;
889
    WHEN invalid_table_definition THEN
890
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
891
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
892
        END IF;
893
END;
894
$$;
895

    
896

    
897
--
898
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
899
--
900

    
901
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
902
idempotent
903
';
904

    
905

    
906
--
907
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
908
--
909

    
910
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
911
    LANGUAGE sql IMMUTABLE
912
    AS $_$
913
/* newline before so the query starts at the beginning of the line.
914
newline after to visually separate queries from one another. */
915
SELECT util.raise_notice($$
916
$$||$1||$$
917
$$)
918
$_$;
919

    
920

    
921
--
922
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
923
--
924

    
925
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
926
    LANGUAGE sql STABLE STRICT
927
    AS $_$
928
SELECT util.eval2set($$
929
SELECT col
930
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
931
LEFT JOIN $$||$2||$$ ON "to" = col
932
WHERE "from" IS NULL
933
$$, NULL::text)
934
$_$;
935

    
936

    
937
--
938
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
939
--
940

    
941
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
942
gets table_''s derived columns (all the columns not in the names table)
943
';
944

    
945

    
946
--
947
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
948
--
949

    
950
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
951
    LANGUAGE sql STABLE
952
    AS $_$
953
SELECT * FROM util.diff($1::text, $2::text, $3,
954
	util.has_single_row($1) AND util.has_single_row($2))
955
$_$;
956

    
957

    
958
--
959
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
960
--
961

    
962
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
963
col_type_null (*required*): NULL::shared_base_type
964
usage:
965
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
966
';
967

    
968

    
969
--
970
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
971
--
972

    
973
CREATE FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
974
    LANGUAGE sql STABLE
975
    AS $_$
976
SELECT * FROM
977
util.eval2col_pair($$
978
/* need to explicitly cast each side to the return type because this does not
979
happen automatically even when an implicit cast is available */
980
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
981
FROM $$||$1||$$ left_
982
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
983
$$||util._if($4, ''::text, $$ON left_ = right_
984
$$)||
985
$$WHERE left_ IS DISTINCT FROM right_
986
ORDER BY left_, right_
987
$$, $3)
988
$_$;
989

    
990

    
991
--
992
-- Name: FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
993
--
994

    
995
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
996
col_type_null (*required*): NULL::col_type
997
single_row: whether the tables consist of a single row, which should be
998
	displayed side-by-side
999

    
1000
to run EXPLAIN on the FULL JOIN query:
1001
# run this function
1002
# look for a NOTICE containing the expanded query that it ran
1003
# run EXPLAIN on this expanded query
1004
';
1005

    
1006

    
1007
--
1008
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1009
--
1010

    
1011
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1012
    LANGUAGE sql STRICT
1013
    AS $_$
1014
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1015
$_$;
1016

    
1017

    
1018
--
1019
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1020
--
1021

    
1022
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1023
idempotent
1024
';
1025

    
1026

    
1027
--
1028
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1029
--
1030

    
1031
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1032
    LANGUAGE sql STRICT
1033
    AS $_$
1034
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1035
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1036
$_$;
1037

    
1038

    
1039
--
1040
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1041
--
1042

    
1043
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1044
idempotent
1045
';
1046

    
1047

    
1048
--
1049
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1050
--
1051

    
1052
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1053
    LANGUAGE sql
1054
    AS $_$
1055
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1056
included in the debug SQL */
1057
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1058
$_$;
1059

    
1060

    
1061
--
1062
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1063
--
1064

    
1065
CREATE FUNCTION drop_relation(type text, relation text, force boolean DEFAULT false) RETURNS void
1066
    LANGUAGE sql
1067
    AS $_$
1068
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1069
||util._if($3, $$ CASCADE$$, ''::text))
1070
$_$;
1071

    
1072

    
1073
--
1074
-- Name: FUNCTION drop_relation(type text, relation text, force boolean); Type: COMMENT; Schema: util; Owner: -
1075
--
1076

    
1077
COMMENT ON FUNCTION drop_relation(type text, relation text, force boolean) IS '
1078
idempotent
1079
';
1080

    
1081

    
1082
--
1083
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1084
--
1085

    
1086
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1087
    LANGUAGE sql STRICT
1088
    AS $_$
1089
SELECT util.drop_relation('TABLE', $1, $2)
1090
$_$;
1091

    
1092

    
1093
--
1094
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1095
--
1096

    
1097
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1098
idempotent
1099
';
1100

    
1101

    
1102
--
1103
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1104
--
1105

    
1106
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1107
    LANGUAGE sql STRICT
1108
    AS $_$
1109
SELECT util.drop_relation('VIEW', $1, $2)
1110
$_$;
1111

    
1112

    
1113
--
1114
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1115
--
1116

    
1117
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1118
idempotent
1119
';
1120

    
1121

    
1122
--
1123
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1124
--
1125

    
1126
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1127
    LANGUAGE sql IMMUTABLE
1128
    AS $_$
1129
SELECT util.array_fill($1, 0)
1130
$_$;
1131

    
1132

    
1133
--
1134
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1135
--
1136

    
1137
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1138
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1139
';
1140

    
1141

    
1142
--
1143
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1144
--
1145

    
1146
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1147
    LANGUAGE sql IMMUTABLE
1148
    AS $_$
1149
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1150
$_$;
1151

    
1152

    
1153
--
1154
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1155
--
1156

    
1157
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1158
    LANGUAGE sql IMMUTABLE
1159
    AS $_$
1160
SELECT regexp_replace($2, '("?)$', $1||'\1')
1161
$_$;
1162

    
1163

    
1164
--
1165
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1166
--
1167

    
1168
CREATE FUNCTION eval(sql text) RETURNS void
1169
    LANGUAGE plpgsql STRICT
1170
    AS $$
1171
BEGIN
1172
	PERFORM util.debug_print_sql(sql);
1173
	EXECUTE sql;
1174
END;
1175
$$;
1176

    
1177

    
1178
--
1179
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1180
--
1181

    
1182
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1183
    LANGUAGE plpgsql
1184
    AS $$
1185
BEGIN
1186
	PERFORM util.debug_print_sql(sql);
1187
	RETURN QUERY EXECUTE sql;
1188
END;
1189
$$;
1190

    
1191

    
1192
--
1193
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1194
--
1195

    
1196
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1197
col_type_null (*required*): NULL::col_type
1198
';
1199

    
1200

    
1201
--
1202
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1203
--
1204

    
1205
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1206
    LANGUAGE plpgsql
1207
    AS $$
1208
BEGIN
1209
	PERFORM util.debug_print_sql(sql);
1210
	RETURN QUERY EXECUTE sql;
1211
END;
1212
$$;
1213

    
1214

    
1215
--
1216
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1217
--
1218

    
1219
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1220
    LANGUAGE plpgsql
1221
    AS $$
1222
BEGIN
1223
	PERFORM util.debug_print_sql(sql);
1224
	RETURN QUERY EXECUTE sql;
1225
END;
1226
$$;
1227

    
1228

    
1229
--
1230
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1231
--
1232

    
1233
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1234
ret_type_null: NULL::ret_type
1235
';
1236

    
1237

    
1238
--
1239
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1240
--
1241

    
1242
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1243
    LANGUAGE plpgsql
1244
    AS $$
1245
DECLARE
1246
	ret_val ret_type_null%TYPE;
1247
BEGIN
1248
	PERFORM util.debug_print_sql(sql);
1249
	EXECUTE sql INTO STRICT ret_val;
1250
	RETURN ret_val;
1251
END;
1252
$$;
1253

    
1254

    
1255
--
1256
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1257
--
1258

    
1259
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1260
ret_type_null: NULL::ret_type
1261
';
1262

    
1263

    
1264
--
1265
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1266
--
1267

    
1268
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1269
    LANGUAGE sql
1270
    AS $_$
1271
SELECT util.eval2val($$SELECT $$||$1, $2)
1272
$_$;
1273

    
1274

    
1275
--
1276
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1277
--
1278

    
1279
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1280
ret_type_null: NULL::ret_type
1281
';
1282

    
1283

    
1284
--
1285
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1286
--
1287

    
1288
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1289
    LANGUAGE sql
1290
    AS $_$
1291
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1292
$_$;
1293

    
1294

    
1295
--
1296
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1297
--
1298

    
1299
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1300
sql: can be NULL, which will be passed through
1301
ret_type_null: NULL::ret_type
1302
';
1303

    
1304

    
1305
--
1306
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1307
--
1308

    
1309
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1310
    LANGUAGE sql STABLE STRICT
1311
    AS $_$
1312
SELECT col_name
1313
FROM unnest($2) s (col_name)
1314
WHERE util.col_exists(($1, col_name))
1315
$_$;
1316

    
1317

    
1318
--
1319
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1320
--
1321

    
1322
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1323
    LANGUAGE sql
1324
    AS $_$
1325
SELECT util.eval2set($$EXPLAIN $$||$1)
1326
$_$;
1327

    
1328

    
1329
--
1330
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1331
--
1332

    
1333
CREATE FUNCTION explain2notice(sql text) RETURNS void
1334
    LANGUAGE plpgsql
1335
    AS $_$
1336
BEGIN
1337
	RAISE NOTICE '%', $$EXPLAIN:
1338
$$||util.explain2str(sql);
1339
END;
1340
$_$;
1341

    
1342

    
1343
--
1344
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1345
--
1346

    
1347
CREATE FUNCTION explain2str(sql text) RETURNS text
1348
    LANGUAGE sql
1349
    AS $_$
1350
SELECT util.join_strs(explain, $$
1351
$$) FROM util.explain($1)
1352
$_$;
1353

    
1354

    
1355
SET default_tablespace = '';
1356

    
1357
SET default_with_oids = false;
1358

    
1359
--
1360
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1361
--
1362

    
1363
CREATE TABLE explain (
1364
    line text NOT NULL
1365
);
1366

    
1367

    
1368
--
1369
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1370
--
1371

    
1372
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1373
    LANGUAGE sql
1374
    AS $_$
1375
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1376
$$||quote_nullable($1)||$$
1377
)$$)
1378
$_$;
1379

    
1380

    
1381
--
1382
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1383
--
1384

    
1385
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1386
usage:
1387
PERFORM util.explain2table($$
1388
query
1389
$$);
1390
';
1391

    
1392

    
1393
--
1394
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1395
--
1396

    
1397
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1398
    LANGUAGE sql IMMUTABLE
1399
    AS $_$
1400
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1401
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1402
) END
1403
$_$;
1404

    
1405

    
1406
--
1407
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1408
--
1409

    
1410
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1411
ensures that an array will always have proper non-NULL dimensions
1412
';
1413

    
1414

    
1415
--
1416
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1417
--
1418

    
1419
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1420
    LANGUAGE plpgsql
1421
    AS $_$
1422
DECLARE
1423
	PG_EXCEPTION_DETAIL text;
1424
	recreate_users_cmd text = util.save_drop_views(users);
1425
BEGIN
1426
	PERFORM util.eval(cmd);
1427
	PERFORM util.eval(recreate_users_cmd);
1428
EXCEPTION
1429
WHEN dependent_objects_still_exist THEN
1430
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1431
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1432
	users = array(SELECT * FROM util.regexp_matches_group(
1433
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1434
	IF util.is_empty(users) THEN RAISE; END IF;
1435
	PERFORM util.force_recreate(cmd, users);
1436
END;
1437
$_$;
1438

    
1439

    
1440
--
1441
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1442
--
1443

    
1444
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1445
idempotent
1446

    
1447
users: not necessary to provide this because it will be autopopulated
1448
';
1449

    
1450

    
1451
--
1452
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1453
--
1454

    
1455
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1456
    LANGUAGE plpgsql STRICT
1457
    AS $_$
1458
DECLARE
1459
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1460
$$||query;
1461
BEGIN
1462
	EXECUTE mk_view;
1463
EXCEPTION
1464
WHEN invalid_table_definition THEN
1465
	IF SQLERRM = 'cannot drop columns from view'
1466
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1467
	THEN
1468
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1469
		EXECUTE mk_view;
1470
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1471
	END IF;
1472
END;
1473
$_$;
1474

    
1475

    
1476
--
1477
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1478
--
1479

    
1480
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1481
idempotent
1482
';
1483

    
1484

    
1485
--
1486
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1487
--
1488

    
1489
CREATE FUNCTION grants_users() RETURNS SETOF text
1490
    LANGUAGE sql IMMUTABLE
1491
    AS $$
1492
VALUES ('bien_read'), ('public_')
1493
$$;
1494

    
1495

    
1496
--
1497
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1498
--
1499

    
1500
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1501
    LANGUAGE sql IMMUTABLE
1502
    AS $_$
1503
SELECT substring($2 for length($1)) = $1
1504
$_$;
1505

    
1506

    
1507
--
1508
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1509
--
1510

    
1511
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1512
    LANGUAGE sql STABLE
1513
    AS $_$
1514
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1515
$_$;
1516

    
1517

    
1518
--
1519
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1520
--
1521

    
1522
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1523
    LANGUAGE sql IMMUTABLE
1524
    AS $_$
1525
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1526
$_$;
1527

    
1528

    
1529
--
1530
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1531
--
1532

    
1533
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1534
avoids repeating the same value for each key
1535
';
1536

    
1537

    
1538
--
1539
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1540
--
1541

    
1542
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1543
    LANGUAGE sql IMMUTABLE
1544
    AS $_$
1545
SELECT COALESCE($1, $2)
1546
$_$;
1547

    
1548

    
1549
--
1550
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1551
--
1552

    
1553
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1554
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1555
';
1556

    
1557

    
1558
--
1559
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1560
--
1561

    
1562
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1563
    LANGUAGE sql
1564
    AS $_$
1565
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1566
$_$;
1567

    
1568

    
1569
--
1570
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1571
--
1572

    
1573
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1574
    LANGUAGE sql STABLE STRICT
1575
    AS $_$
1576
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1577
$_$;
1578

    
1579

    
1580
--
1581
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1582
--
1583

    
1584
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1585
    LANGUAGE sql IMMUTABLE
1586
    AS $_$
1587
SELECT util.array_length($1) = 0
1588
$_$;
1589

    
1590

    
1591
--
1592
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1593
--
1594

    
1595
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1596
    LANGUAGE sql IMMUTABLE
1597
    AS $_$
1598
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1599
$_$;
1600

    
1601

    
1602
--
1603
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1604
--
1605

    
1606
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1607
    LANGUAGE sql IMMUTABLE
1608
    AS $_$
1609
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1610
$_$;
1611

    
1612

    
1613
--
1614
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1615
--
1616

    
1617
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1618
    LANGUAGE sql STABLE
1619
    AS $_$
1620
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1621
$_$;
1622

    
1623

    
1624
--
1625
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1626
--
1627

    
1628
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1629
    LANGUAGE sql STABLE
1630
    AS $_$
1631
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1632
$_$;
1633

    
1634

    
1635
--
1636
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1637
--
1638

    
1639
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1640
    LANGUAGE sql IMMUTABLE STRICT
1641
    AS $_$
1642
SELECT $1 || $3 || $2
1643
$_$;
1644

    
1645

    
1646
--
1647
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1648
--
1649

    
1650
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1651
    LANGUAGE sql IMMUTABLE
1652
    AS $_$
1653
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1654
$_$;
1655

    
1656

    
1657
--
1658
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660

    
1661
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1662
    LANGUAGE sql IMMUTABLE
1663
    AS $_$
1664
SELECT ltrim($1, $$
1665
$$)
1666
$_$;
1667

    
1668

    
1669
--
1670
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1671
--
1672

    
1673
CREATE FUNCTION map_filter_insert() RETURNS trigger
1674
    LANGUAGE plpgsql
1675
    AS $$
1676
BEGIN
1677
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1678
	RETURN new;
1679
END;
1680
$$;
1681

    
1682

    
1683
--
1684
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1685
--
1686

    
1687
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1688
    LANGUAGE plpgsql STABLE STRICT
1689
    AS $_$
1690
DECLARE
1691
    value text;
1692
BEGIN
1693
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1694
        INTO value USING key;
1695
    RETURN value;
1696
END;
1697
$_$;
1698

    
1699

    
1700
--
1701
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1702
--
1703

    
1704
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1705
    LANGUAGE sql IMMUTABLE
1706
    AS $_$
1707
SELECT util._map(util.nulls_map($1), $2)
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1713
--
1714

    
1715
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1716
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1717

    
1718
[1] inlining of function calls, which is different from constant folding
1719
[2] _map()''s profiling query
1720
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1721
and map_nulls()''s profiling query
1722
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1723
both take ~920 ms.
1724
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.
1725
';
1726

    
1727

    
1728
--
1729
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1730
--
1731

    
1732
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1733
    LANGUAGE plpgsql STABLE STRICT
1734
    AS $_$
1735
BEGIN
1736
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1737
END;
1738
$_$;
1739

    
1740

    
1741
--
1742
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1743
--
1744

    
1745
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1746
    LANGUAGE sql
1747
    AS $_$
1748
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1749
$$||util.ltrim_nl($2));
1750
-- make sure the created table has the correct estimated row count
1751
SELECT util.analyze_($1);
1752
$_$;
1753

    
1754

    
1755
--
1756
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1757
--
1758

    
1759
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1760
idempotent
1761
';
1762

    
1763

    
1764
--
1765
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767

    
1768
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1769
    LANGUAGE sql
1770
    AS $_$
1771
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1772
$_$;
1773

    
1774

    
1775
--
1776
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1777
--
1778

    
1779
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1780
idempotent
1781
';
1782

    
1783

    
1784
--
1785
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1786
--
1787

    
1788
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1789
    LANGUAGE sql STRICT
1790
    AS $_$
1791
SELECT util.create_if_not_exists($$
1792
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1793
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1794
||quote_literal($2)||$$;
1795
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1796
constant
1797
';
1798
$$)
1799
$_$;
1800

    
1801

    
1802
--
1803
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1804
--
1805

    
1806
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1807
idempotent
1808
';
1809

    
1810

    
1811
--
1812
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1813
--
1814

    
1815
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1816
    LANGUAGE plpgsql STRICT
1817
    AS $_$
1818
DECLARE
1819
    type regtype = util.typeof(expr, col.table_::text::regtype);
1820
    col_name_sql text = quote_ident(col.name);
1821
BEGIN
1822
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1823
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1824
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1825
$$||expr||$$;
1826
$$);
1827
END;
1828
$_$;
1829

    
1830

    
1831
--
1832
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1833
--
1834

    
1835
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1836
idempotent
1837
';
1838

    
1839

    
1840
--
1841
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1842
--
1843

    
1844
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1845
    LANGUAGE sql STRICT
1846
    AS $_$
1847
SELECT util.create_if_not_exists($$
1848
CREATE TABLE $$||$1||$$
1849
(
1850
    LIKE util.map INCLUDING ALL
1851
);
1852

    
1853
CREATE TRIGGER map_filter_insert
1854
  BEFORE INSERT
1855
  ON $$||$1||$$
1856
  FOR EACH ROW
1857
  EXECUTE PROCEDURE util.map_filter_insert();
1858
$$)
1859
$_$;
1860

    
1861

    
1862
--
1863
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1864
--
1865

    
1866
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1867
    LANGUAGE sql IMMUTABLE
1868
    AS $_$
1869
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1870
$_$;
1871

    
1872

    
1873
--
1874
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1875
--
1876

    
1877
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1878
    LANGUAGE sql IMMUTABLE
1879
    AS $_$
1880
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1881
$_$;
1882

    
1883

    
1884
--
1885
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1886
--
1887

    
1888
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1889
usage:
1890
for *1* schema arg:
1891
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1892
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1893
';
1894

    
1895

    
1896
--
1897
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1898
--
1899

    
1900
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1901
    LANGUAGE sql IMMUTABLE
1902
    AS $_$
1903
SELECT $$SET LOCAL search_path TO $$||$1
1904
$_$;
1905

    
1906

    
1907
--
1908
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1909
--
1910

    
1911
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1912
    LANGUAGE sql STRICT
1913
    AS $_$
1914
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1915
$_$;
1916

    
1917

    
1918
--
1919
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1920
--
1921

    
1922
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1923
idempotent
1924
';
1925

    
1926

    
1927
--
1928
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1929
--
1930

    
1931
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1932
    LANGUAGE plpgsql STRICT
1933
    AS $_$
1934
DECLARE
1935
	view_qual_name text = util.qual_name(view_);
1936
BEGIN
1937
	EXECUTE $$
1938
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1939
  RETURNS SETOF $$||view_||$$ AS
1940
$BODY1$
1941
SELECT * FROM $$||view_qual_name||$$
1942
ORDER BY sort_col
1943
LIMIT $1 OFFSET $2
1944
$BODY1$
1945
  LANGUAGE sql STABLE
1946
  COST 100
1947
  ROWS 1000
1948
$$;
1949
	
1950
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1951
END;
1952
$_$;
1953

    
1954

    
1955
--
1956
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1957
--
1958

    
1959
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1960
    LANGUAGE plpgsql STRICT
1961
    AS $_$
1962
DECLARE
1963
	view_qual_name text = util.qual_name(view_);
1964
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1965
BEGIN
1966
	EXECUTE $$
1967
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1968
  RETURNS integer AS
1969
$BODY1$
1970
SELECT $$||quote_ident(row_num_col)||$$
1971
FROM $$||view_qual_name||$$
1972
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1973
LIMIT 1
1974
$BODY1$
1975
  LANGUAGE sql STABLE
1976
  COST 100;
1977
$$;
1978
	
1979
	EXECUTE $$
1980
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1981
  RETURNS SETOF $$||view_||$$ AS
1982
$BODY1$
1983
SELECT * FROM $$||view_qual_name||$$
1984
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1985
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1986
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1987
ORDER BY $$||quote_ident(row_num_col)||$$
1988
$BODY1$
1989
  LANGUAGE sql STABLE
1990
  COST 100
1991
  ROWS 1000
1992
$$;
1993
	
1994
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1995
END;
1996
$_$;
1997

    
1998

    
1999
--
2000
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2001
--
2002

    
2003
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2004
    LANGUAGE plpgsql STRICT
2005
    AS $_$
2006
DECLARE
2007
	view_qual_name text = util.qual_name(view_);
2008
BEGIN
2009
	EXECUTE $$
2010
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2011
  RETURNS SETOF $$||view_||$$
2012
  SET enable_sort TO 'off'
2013
  AS
2014
$BODY1$
2015
SELECT * FROM $$||view_qual_name||$$($2, $3)
2016
$BODY1$
2017
  LANGUAGE sql STABLE
2018
  COST 100
2019
  ROWS 1000
2020
;
2021
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2022
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2023
If you want to run EXPLAIN and get expanded output, use the regular subset
2024
function instead. (When a config param is set on a function, EXPLAIN produces
2025
just a function scan.)
2026
';
2027
$$;
2028
END;
2029
$_$;
2030

    
2031

    
2032
--
2033
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2034
--
2035

    
2036
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2037
creates subset function which turns off enable_sort
2038
';
2039

    
2040

    
2041
--
2042
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2043
--
2044

    
2045
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2046
    LANGUAGE sql IMMUTABLE
2047
    AS $_$
2048
SELECT util.mk_set_search_path(util.schema_esc($1))
2049
$_$;
2050

    
2051

    
2052
--
2053
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2054
--
2055

    
2056
CREATE FUNCTION name(table_ regclass) RETURNS text
2057
    LANGUAGE sql STABLE
2058
    AS $_$
2059
SELECT relname::text FROM pg_class WHERE oid = $1
2060
$_$;
2061

    
2062

    
2063
--
2064
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2065
--
2066

    
2067
CREATE FUNCTION name(type regtype) RETURNS text
2068
    LANGUAGE sql STABLE STRICT
2069
    AS $_$
2070
SELECT typname::text FROM pg_type WHERE oid = $1
2071
$_$;
2072

    
2073

    
2074
--
2075
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2076
--
2077

    
2078
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2079
    LANGUAGE sql IMMUTABLE
2080
    AS $_$
2081
SELECT octet_length($1) >= util.namedatalen() - $2
2082
$_$;
2083

    
2084

    
2085
--
2086
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2087
--
2088

    
2089
CREATE FUNCTION namedatalen() RETURNS integer
2090
    LANGUAGE sql IMMUTABLE
2091
    AS $$
2092
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2093
$$;
2094

    
2095

    
2096
--
2097
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2098
--
2099

    
2100
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2101
    LANGUAGE sql IMMUTABLE
2102
    AS $_$
2103
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2104
$_$;
2105

    
2106

    
2107
--
2108
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2109
--
2110

    
2111
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2112
    LANGUAGE sql IMMUTABLE
2113
    AS $_$
2114
SELECT $1 IS NOT NULL
2115
$_$;
2116

    
2117

    
2118
--
2119
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2120
--
2121

    
2122
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2123
    LANGUAGE sql IMMUTABLE
2124
    AS $_$
2125
SELECT util.hstore($1, NULL) || '*=>*'
2126
$_$;
2127

    
2128

    
2129
--
2130
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2131
--
2132

    
2133
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2134
for use with _map()
2135
';
2136

    
2137

    
2138
--
2139
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2140
--
2141

    
2142
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2143
    LANGUAGE sql IMMUTABLE
2144
    AS $_$
2145
SELECT $2 + COALESCE($1, 0)
2146
$_$;
2147

    
2148

    
2149
--
2150
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2151
--
2152

    
2153
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2154
    LANGUAGE sql IMMUTABLE
2155
    AS $_$
2156
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2157
$_$;
2158

    
2159

    
2160
--
2161
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2162
--
2163

    
2164
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2165
    LANGUAGE sql STABLE STRICT
2166
    SET search_path TO pg_temp
2167
    AS $_$
2168
SELECT $1::text
2169
$_$;
2170

    
2171

    
2172
--
2173
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2174
--
2175

    
2176
CREATE FUNCTION qual_name(type regtype) RETURNS text
2177
    LANGUAGE sql STABLE STRICT
2178
    SET search_path TO pg_temp
2179
    AS $_$
2180
SELECT $1::text
2181
$_$;
2182

    
2183

    
2184
--
2185
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2186
--
2187

    
2188
COMMENT ON FUNCTION qual_name(type regtype) IS '
2189
a type''s schema-qualified name
2190
';
2191

    
2192

    
2193
--
2194
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2195
--
2196

    
2197
CREATE FUNCTION qual_name(type unknown) RETURNS text
2198
    LANGUAGE sql STABLE STRICT
2199
    AS $_$
2200
SELECT util.qual_name($1::text::regtype)
2201
$_$;
2202

    
2203

    
2204
--
2205
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207

    
2208
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2209
    LANGUAGE sql IMMUTABLE STRICT
2210
    AS $_$
2211
SELECT util.raise_notice('ERROR:  '||$1)
2212
$_$;
2213

    
2214

    
2215
--
2216
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2217
--
2218

    
2219
CREATE FUNCTION raise_notice(msg text) RETURNS void
2220
    LANGUAGE plpgsql IMMUTABLE STRICT
2221
    AS $$
2222
BEGIN
2223
	RAISE NOTICE '%', msg;
2224
END;
2225
$$;
2226

    
2227

    
2228
--
2229
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231

    
2232
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2233
    LANGUAGE plpgsql IMMUTABLE STRICT
2234
    AS $$
2235
BEGIN
2236
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2237
END;
2238
$$;
2239

    
2240

    
2241
--
2242
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2243
--
2244

    
2245
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2246
    LANGUAGE sql IMMUTABLE
2247
    AS $_$
2248
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2249
$_$;
2250

    
2251

    
2252
--
2253
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2254
--
2255

    
2256
CREATE FUNCTION regexp_quote(str text) RETURNS text
2257
    LANGUAGE sql IMMUTABLE
2258
    AS $_$
2259
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2260
$_$;
2261

    
2262

    
2263
--
2264
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2265
--
2266

    
2267
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2268
    LANGUAGE sql STABLE
2269
    AS $_$
2270
SELECT util.relation_type(util.relation_type_char($1))
2271
$_$;
2272

    
2273

    
2274
--
2275
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2276
--
2277

    
2278
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2279
    LANGUAGE sql IMMUTABLE
2280
    AS $_$
2281
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2282
$_$;
2283

    
2284

    
2285
--
2286
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288

    
2289
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2290
    LANGUAGE sql STABLE
2291
    AS $_$
2292
SELECT relkind FROM pg_class WHERE oid = $1
2293
$_$;
2294

    
2295

    
2296
--
2297
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2298
--
2299

    
2300
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2301
    LANGUAGE sql
2302
    AS $_$
2303
/* can't have in_table/out_table inherit from *each other*, because inheritance
2304
also causes the rows of the parent table to be included in the child table.
2305
instead, they need to inherit from a common, empty table. */
2306
SELECT util.drop_table($4, force := true);
2307
SELECT util.copy_struct($2, $4);
2308
SELECT util.inherit($2, $4);
2309
SELECT util.inherit($3, $4);
2310

    
2311
SELECT util.rematerialize_query($1, $$
2312
SELECT * FROM util.diff(
2313
  $$||quote_nullable($2)||$$::regclass
2314
, $$||quote_nullable($3)||$$::regclass
2315
, NULL::$$||$4||$$)
2316
$$);
2317

    
2318
/* the table unfortunately cannot be *materialized* in human-readable form,
2319
because this would create column name collisions between the two sides */
2320
SELECT util.set_comment($1, '
2321
to view this table in human-readable form (with each side''s tuple column
2322
expanded to its component fields):
2323
SELECT (left_).*, (right_).* FROM '||$1||';
2324
');
2325
$_$;
2326

    
2327

    
2328
--
2329
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2330
--
2331

    
2332
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2333
type_table (*required*): table to create as the shared base type
2334
';
2335

    
2336

    
2337
--
2338
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2339
--
2340

    
2341
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2342
    LANGUAGE sql
2343
    AS $_$
2344
SELECT util.drop_table($1);
2345
SELECT util.materialize_query($1, $2);
2346
$_$;
2347

    
2348

    
2349
--
2350
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2351
--
2352

    
2353
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2354
idempotent, but repeats action each time
2355
';
2356

    
2357

    
2358
--
2359
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2360
--
2361

    
2362
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2363
    LANGUAGE sql
2364
    AS $_$
2365
SELECT util.drop_table($1);
2366
SELECT util.materialize_view($1, $2);
2367
$_$;
2368

    
2369

    
2370
--
2371
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2372
--
2373

    
2374
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2375
idempotent, but repeats action each time
2376
';
2377

    
2378

    
2379
--
2380
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382

    
2383
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2384
    LANGUAGE sql STRICT
2385
    AS $_$
2386
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2387
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2388
FROM util.col_names($1::text::regtype) f (name);
2389
SELECT NULL::void; -- don't fold away functions called in previous query
2390
$_$;
2391

    
2392

    
2393
--
2394
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2395
--
2396

    
2397
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2398
idempotent
2399
';
2400

    
2401

    
2402
--
2403
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2404
--
2405

    
2406
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2407
    LANGUAGE sql
2408
    AS $_$
2409
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2410
included in the debug SQL */
2411
SELECT util.rename_relation(util.qual_name($1), $2)
2412
$_$;
2413

    
2414

    
2415
--
2416
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2417
--
2418

    
2419
CREATE FUNCTION rename_relation(from_ text, to_ text) RETURNS void
2420
    LANGUAGE sql
2421
    AS $_$
2422
/* 'ALTER TABLE can be used with views too'
2423
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2424
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2425
||quote_ident($2))
2426
$_$;
2427

    
2428

    
2429
--
2430
-- Name: FUNCTION rename_relation(from_ text, to_ text); Type: COMMENT; Schema: util; Owner: -
2431
--
2432

    
2433
COMMENT ON FUNCTION rename_relation(from_ text, to_ text) IS '
2434
idempotent
2435
';
2436

    
2437

    
2438
--
2439
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2440
--
2441

    
2442
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2443
    LANGUAGE sql IMMUTABLE
2444
    AS $_$
2445
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2446
$_$;
2447

    
2448

    
2449
--
2450
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2451
--
2452

    
2453
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2454
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 
2455
';
2456

    
2457

    
2458
--
2459
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2460
--
2461

    
2462
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2463
    LANGUAGE sql STRICT
2464
    AS $_$
2465
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2466
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2467
SELECT util.set_col_names($1, $2);
2468
$_$;
2469

    
2470

    
2471
--
2472
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2473
--
2474

    
2475
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2476
idempotent.
2477
alters the names table, so it will need to be repopulated after running this function.
2478
';
2479

    
2480

    
2481
--
2482
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2483
--
2484

    
2485
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2486
    LANGUAGE sql STRICT
2487
    AS $_$
2488
SELECT util.drop_table($1);
2489
SELECT util.mk_map_table($1);
2490
$_$;
2491

    
2492

    
2493
--
2494
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2495
--
2496

    
2497
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2498
    LANGUAGE sql IMMUTABLE
2499
    AS $_$
2500
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2501
$_$;
2502

    
2503

    
2504
--
2505
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2506
--
2507

    
2508
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2509
    LANGUAGE plpgsql STRICT
2510
    AS $_$
2511
DECLARE
2512
	result text = NULL;
2513
BEGIN
2514
	BEGIN
2515
		result = util.show_create_view(view_);
2516
		PERFORM util.eval($$DROP VIEW $$||view_);
2517
	EXCEPTION
2518
		WHEN undefined_table THEN NULL;
2519
	END;
2520
	RETURN result;
2521
END;
2522
$_$;
2523

    
2524

    
2525
--
2526
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2527
--
2528

    
2529
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2530
    LANGUAGE sql
2531
    AS $_$
2532
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2533
$_$;
2534

    
2535

    
2536
--
2537
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2538
--
2539

    
2540
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2541
    LANGUAGE sql STABLE
2542
    AS $_$
2543
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2544
$_$;
2545

    
2546

    
2547
--
2548
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2549
--
2550

    
2551
CREATE FUNCTION schema(table_ regclass) RETURNS text
2552
    LANGUAGE sql STABLE
2553
    AS $_$
2554
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2555
$_$;
2556

    
2557

    
2558
--
2559
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2560
--
2561

    
2562
CREATE FUNCTION schema(type regtype) RETURNS text
2563
    LANGUAGE sql STABLE
2564
    AS $_$
2565
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2566
$_$;
2567

    
2568

    
2569
--
2570
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2571
--
2572

    
2573
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2574
    LANGUAGE sql STABLE
2575
    AS $_$
2576
SELECT util.schema(pg_typeof($1))
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2582
--
2583

    
2584
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2585
    LANGUAGE sql STABLE
2586
    AS $_$
2587
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2588
$_$;
2589

    
2590

    
2591
--
2592
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2593
--
2594

    
2595
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2596
a schema bundle is a group of schemas with a common prefix
2597
';
2598

    
2599

    
2600
--
2601
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2602
--
2603

    
2604
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2605
    LANGUAGE sql
2606
    AS $_$
2607
SELECT util.schema_rename(old_schema,
2608
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2609
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2610
SELECT NULL::void; -- don't fold away functions called in previous query
2611
$_$;
2612

    
2613

    
2614
--
2615
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2616
--
2617

    
2618
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2619
    LANGUAGE plpgsql
2620
    AS $$
2621
BEGIN
2622
	-- don't schema_bundle_rm() the schema_bundle to keep!
2623
	IF replace = with_ THEN RETURN; END IF;
2624
	
2625
	PERFORM util.schema_bundle_rm(replace);
2626
	PERFORM util.schema_bundle_rename(with_, replace);
2627
END;
2628
$$;
2629

    
2630

    
2631
--
2632
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2633
--
2634

    
2635
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2636
    LANGUAGE sql
2637
    AS $_$
2638
SELECT util.schema_rm(schema)
2639
FROM util.schema_bundle_get_schemas($1) f (schema);
2640
SELECT NULL::void; -- don't fold away functions called in previous query
2641
$_$;
2642

    
2643

    
2644
--
2645
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2646
--
2647

    
2648
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2649
    LANGUAGE sql STABLE
2650
    AS $_$
2651
SELECT quote_ident(util.schema($1))
2652
$_$;
2653

    
2654

    
2655
--
2656
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2657
--
2658

    
2659
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2660
    LANGUAGE sql IMMUTABLE
2661
    AS $_$
2662
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2663
$_$;
2664

    
2665

    
2666
--
2667
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2668
--
2669

    
2670
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2671
    LANGUAGE sql STABLE
2672
    AS $_$
2673
SELECT oid FROM pg_namespace WHERE nspname = $1
2674
$_$;
2675

    
2676

    
2677
--
2678
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2679
--
2680

    
2681
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2682
    LANGUAGE sql
2683
    AS $_$
2684
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2685
$_$;
2686

    
2687

    
2688
--
2689
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2690
--
2691

    
2692
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2693
    LANGUAGE plpgsql
2694
    AS $$
2695
BEGIN
2696
	-- don't schema_rm() the schema to keep!
2697
	IF replace = with_ THEN RETURN; END IF;
2698
	
2699
	PERFORM util.schema_rm(replace);
2700
	PERFORM util.schema_rename(with_, replace);
2701
END;
2702
$$;
2703

    
2704

    
2705
--
2706
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2707
--
2708

    
2709
CREATE FUNCTION schema_rm(schema text) RETURNS void
2710
    LANGUAGE sql
2711
    AS $_$
2712
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2713
$_$;
2714

    
2715

    
2716
--
2717
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2718
--
2719

    
2720
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2721
    LANGUAGE sql STRICT
2722
    AS $_$
2723
SELECT util.eval(
2724
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2725
$_$;
2726

    
2727

    
2728
--
2729
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2730
--
2731

    
2732
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2733
    LANGUAGE plpgsql STRICT
2734
    AS $_$
2735
DECLARE
2736
    old text[] = ARRAY(SELECT util.col_names(table_));
2737
    new text[] = ARRAY(SELECT util.map_values(names));
2738
BEGIN
2739
    old = old[1:array_length(new, 1)]; -- truncate to same length
2740
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2741
||$$ TO $$||quote_ident(value))
2742
    FROM each(hstore(old, new))
2743
    WHERE value != key -- not same name
2744
    ;
2745
END;
2746
$_$;
2747

    
2748

    
2749
--
2750
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2751
--
2752

    
2753
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2754
idempotent
2755
';
2756

    
2757

    
2758
--
2759
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2760
--
2761

    
2762
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2763
    LANGUAGE plpgsql STRICT
2764
    AS $_$
2765
DECLARE
2766
	row_ util.map;
2767
BEGIN
2768
	-- rename any metadata cols rather than re-adding them with new names
2769
	BEGIN
2770
		PERFORM util.set_col_names(table_, names);
2771
	EXCEPTION
2772
		WHEN array_subscript_error THEN -- selective suppress
2773
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2774
				-- metadata cols not yet added
2775
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2776
			END IF;
2777
	END;
2778
	
2779
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2780
	LOOP
2781
		PERFORM util.mk_const_col((table_, row_."to"),
2782
			substring(row_."from" from 2));
2783
	END LOOP;
2784
	
2785
	PERFORM util.set_col_names(table_, names);
2786
END;
2787
$_$;
2788

    
2789

    
2790
--
2791
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2792
--
2793

    
2794
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2795
idempotent.
2796
the metadata mappings must be *last* in the names table.
2797
';
2798

    
2799

    
2800
--
2801
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2802
--
2803

    
2804
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2805
    LANGUAGE plpgsql STRICT
2806
    AS $_$
2807
DECLARE
2808
    sql text = $$ALTER TABLE $$||table_||$$
2809
$$||NULLIF(array_to_string(ARRAY(
2810
    SELECT
2811
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2812
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2813
    FROM
2814
    (
2815
        SELECT
2816
          quote_ident(col_name) AS col_name_sql
2817
        , util.col_type((table_, col_name)) AS curr_type
2818
        , type AS target_type
2819
        FROM unnest(col_casts)
2820
    ) s
2821
    WHERE curr_type != target_type
2822
), '
2823
, '), '');
2824
BEGIN
2825
    PERFORM util.debug_print_sql(sql);
2826
    EXECUTE COALESCE(sql, '');
2827
END;
2828
$_$;
2829

    
2830

    
2831
--
2832
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2833
--
2834

    
2835
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2836
idempotent
2837
';
2838

    
2839

    
2840
--
2841
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2842
--
2843

    
2844
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2845
    LANGUAGE sql STRICT
2846
    AS $_$
2847
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2848
$_$;
2849

    
2850

    
2851
--
2852
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2853
--
2854

    
2855
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2856
    LANGUAGE sql STABLE
2857
    AS $_$
2858
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2859
$$||util.show_grants_for($1)
2860
$_$;
2861

    
2862

    
2863
--
2864
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2865
--
2866

    
2867
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2868
    LANGUAGE sql STABLE
2869
    AS $_$
2870
SELECT string_agg(cmd, '')
2871
FROM
2872
(
2873
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2874
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2875
$$ ELSE '' END) AS cmd
2876
	FROM util.grants_users() f (user_)
2877
) s
2878
$_$;
2879

    
2880

    
2881
--
2882
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2883
--
2884

    
2885
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2886
    LANGUAGE sql STABLE
2887
    AS $_$
2888
SELECT oid FROM pg_class
2889
WHERE relkind = ANY($3) AND relname ~ $1
2890
AND util.schema_matches(util.schema(relnamespace), $2)
2891
ORDER BY relname
2892
$_$;
2893

    
2894

    
2895
--
2896
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
2897
--
2898

    
2899
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2900
    LANGUAGE sql STABLE
2901
    AS $_$
2902
SELECT view_
2903
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2904
WHERE util.schema(view_) = $2
2905
$_$;
2906

    
2907

    
2908
--
2909
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2910
--
2911

    
2912
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2913
    LANGUAGE plpgsql STABLE STRICT
2914
    AS $_$
2915
DECLARE
2916
    hstore hstore;
2917
BEGIN
2918
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2919
        table_||$$))$$ INTO STRICT hstore;
2920
    RETURN hstore;
2921
END;
2922
$_$;
2923

    
2924

    
2925
--
2926
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2927
--
2928

    
2929
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2930
    LANGUAGE sql STABLE STRICT
2931
    AS $_$
2932
SELECT COUNT(*) > 0 FROM pg_constraint
2933
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2934
$_$;
2935

    
2936

    
2937
--
2938
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2939
--
2940

    
2941
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2942
gets whether a status flag is set by the presence of a table constraint
2943
';
2944

    
2945

    
2946
--
2947
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2948
--
2949

    
2950
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2951
    LANGUAGE sql STRICT
2952
    AS $_$
2953
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2954
||quote_ident($2)||$$ CHECK (true)$$)
2955
$_$;
2956

    
2957

    
2958
--
2959
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2960
--
2961

    
2962
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2963
stores a status flag by the presence of a table constraint.
2964
idempotent.
2965
';
2966

    
2967

    
2968
--
2969
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2970
--
2971

    
2972
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2973
    LANGUAGE sql STABLE STRICT
2974
    AS $_$
2975
SELECT util.table_flag__get($1, 'nulls_mapped')
2976
$_$;
2977

    
2978

    
2979
--
2980
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2981
--
2982

    
2983
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2984
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2985
';
2986

    
2987

    
2988
--
2989
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2990
--
2991

    
2992
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2993
    LANGUAGE sql STRICT
2994
    AS $_$
2995
SELECT util.table_flag__set($1, 'nulls_mapped')
2996
$_$;
2997

    
2998

    
2999
--
3000
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3001
--
3002

    
3003
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3004
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3005
idempotent.
3006
';
3007

    
3008

    
3009
--
3010
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3011
--
3012

    
3013
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3014
    LANGUAGE plpgsql STRICT
3015
    AS $_$
3016
DECLARE
3017
    row record;
3018
BEGIN
3019
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3020
    LOOP
3021
        IF row.global_name != row.name THEN
3022
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3023
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3024
        END IF;
3025
    END LOOP;
3026
END;
3027
$_$;
3028

    
3029

    
3030
--
3031
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3032
--
3033

    
3034
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3035
idempotent
3036
';
3037

    
3038

    
3039
--
3040
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3041
--
3042

    
3043
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3044
    LANGUAGE sql STRICT
3045
    AS $_$
3046
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3047
SELECT NULL::void; -- don't fold away functions called in previous query
3048
$_$;
3049

    
3050

    
3051
--
3052
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3053
--
3054

    
3055
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3056
trims table_ to include only columns in the original data.
3057
idempotent.
3058
';
3059

    
3060

    
3061
--
3062
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3063
--
3064

    
3065
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3066
    LANGUAGE plpgsql STRICT
3067
    AS $_$
3068
BEGIN
3069
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3070
END;
3071
$_$;
3072

    
3073

    
3074
--
3075
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3076
--
3077

    
3078
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3079
idempotent
3080
';
3081

    
3082

    
3083
--
3084
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3085
--
3086

    
3087
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3088
    LANGUAGE sql IMMUTABLE
3089
    AS $_$
3090
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3091
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3092
$_$;
3093

    
3094

    
3095
--
3096
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3097
--
3098

    
3099
CREATE FUNCTION try_create(sql text) RETURNS void
3100
    LANGUAGE plpgsql STRICT
3101
    AS $$
3102
BEGIN
3103
    PERFORM util.eval(sql);
3104
EXCEPTION
3105
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3106
    WHEN undefined_column THEN NULL;
3107
    WHEN duplicate_column THEN NULL;
3108
END;
3109
$$;
3110

    
3111

    
3112
--
3113
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3114
--
3115

    
3116
COMMENT ON FUNCTION try_create(sql text) IS '
3117
idempotent
3118
';
3119

    
3120

    
3121
--
3122
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3123
--
3124

    
3125
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3126
    LANGUAGE sql STRICT
3127
    AS $_$
3128
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3129
$_$;
3130

    
3131

    
3132
--
3133
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3134
--
3135

    
3136
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3137
idempotent
3138
';
3139

    
3140

    
3141
--
3142
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3143
--
3144

    
3145
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3146
    LANGUAGE sql IMMUTABLE
3147
    AS $_$
3148
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3149
$_$;
3150

    
3151

    
3152
--
3153
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3154
--
3155

    
3156
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3157
a type''s NOT NULL qualifier
3158
';
3159

    
3160

    
3161
--
3162
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3163
--
3164

    
3165
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3166
    LANGUAGE plpgsql STABLE
3167
    AS $_$
3168
DECLARE
3169
    type regtype;
3170
BEGIN
3171
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3172
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3173
    RETURN type;
3174
END;
3175
$_$;
3176

    
3177

    
3178
--
3179
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3180
--
3181

    
3182
CREATE AGGREGATE all_same(anyelement) (
3183
    SFUNC = all_same_transform,
3184
    STYPE = anyarray,
3185
    FINALFUNC = all_same_final
3186
);
3187

    
3188

    
3189
--
3190
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3191
--
3192

    
3193
COMMENT ON AGGREGATE all_same(anyelement) IS '
3194
includes NULLs in comparison
3195
';
3196

    
3197

    
3198
--
3199
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3200
--
3201

    
3202
CREATE AGGREGATE join_strs(text, text) (
3203
    SFUNC = join_strs_transform,
3204
    STYPE = text
3205
);
3206

    
3207

    
3208
--
3209
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3210
--
3211

    
3212
CREATE OPERATOR -> (
3213
    PROCEDURE = map_get,
3214
    LEFTARG = regclass,
3215
    RIGHTARG = text
3216
);
3217

    
3218

    
3219
--
3220
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3221
--
3222

    
3223
CREATE OPERATOR => (
3224
    PROCEDURE = hstore,
3225
    LEFTARG = text[],
3226
    RIGHTARG = text
3227
);
3228

    
3229

    
3230
--
3231
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3232
--
3233

    
3234
COMMENT ON OPERATOR => (text[], text) IS '
3235
usage: array[''key1'', ...]::text[] => ''value''
3236
';
3237

    
3238

    
3239
--
3240
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3241
--
3242

    
3243
CREATE OPERATOR ?*>= (
3244
    PROCEDURE = is_populated_more_often_than,
3245
    LEFTARG = anyelement,
3246
    RIGHTARG = anyelement
3247
);
3248

    
3249

    
3250
--
3251
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3252
--
3253

    
3254
CREATE OPERATOR ?>= (
3255
    PROCEDURE = is_more_complete_than,
3256
    LEFTARG = anyelement,
3257
    RIGHTARG = anyelement
3258
);
3259

    
3260

    
3261
--
3262
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3263
--
3264

    
3265
CREATE OPERATOR ||% (
3266
    PROCEDURE = concat_esc,
3267
    LEFTARG = text,
3268
    RIGHTARG = text
3269
);
3270

    
3271

    
3272
--
3273
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3274
--
3275

    
3276
COMMENT ON OPERATOR ||% (text, text) IS '
3277
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3278
';
3279

    
3280

    
3281
--
3282
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3283
--
3284

    
3285
CREATE TABLE map (
3286
    "from" text NOT NULL,
3287
    "to" text,
3288
    filter text,
3289
    notes text
3290
);
3291

    
3292

    
3293
--
3294
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3295
--
3296

    
3297

    
3298

    
3299
--
3300
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3301
--
3302

    
3303

    
3304

    
3305
--
3306
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3307
--
3308

    
3309
ALTER TABLE ONLY map
3310
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3311

    
3312

    
3313
--
3314
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3315
--
3316

    
3317
ALTER TABLE ONLY map
3318
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3319

    
3320

    
3321
--
3322
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3323
--
3324

    
3325
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3326

    
3327

    
3328
--
3329
-- PostgreSQL database dump complete
3330
--
3331

    
(19-19/29)