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
SELECT (CASE
1056
WHEN util.is_table($1) THEN util.drop_table($1::text, $2)
1057
WHEN util.is_view($1)  THEN util.drop_view ($1::text, $2)
1058
-- otherwise, throw case_not_found error
1059
END)
1060
$_$;
1061

    
1062

    
1063
--
1064
-- Name: FUNCTION drop_relation(relation regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
1065
--
1066

    
1067
COMMENT ON FUNCTION drop_relation(relation regclass, force boolean) IS '
1068
idempotent
1069
';
1070

    
1071

    
1072
--
1073
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1074
--
1075

    
1076
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1077
    LANGUAGE sql STRICT
1078
    AS $_$
1079
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1
1080
||util._if($2, $$ CASCADE$$, ''::text))
1081
$_$;
1082

    
1083

    
1084
--
1085
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1086
--
1087

    
1088
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1089
idempotent
1090
';
1091

    
1092

    
1093
--
1094
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1095
--
1096

    
1097
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1098
    LANGUAGE sql STRICT
1099
    AS $_$
1100
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1
1101
||util._if($2, $$ CASCADE$$, ''::text))
1102
$_$;
1103

    
1104

    
1105
--
1106
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1107
--
1108

    
1109
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1110
idempotent
1111
';
1112

    
1113

    
1114
--
1115
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117

    
1118
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1119
    LANGUAGE sql IMMUTABLE
1120
    AS $_$
1121
SELECT util.array_fill($1, 0)
1122
$_$;
1123

    
1124

    
1125
--
1126
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1127
--
1128

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

    
1133

    
1134
--
1135
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1136
--
1137

    
1138
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1139
    LANGUAGE sql IMMUTABLE
1140
    AS $_$
1141
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1142
$_$;
1143

    
1144

    
1145
--
1146
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1147
--
1148

    
1149
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1150
    LANGUAGE sql IMMUTABLE
1151
    AS $_$
1152
SELECT regexp_replace($2, '("?)$', $1||'\1')
1153
$_$;
1154

    
1155

    
1156
--
1157
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1158
--
1159

    
1160
CREATE FUNCTION eval(sql text) RETURNS void
1161
    LANGUAGE plpgsql STRICT
1162
    AS $$
1163
BEGIN
1164
	PERFORM util.debug_print_sql(sql);
1165
	EXECUTE sql;
1166
END;
1167
$$;
1168

    
1169

    
1170
--
1171
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1172
--
1173

    
1174
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1175
    LANGUAGE plpgsql
1176
    AS $$
1177
BEGIN
1178
	PERFORM util.debug_print_sql(sql);
1179
	RETURN QUERY EXECUTE sql;
1180
END;
1181
$$;
1182

    
1183

    
1184
--
1185
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1186
--
1187

    
1188
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1189
col_type_null (*required*): NULL::col_type
1190
';
1191

    
1192

    
1193
--
1194
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1195
--
1196

    
1197
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1198
    LANGUAGE plpgsql
1199
    AS $$
1200
BEGIN
1201
	PERFORM util.debug_print_sql(sql);
1202
	RETURN QUERY EXECUTE sql;
1203
END;
1204
$$;
1205

    
1206

    
1207
--
1208
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1209
--
1210

    
1211
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1212
    LANGUAGE plpgsql
1213
    AS $$
1214
BEGIN
1215
	PERFORM util.debug_print_sql(sql);
1216
	RETURN QUERY EXECUTE sql;
1217
END;
1218
$$;
1219

    
1220

    
1221
--
1222
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1223
--
1224

    
1225
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1226
ret_type_null: NULL::ret_type
1227
';
1228

    
1229

    
1230
--
1231
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1232
--
1233

    
1234
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1235
    LANGUAGE plpgsql
1236
    AS $$
1237
DECLARE
1238
	ret_val ret_type_null%TYPE;
1239
BEGIN
1240
	PERFORM util.debug_print_sql(sql);
1241
	EXECUTE sql INTO STRICT ret_val;
1242
	RETURN ret_val;
1243
END;
1244
$$;
1245

    
1246

    
1247
--
1248
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1249
--
1250

    
1251
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1252
ret_type_null: NULL::ret_type
1253
';
1254

    
1255

    
1256
--
1257
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1258
--
1259

    
1260
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1261
    LANGUAGE sql
1262
    AS $_$
1263
SELECT util.eval2val($$SELECT $$||$1, $2)
1264
$_$;
1265

    
1266

    
1267
--
1268
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1269
--
1270

    
1271
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1272
ret_type_null: NULL::ret_type
1273
';
1274

    
1275

    
1276
--
1277
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1278
--
1279

    
1280
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1281
    LANGUAGE sql
1282
    AS $_$
1283
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1284
$_$;
1285

    
1286

    
1287
--
1288
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1289
--
1290

    
1291
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1292
sql: can be NULL, which will be passed through
1293
ret_type_null: NULL::ret_type
1294
';
1295

    
1296

    
1297
--
1298
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1299
--
1300

    
1301
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1302
    LANGUAGE sql STABLE STRICT
1303
    AS $_$
1304
SELECT col_name
1305
FROM unnest($2) s (col_name)
1306
WHERE util.col_exists(($1, col_name))
1307
$_$;
1308

    
1309

    
1310
--
1311
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1312
--
1313

    
1314
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1315
    LANGUAGE sql
1316
    AS $_$
1317
SELECT util.eval2set($$EXPLAIN $$||$1)
1318
$_$;
1319

    
1320

    
1321
--
1322
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1323
--
1324

    
1325
CREATE FUNCTION explain2notice(sql text) RETURNS void
1326
    LANGUAGE plpgsql
1327
    AS $_$
1328
BEGIN
1329
	RAISE NOTICE '%', $$EXPLAIN:
1330
$$||util.explain2str(sql);
1331
END;
1332
$_$;
1333

    
1334

    
1335
--
1336
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1337
--
1338

    
1339
CREATE FUNCTION explain2str(sql text) RETURNS text
1340
    LANGUAGE sql
1341
    AS $_$
1342
SELECT util.join_strs(explain, $$
1343
$$) FROM util.explain($1)
1344
$_$;
1345

    
1346

    
1347
SET default_tablespace = '';
1348

    
1349
SET default_with_oids = false;
1350

    
1351
--
1352
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1353
--
1354

    
1355
CREATE TABLE explain (
1356
    line text NOT NULL
1357
);
1358

    
1359

    
1360
--
1361
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1362
--
1363

    
1364
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1365
    LANGUAGE sql
1366
    AS $_$
1367
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1368
$$||quote_nullable($1)||$$
1369
)$$)
1370
$_$;
1371

    
1372

    
1373
--
1374
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1375
--
1376

    
1377
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1378
usage:
1379
PERFORM util.explain2table($$
1380
query
1381
$$);
1382
';
1383

    
1384

    
1385
--
1386
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1387
--
1388

    
1389
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1390
    LANGUAGE sql IMMUTABLE
1391
    AS $_$
1392
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1393
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1394
) END
1395
$_$;
1396

    
1397

    
1398
--
1399
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1400
--
1401

    
1402
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1403
ensures that an array will always have proper non-NULL dimensions
1404
';
1405

    
1406

    
1407
--
1408
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1409
--
1410

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

    
1431

    
1432
--
1433
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1434
--
1435

    
1436
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1437
idempotent
1438

    
1439
users: not necessary to provide this because it will be autopopulated
1440
';
1441

    
1442

    
1443
--
1444
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1445
--
1446

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

    
1467

    
1468
--
1469
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1470
--
1471

    
1472
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1473
idempotent
1474
';
1475

    
1476

    
1477
--
1478
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1479
--
1480

    
1481
CREATE FUNCTION grants_users() RETURNS SETOF text
1482
    LANGUAGE sql IMMUTABLE
1483
    AS $$
1484
VALUES ('bien_read'), ('public_')
1485
$$;
1486

    
1487

    
1488
--
1489
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1490
--
1491

    
1492
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1493
    LANGUAGE sql IMMUTABLE
1494
    AS $_$
1495
SELECT substring($2 for length($1)) = $1
1496
$_$;
1497

    
1498

    
1499
--
1500
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1501
--
1502

    
1503
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1504
    LANGUAGE sql STABLE
1505
    AS $_$
1506
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1507
$_$;
1508

    
1509

    
1510
--
1511
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1512
--
1513

    
1514
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1515
    LANGUAGE sql IMMUTABLE
1516
    AS $_$
1517
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1518
$_$;
1519

    
1520

    
1521
--
1522
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1523
--
1524

    
1525
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1526
avoids repeating the same value for each key
1527
';
1528

    
1529

    
1530
--
1531
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1532
--
1533

    
1534
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1535
    LANGUAGE sql IMMUTABLE
1536
    AS $_$
1537
SELECT COALESCE($1, $2)
1538
$_$;
1539

    
1540

    
1541
--
1542
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1543
--
1544

    
1545
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1546
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1547
';
1548

    
1549

    
1550
--
1551
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1552
--
1553

    
1554
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1555
    LANGUAGE sql
1556
    AS $_$
1557
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1558
$_$;
1559

    
1560

    
1561
--
1562
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1563
--
1564

    
1565
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1566
    LANGUAGE sql STABLE STRICT
1567
    AS $_$
1568
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1569
$_$;
1570

    
1571

    
1572
--
1573
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1574
--
1575

    
1576
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1577
    LANGUAGE sql IMMUTABLE
1578
    AS $_$
1579
SELECT util.array_length($1) = 0
1580
$_$;
1581

    
1582

    
1583
--
1584
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1585
--
1586

    
1587
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1588
    LANGUAGE sql IMMUTABLE
1589
    AS $_$
1590
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1591
$_$;
1592

    
1593

    
1594
--
1595
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1596
--
1597

    
1598
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1599
    LANGUAGE sql IMMUTABLE
1600
    AS $_$
1601
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1602
$_$;
1603

    
1604

    
1605
--
1606
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1607
--
1608

    
1609
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1610
    LANGUAGE sql STABLE
1611
    AS $_$
1612
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1613
$_$;
1614

    
1615

    
1616
--
1617
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1618
--
1619

    
1620
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1621
    LANGUAGE sql STABLE
1622
    AS $_$
1623
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1624
$_$;
1625

    
1626

    
1627
--
1628
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1629
--
1630

    
1631
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1632
    LANGUAGE sql IMMUTABLE STRICT
1633
    AS $_$
1634
SELECT $1 || $3 || $2
1635
$_$;
1636

    
1637

    
1638
--
1639
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1640
--
1641

    
1642
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1643
    LANGUAGE sql IMMUTABLE
1644
    AS $_$
1645
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1646
$_$;
1647

    
1648

    
1649
--
1650
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1651
--
1652

    
1653
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1654
    LANGUAGE sql IMMUTABLE
1655
    AS $_$
1656
SELECT ltrim($1, $$
1657
$$)
1658
$_$;
1659

    
1660

    
1661
--
1662
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1663
--
1664

    
1665
CREATE FUNCTION map_filter_insert() RETURNS trigger
1666
    LANGUAGE plpgsql
1667
    AS $$
1668
BEGIN
1669
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1670
	RETURN new;
1671
END;
1672
$$;
1673

    
1674

    
1675
--
1676
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1677
--
1678

    
1679
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1680
    LANGUAGE plpgsql STABLE STRICT
1681
    AS $_$
1682
DECLARE
1683
    value text;
1684
BEGIN
1685
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1686
        INTO value USING key;
1687
    RETURN value;
1688
END;
1689
$_$;
1690

    
1691

    
1692
--
1693
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1694
--
1695

    
1696
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1697
    LANGUAGE sql IMMUTABLE
1698
    AS $_$
1699
SELECT util._map(util.nulls_map($1), $2)
1700
$_$;
1701

    
1702

    
1703
--
1704
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1705
--
1706

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

    
1710
[1] inlining of function calls, which is different from constant folding
1711
[2] _map()''s profiling query
1712
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1713
and map_nulls()''s profiling query
1714
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1715
both take ~920 ms.
1716
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.
1717
';
1718

    
1719

    
1720
--
1721
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1722
--
1723

    
1724
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1725
    LANGUAGE plpgsql STABLE STRICT
1726
    AS $_$
1727
BEGIN
1728
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1729
END;
1730
$_$;
1731

    
1732

    
1733
--
1734
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1735
--
1736

    
1737
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1738
    LANGUAGE sql
1739
    AS $_$
1740
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1741
$$||util.ltrim_nl($2));
1742
-- make sure the created table has the correct estimated row count
1743
SELECT util.analyze_($1);
1744
$_$;
1745

    
1746

    
1747
--
1748
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1749
--
1750

    
1751
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1752
idempotent
1753
';
1754

    
1755

    
1756
--
1757
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1758
--
1759

    
1760
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1761
    LANGUAGE sql
1762
    AS $_$
1763
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1764
$_$;
1765

    
1766

    
1767
--
1768
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1769
--
1770

    
1771
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1772
idempotent
1773
';
1774

    
1775

    
1776
--
1777
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779

    
1780
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1781
    LANGUAGE sql STRICT
1782
    AS $_$
1783
SELECT util.create_if_not_exists($$
1784
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1785
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1786
||quote_literal($2)||$$;
1787
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1788
constant
1789
';
1790
$$)
1791
$_$;
1792

    
1793

    
1794
--
1795
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1796
--
1797

    
1798
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1799
idempotent
1800
';
1801

    
1802

    
1803
--
1804
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1805
--
1806

    
1807
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1808
    LANGUAGE plpgsql STRICT
1809
    AS $_$
1810
DECLARE
1811
    type regtype = util.typeof(expr, col.table_::text::regtype);
1812
    col_name_sql text = quote_ident(col.name);
1813
BEGIN
1814
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1815
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1816
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1817
$$||expr||$$;
1818
$$);
1819
END;
1820
$_$;
1821

    
1822

    
1823
--
1824
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1825
--
1826

    
1827
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1828
idempotent
1829
';
1830

    
1831

    
1832
--
1833
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1834
--
1835

    
1836
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1837
    LANGUAGE sql STRICT
1838
    AS $_$
1839
SELECT util.create_if_not_exists($$
1840
CREATE TABLE $$||$1||$$
1841
(
1842
    LIKE util.map INCLUDING ALL
1843
);
1844

    
1845
CREATE TRIGGER map_filter_insert
1846
  BEFORE INSERT
1847
  ON $$||$1||$$
1848
  FOR EACH ROW
1849
  EXECUTE PROCEDURE util.map_filter_insert();
1850
$$)
1851
$_$;
1852

    
1853

    
1854
--
1855
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1856
--
1857

    
1858
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1859
    LANGUAGE sql IMMUTABLE
1860
    AS $_$
1861
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1862
$_$;
1863

    
1864

    
1865
--
1866
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1867
--
1868

    
1869
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1870
    LANGUAGE sql IMMUTABLE
1871
    AS $_$
1872
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1873
$_$;
1874

    
1875

    
1876
--
1877
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1878
--
1879

    
1880
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1881
usage:
1882
for *1* schema arg:
1883
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1884
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1885
';
1886

    
1887

    
1888
--
1889
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1890
--
1891

    
1892
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1893
    LANGUAGE sql IMMUTABLE
1894
    AS $_$
1895
SELECT $$SET LOCAL search_path TO $$||$1
1896
$_$;
1897

    
1898

    
1899
--
1900
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1901
--
1902

    
1903
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1904
    LANGUAGE sql STRICT
1905
    AS $_$
1906
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1907
$_$;
1908

    
1909

    
1910
--
1911
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1912
--
1913

    
1914
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1915
idempotent
1916
';
1917

    
1918

    
1919
--
1920
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1921
--
1922

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

    
1946

    
1947
--
1948
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1949
--
1950

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

    
1990

    
1991
--
1992
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1993
--
1994

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

    
2023

    
2024
--
2025
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2026
--
2027

    
2028
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2029
creates subset function which turns off enable_sort
2030
';
2031

    
2032

    
2033
--
2034
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2035
--
2036

    
2037
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2038
    LANGUAGE sql IMMUTABLE
2039
    AS $_$
2040
SELECT util.mk_set_search_path(util.schema_esc($1))
2041
$_$;
2042

    
2043

    
2044
--
2045
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2046
--
2047

    
2048
CREATE FUNCTION name(table_ regclass) RETURNS text
2049
    LANGUAGE sql STABLE
2050
    AS $_$
2051
SELECT relname::text FROM pg_class WHERE oid = $1
2052
$_$;
2053

    
2054

    
2055
--
2056
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2057
--
2058

    
2059
CREATE FUNCTION name(type regtype) RETURNS text
2060
    LANGUAGE sql STABLE STRICT
2061
    AS $_$
2062
SELECT typname::text FROM pg_type WHERE oid = $1
2063
$_$;
2064

    
2065

    
2066
--
2067
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2068
--
2069

    
2070
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2071
    LANGUAGE sql IMMUTABLE
2072
    AS $_$
2073
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2074
$_$;
2075

    
2076

    
2077
--
2078
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2079
--
2080

    
2081
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2082
    LANGUAGE sql IMMUTABLE
2083
    AS $_$
2084
SELECT $1 IS NOT NULL
2085
$_$;
2086

    
2087

    
2088
--
2089
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2090
--
2091

    
2092
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2093
    LANGUAGE sql IMMUTABLE
2094
    AS $_$
2095
SELECT util.hstore($1, NULL) || '*=>*'
2096
$_$;
2097

    
2098

    
2099
--
2100
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2101
--
2102

    
2103
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2104
for use with _map()
2105
';
2106

    
2107

    
2108
--
2109
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2110
--
2111

    
2112
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2113
    LANGUAGE sql IMMUTABLE
2114
    AS $_$
2115
SELECT $2 + COALESCE($1, 0)
2116
$_$;
2117

    
2118

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

    
2123
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2124
    LANGUAGE sql IMMUTABLE
2125
    AS $_$
2126
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2127
$_$;
2128

    
2129

    
2130
--
2131
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2132
--
2133

    
2134
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2135
    LANGUAGE sql STABLE STRICT
2136
    SET search_path TO pg_temp
2137
    AS $_$
2138
SELECT $1::text
2139
$_$;
2140

    
2141

    
2142
--
2143
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2144
--
2145

    
2146
CREATE FUNCTION qual_name(type regtype) RETURNS text
2147
    LANGUAGE sql STABLE STRICT
2148
    SET search_path TO pg_temp
2149
    AS $_$
2150
SELECT $1::text
2151
$_$;
2152

    
2153

    
2154
--
2155
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2156
--
2157

    
2158
COMMENT ON FUNCTION qual_name(type regtype) IS '
2159
a type''s schema-qualified name
2160
';
2161

    
2162

    
2163
--
2164
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2165
--
2166

    
2167
CREATE FUNCTION qual_name(type unknown) RETURNS text
2168
    LANGUAGE sql STABLE STRICT
2169
    AS $_$
2170
SELECT util.qual_name($1::text::regtype)
2171
$_$;
2172

    
2173

    
2174
--
2175
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2176
--
2177

    
2178
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2179
    LANGUAGE sql IMMUTABLE STRICT
2180
    AS $_$
2181
SELECT util.raise_notice('ERROR:  '||$1)
2182
$_$;
2183

    
2184

    
2185
--
2186
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2187
--
2188

    
2189
CREATE FUNCTION raise_notice(msg text) RETURNS void
2190
    LANGUAGE plpgsql IMMUTABLE STRICT
2191
    AS $$
2192
BEGIN
2193
	RAISE NOTICE '%', msg;
2194
END;
2195
$$;
2196

    
2197

    
2198
--
2199
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2200
--
2201

    
2202
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2203
    LANGUAGE plpgsql IMMUTABLE STRICT
2204
    AS $$
2205
BEGIN
2206
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2207
END;
2208
$$;
2209

    
2210

    
2211
--
2212
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2213
--
2214

    
2215
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2216
    LANGUAGE sql IMMUTABLE
2217
    AS $_$
2218
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2219
$_$;
2220

    
2221

    
2222
--
2223
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2224
--
2225

    
2226
CREATE FUNCTION regexp_quote(str text) RETURNS text
2227
    LANGUAGE sql IMMUTABLE
2228
    AS $_$
2229
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2230
$_$;
2231

    
2232

    
2233
--
2234
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2235
--
2236

    
2237
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2238
    LANGUAGE sql IMMUTABLE
2239
    AS $_$
2240
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2241
$_$;
2242

    
2243

    
2244
--
2245
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2246
--
2247

    
2248
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2249
    LANGUAGE sql STABLE
2250
    AS $_$
2251
SELECT relkind FROM pg_class WHERE oid = $1
2252
$_$;
2253

    
2254

    
2255
--
2256
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2257
--
2258

    
2259
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2260
    LANGUAGE sql
2261
    AS $_$
2262
/* can't have in_table/out_table inherit from *each other*, because inheritance
2263
also causes the rows of the parent table to be included in the child table.
2264
instead, they need to inherit from a common, empty table. */
2265
SELECT util.drop_table($4, force := true);
2266
SELECT util.copy_struct($2, $4);
2267
SELECT util.inherit($2, $4);
2268
SELECT util.inherit($3, $4);
2269

    
2270
SELECT util.rematerialize_query($1, $$
2271
SELECT * FROM util.diff(
2272
  $$||quote_nullable($2)||$$::regclass
2273
, $$||quote_nullable($3)||$$::regclass
2274
, NULL::$$||$4||$$)
2275
$$);
2276

    
2277
/* the table unfortunately cannot be *materialized* in human-readable form,
2278
because this would create column name collisions between the two sides */
2279
SELECT util.set_comment($1, '
2280
to view this table in human-readable form (with each side''s tuple column
2281
expanded to its component fields):
2282
SELECT (left_).*, (right_).* FROM '||$1||';
2283
');
2284
$_$;
2285

    
2286

    
2287
--
2288
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2289
--
2290

    
2291
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2292
type_table (*required*): table to create as the shared base type
2293
';
2294

    
2295

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

    
2300
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2301
    LANGUAGE sql
2302
    AS $_$
2303
SELECT util.drop_table($1);
2304
SELECT util.materialize_query($1, $2);
2305
$_$;
2306

    
2307

    
2308
--
2309
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2310
--
2311

    
2312
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2313
idempotent, but repeats action each time
2314
';
2315

    
2316

    
2317
--
2318
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2319
--
2320

    
2321
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2322
    LANGUAGE sql
2323
    AS $_$
2324
SELECT util.drop_table($1);
2325
SELECT util.materialize_view($1, $2);
2326
$_$;
2327

    
2328

    
2329
--
2330
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2331
--
2332

    
2333
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2334
idempotent, but repeats action each time
2335
';
2336

    
2337

    
2338
--
2339
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2340
--
2341

    
2342
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2343
    LANGUAGE sql STRICT
2344
    AS $_$
2345
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2346
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2347
FROM util.col_names($1::text::regtype) f (name);
2348
SELECT NULL::void; -- don't fold away functions called in previous query
2349
$_$;
2350

    
2351

    
2352
--
2353
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2354
--
2355

    
2356
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2357
idempotent
2358
';
2359

    
2360

    
2361
--
2362
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2363
--
2364

    
2365
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2366
    LANGUAGE sql STRICT
2367
    AS $_$
2368
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2369
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2370
SELECT util.set_col_names($1, $2);
2371
$_$;
2372

    
2373

    
2374
--
2375
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2376
--
2377

    
2378
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2379
idempotent.
2380
alters the names table, so it will need to be repopulated after running this function.
2381
';
2382

    
2383

    
2384
--
2385
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2386
--
2387

    
2388
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2389
    LANGUAGE sql STRICT
2390
    AS $_$
2391
SELECT util.drop_table($1);
2392
SELECT util.mk_map_table($1);
2393
$_$;
2394

    
2395

    
2396
--
2397
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2398
--
2399

    
2400
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2401
    LANGUAGE plpgsql STRICT
2402
    AS $_$
2403
DECLARE
2404
	result text = NULL;
2405
BEGIN
2406
	BEGIN
2407
		result = util.show_create_view(view_);
2408
		PERFORM util.eval($$DROP VIEW $$||view_);
2409
	EXCEPTION
2410
		WHEN undefined_table THEN NULL;
2411
	END;
2412
	RETURN result;
2413
END;
2414
$_$;
2415

    
2416

    
2417
--
2418
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2419
--
2420

    
2421
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2422
    LANGUAGE sql
2423
    AS $_$
2424
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2425
$_$;
2426

    
2427

    
2428
--
2429
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2430
--
2431

    
2432
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2433
    LANGUAGE sql STABLE
2434
    AS $_$
2435
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2436
$_$;
2437

    
2438

    
2439
--
2440
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2441
--
2442

    
2443
CREATE FUNCTION schema(table_ regclass) RETURNS text
2444
    LANGUAGE sql STABLE
2445
    AS $_$
2446
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2447
$_$;
2448

    
2449

    
2450
--
2451
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2452
--
2453

    
2454
CREATE FUNCTION schema(type regtype) RETURNS text
2455
    LANGUAGE sql STABLE
2456
    AS $_$
2457
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2458
$_$;
2459

    
2460

    
2461
--
2462
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2463
--
2464

    
2465
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2466
    LANGUAGE sql STABLE
2467
    AS $_$
2468
SELECT util.schema(pg_typeof($1))
2469
$_$;
2470

    
2471

    
2472
--
2473
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2474
--
2475

    
2476
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2477
    LANGUAGE sql STABLE
2478
    AS $_$
2479
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2480
$_$;
2481

    
2482

    
2483
--
2484
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2485
--
2486

    
2487
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2488
a schema bundle is a group of schemas with a common prefix
2489
';
2490

    
2491

    
2492
--
2493
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2494
--
2495

    
2496
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2497
    LANGUAGE sql
2498
    AS $_$
2499
SELECT util.schema_rename(old_schema,
2500
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2501
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2502
SELECT NULL::void; -- don't fold away functions called in previous query
2503
$_$;
2504

    
2505

    
2506
--
2507
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2508
--
2509

    
2510
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2511
    LANGUAGE plpgsql
2512
    AS $$
2513
BEGIN
2514
	-- don't schema_bundle_rm() the schema_bundle to keep!
2515
	IF replace = with_ THEN RETURN; END IF;
2516
	
2517
	PERFORM util.schema_bundle_rm(replace);
2518
	PERFORM util.schema_bundle_rename(with_, replace);
2519
END;
2520
$$;
2521

    
2522

    
2523
--
2524
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2525
--
2526

    
2527
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2528
    LANGUAGE sql
2529
    AS $_$
2530
SELECT util.schema_rm(schema)
2531
FROM util.schema_bundle_get_schemas($1) f (schema);
2532
SELECT NULL::void; -- don't fold away functions called in previous query
2533
$_$;
2534

    
2535

    
2536
--
2537
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2538
--
2539

    
2540
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2541
    LANGUAGE sql STABLE
2542
    AS $_$
2543
SELECT quote_ident(util.schema($1))
2544
$_$;
2545

    
2546

    
2547
--
2548
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2549
--
2550

    
2551
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2552
    LANGUAGE sql IMMUTABLE
2553
    AS $_$
2554
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2555
$_$;
2556

    
2557

    
2558
--
2559
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2560
--
2561

    
2562
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2563
    LANGUAGE sql STABLE
2564
    AS $_$
2565
SELECT oid FROM pg_namespace WHERE nspname = $1
2566
$_$;
2567

    
2568

    
2569
--
2570
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2571
--
2572

    
2573
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2574
    LANGUAGE sql
2575
    AS $_$
2576
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2577
$_$;
2578

    
2579

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

    
2584
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2585
    LANGUAGE plpgsql
2586
    AS $$
2587
BEGIN
2588
	-- don't schema_rm() the schema to keep!
2589
	IF replace = with_ THEN RETURN; END IF;
2590
	
2591
	PERFORM util.schema_rm(replace);
2592
	PERFORM util.schema_rename(with_, replace);
2593
END;
2594
$$;
2595

    
2596

    
2597
--
2598
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2599
--
2600

    
2601
CREATE FUNCTION schema_rm(schema text) RETURNS void
2602
    LANGUAGE sql
2603
    AS $_$
2604
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2605
$_$;
2606

    
2607

    
2608
--
2609
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2610
--
2611

    
2612
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2613
    LANGUAGE sql STRICT
2614
    AS $_$
2615
SELECT util.eval(
2616
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2617
$_$;
2618

    
2619

    
2620
--
2621
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2622
--
2623

    
2624
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2625
    LANGUAGE plpgsql STRICT
2626
    AS $_$
2627
DECLARE
2628
    old text[] = ARRAY(SELECT util.col_names(table_));
2629
    new text[] = ARRAY(SELECT util.map_values(names));
2630
BEGIN
2631
    old = old[1:array_length(new, 1)]; -- truncate to same length
2632
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2633
||$$ TO $$||quote_ident(value))
2634
    FROM each(hstore(old, new))
2635
    WHERE value != key -- not same name
2636
    ;
2637
END;
2638
$_$;
2639

    
2640

    
2641
--
2642
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2643
--
2644

    
2645
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2646
idempotent
2647
';
2648

    
2649

    
2650
--
2651
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2652
--
2653

    
2654
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2655
    LANGUAGE plpgsql STRICT
2656
    AS $_$
2657
DECLARE
2658
	row_ util.map;
2659
BEGIN
2660
	-- rename any metadata cols rather than re-adding them with new names
2661
	BEGIN
2662
		PERFORM util.set_col_names(table_, names);
2663
	EXCEPTION
2664
		WHEN array_subscript_error THEN -- selective suppress
2665
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2666
				-- metadata cols not yet added
2667
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2668
			END IF;
2669
	END;
2670
	
2671
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2672
	LOOP
2673
		PERFORM util.mk_const_col((table_, row_."to"),
2674
			substring(row_."from" from 2));
2675
	END LOOP;
2676
	
2677
	PERFORM util.set_col_names(table_, names);
2678
END;
2679
$_$;
2680

    
2681

    
2682
--
2683
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2684
--
2685

    
2686
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2687
idempotent.
2688
the metadata mappings must be *last* in the names table.
2689
';
2690

    
2691

    
2692
--
2693
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2694
--
2695

    
2696
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2697
    LANGUAGE plpgsql STRICT
2698
    AS $_$
2699
DECLARE
2700
    sql text = $$ALTER TABLE $$||table_||$$
2701
$$||NULLIF(array_to_string(ARRAY(
2702
    SELECT
2703
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2704
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2705
    FROM
2706
    (
2707
        SELECT
2708
          quote_ident(col_name) AS col_name_sql
2709
        , util.col_type((table_, col_name)) AS curr_type
2710
        , type AS target_type
2711
        FROM unnest(col_casts)
2712
    ) s
2713
    WHERE curr_type != target_type
2714
), '
2715
, '), '');
2716
BEGIN
2717
    PERFORM util.debug_print_sql(sql);
2718
    EXECUTE COALESCE(sql, '');
2719
END;
2720
$_$;
2721

    
2722

    
2723
--
2724
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2725
--
2726

    
2727
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2728
idempotent
2729
';
2730

    
2731

    
2732
--
2733
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2734
--
2735

    
2736
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2737
    LANGUAGE sql STRICT
2738
    AS $_$
2739
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2740
$_$;
2741

    
2742

    
2743
--
2744
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2745
--
2746

    
2747
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2748
    LANGUAGE sql STABLE
2749
    AS $_$
2750
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2751
$$||util.show_grants_for($1)
2752
$_$;
2753

    
2754

    
2755
--
2756
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2757
--
2758

    
2759
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2760
    LANGUAGE sql STABLE
2761
    AS $_$
2762
SELECT string_agg(cmd, '')
2763
FROM
2764
(
2765
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2766
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2767
$$ ELSE '' END) AS cmd
2768
	FROM util.grants_users() f (user_)
2769
) s
2770
$_$;
2771

    
2772

    
2773
--
2774
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2775
--
2776

    
2777
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2778
    LANGUAGE sql STABLE
2779
    AS $_$
2780
SELECT oid FROM pg_class
2781
WHERE relkind = ANY($3) AND relname ~ $1
2782
AND util.schema_matches(util.schema(relnamespace), $2)
2783
ORDER BY relname
2784
$_$;
2785

    
2786

    
2787
--
2788
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
2789
--
2790

    
2791
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2792
    LANGUAGE sql STABLE
2793
    AS $_$
2794
SELECT view_
2795
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2796
WHERE util.schema(view_) = $2
2797
$_$;
2798

    
2799

    
2800
--
2801
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2802
--
2803

    
2804
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2805
    LANGUAGE plpgsql STABLE STRICT
2806
    AS $_$
2807
DECLARE
2808
    hstore hstore;
2809
BEGIN
2810
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2811
        table_||$$))$$ INTO STRICT hstore;
2812
    RETURN hstore;
2813
END;
2814
$_$;
2815

    
2816

    
2817
--
2818
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2819
--
2820

    
2821
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2822
    LANGUAGE sql STABLE STRICT
2823
    AS $_$
2824
SELECT COUNT(*) > 0 FROM pg_constraint
2825
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2826
$_$;
2827

    
2828

    
2829
--
2830
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2831
--
2832

    
2833
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2834
gets whether a status flag is set by the presence of a table constraint
2835
';
2836

    
2837

    
2838
--
2839
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2840
--
2841

    
2842
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2843
    LANGUAGE sql STRICT
2844
    AS $_$
2845
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2846
||quote_ident($2)||$$ CHECK (true)$$)
2847
$_$;
2848

    
2849

    
2850
--
2851
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2852
--
2853

    
2854
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2855
stores a status flag by the presence of a table constraint.
2856
idempotent.
2857
';
2858

    
2859

    
2860
--
2861
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2862
--
2863

    
2864
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2865
    LANGUAGE sql STABLE STRICT
2866
    AS $_$
2867
SELECT util.table_flag__get($1, 'nulls_mapped')
2868
$_$;
2869

    
2870

    
2871
--
2872
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2873
--
2874

    
2875
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2876
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2877
';
2878

    
2879

    
2880
--
2881
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2882
--
2883

    
2884
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2885
    LANGUAGE sql STRICT
2886
    AS $_$
2887
SELECT util.table_flag__set($1, 'nulls_mapped')
2888
$_$;
2889

    
2890

    
2891
--
2892
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2893
--
2894

    
2895
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2896
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2897
idempotent.
2898
';
2899

    
2900

    
2901
--
2902
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2903
--
2904

    
2905
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2906
    LANGUAGE plpgsql STRICT
2907
    AS $_$
2908
DECLARE
2909
    row record;
2910
BEGIN
2911
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2912
    LOOP
2913
        IF row.global_name != row.name THEN
2914
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2915
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2916
        END IF;
2917
    END LOOP;
2918
END;
2919
$_$;
2920

    
2921

    
2922
--
2923
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2924
--
2925

    
2926
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2927
idempotent
2928
';
2929

    
2930

    
2931
--
2932
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2933
--
2934

    
2935
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2936
    LANGUAGE sql STRICT
2937
    AS $_$
2938
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2939
SELECT NULL::void; -- don't fold away functions called in previous query
2940
$_$;
2941

    
2942

    
2943
--
2944
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2945
--
2946

    
2947
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2948
trims table_ to include only columns in the original data.
2949
idempotent.
2950
';
2951

    
2952

    
2953
--
2954
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2955
--
2956

    
2957
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2958
    LANGUAGE plpgsql STRICT
2959
    AS $_$
2960
BEGIN
2961
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2962
END;
2963
$_$;
2964

    
2965

    
2966
--
2967
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2968
--
2969

    
2970
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2971
idempotent
2972
';
2973

    
2974

    
2975
--
2976
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2977
--
2978

    
2979
CREATE FUNCTION try_create(sql text) RETURNS void
2980
    LANGUAGE plpgsql STRICT
2981
    AS $$
2982
BEGIN
2983
    PERFORM util.eval(sql);
2984
EXCEPTION
2985
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2986
    WHEN undefined_column THEN NULL;
2987
    WHEN duplicate_column THEN NULL;
2988
END;
2989
$$;
2990

    
2991

    
2992
--
2993
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2994
--
2995

    
2996
COMMENT ON FUNCTION try_create(sql text) IS '
2997
idempotent
2998
';
2999

    
3000

    
3001
--
3002
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3003
--
3004

    
3005
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3006
    LANGUAGE sql STRICT
3007
    AS $_$
3008
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3009
$_$;
3010

    
3011

    
3012
--
3013
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3014
--
3015

    
3016
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3017
idempotent
3018
';
3019

    
3020

    
3021
--
3022
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3023
--
3024

    
3025
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3026
    LANGUAGE sql IMMUTABLE
3027
    AS $_$
3028
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3029
$_$;
3030

    
3031

    
3032
--
3033
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3034
--
3035

    
3036
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3037
a type''s NOT NULL qualifier
3038
';
3039

    
3040

    
3041
--
3042
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3043
--
3044

    
3045
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3046
    LANGUAGE plpgsql STABLE
3047
    AS $_$
3048
DECLARE
3049
    type regtype;
3050
BEGIN
3051
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3052
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3053
    RETURN type;
3054
END;
3055
$_$;
3056

    
3057

    
3058
--
3059
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3060
--
3061

    
3062
CREATE AGGREGATE all_same(anyelement) (
3063
    SFUNC = all_same_transform,
3064
    STYPE = anyarray,
3065
    FINALFUNC = all_same_final
3066
);
3067

    
3068

    
3069
--
3070
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3071
--
3072

    
3073
COMMENT ON AGGREGATE all_same(anyelement) IS '
3074
includes NULLs in comparison
3075
';
3076

    
3077

    
3078
--
3079
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3080
--
3081

    
3082
CREATE AGGREGATE join_strs(text, text) (
3083
    SFUNC = join_strs_transform,
3084
    STYPE = text
3085
);
3086

    
3087

    
3088
--
3089
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3090
--
3091

    
3092
CREATE OPERATOR -> (
3093
    PROCEDURE = map_get,
3094
    LEFTARG = regclass,
3095
    RIGHTARG = text
3096
);
3097

    
3098

    
3099
--
3100
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3101
--
3102

    
3103
CREATE OPERATOR => (
3104
    PROCEDURE = hstore,
3105
    LEFTARG = text[],
3106
    RIGHTARG = text
3107
);
3108

    
3109

    
3110
--
3111
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3112
--
3113

    
3114
COMMENT ON OPERATOR => (text[], text) IS '
3115
usage: array[''key1'', ...]::text[] => ''value''
3116
';
3117

    
3118

    
3119
--
3120
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3121
--
3122

    
3123
CREATE OPERATOR ?*>= (
3124
    PROCEDURE = is_populated_more_often_than,
3125
    LEFTARG = anyelement,
3126
    RIGHTARG = anyelement
3127
);
3128

    
3129

    
3130
--
3131
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3132
--
3133

    
3134
CREATE OPERATOR ?>= (
3135
    PROCEDURE = is_more_complete_than,
3136
    LEFTARG = anyelement,
3137
    RIGHTARG = anyelement
3138
);
3139

    
3140

    
3141
--
3142
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3143
--
3144

    
3145
CREATE OPERATOR ||% (
3146
    PROCEDURE = concat_esc,
3147
    LEFTARG = text,
3148
    RIGHTARG = text
3149
);
3150

    
3151

    
3152
--
3153
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3154
--
3155

    
3156
COMMENT ON OPERATOR ||% (text, text) IS '
3157
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3158
';
3159

    
3160

    
3161
--
3162
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3163
--
3164

    
3165
CREATE TABLE map (
3166
    "from" text NOT NULL,
3167
    "to" text,
3168
    filter text,
3169
    notes text
3170
);
3171

    
3172

    
3173
--
3174
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3175
--
3176

    
3177

    
3178

    
3179
--
3180
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3181
--
3182

    
3183

    
3184

    
3185
--
3186
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3187
--
3188

    
3189
ALTER TABLE ONLY map
3190
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3191

    
3192

    
3193
--
3194
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3195
--
3196

    
3197
ALTER TABLE ONLY map
3198
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3199

    
3200

    
3201
--
3202
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3203
--
3204

    
3205
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3206

    
3207

    
3208
--
3209
-- PostgreSQL database dump complete
3210
--
3211

    
(19-19/29)