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 util.drop_relation(util.relation_type($1), $1::text, $2)
1056
$_$;
1057

    
1058

    
1059
--
1060
-- Name: FUNCTION drop_relation(relation regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
1061
--
1062

    
1063
COMMENT ON FUNCTION drop_relation(relation regclass, force boolean) IS '
1064
idempotent
1065
';
1066

    
1067

    
1068
--
1069
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1070
--
1071

    
1072
CREATE FUNCTION drop_relation(type text, relation text, force boolean DEFAULT false) RETURNS void
1073
    LANGUAGE sql
1074
    AS $_$
1075
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1076
||util._if($3, $$ CASCADE$$, ''::text))
1077
$_$;
1078

    
1079

    
1080
--
1081
-- Name: FUNCTION drop_relation(type text, relation text, force boolean); Type: COMMENT; Schema: util; Owner: -
1082
--
1083

    
1084
COMMENT ON FUNCTION drop_relation(type text, relation text, force boolean) IS '
1085
idempotent
1086
';
1087

    
1088

    
1089
--
1090
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1091
--
1092

    
1093
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1094
    LANGUAGE sql STRICT
1095
    AS $_$
1096
SELECT util.drop_relation('TABLE', $1, $2)
1097
$_$;
1098

    
1099

    
1100
--
1101
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1102
--
1103

    
1104
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1105
idempotent
1106
';
1107

    
1108

    
1109
--
1110
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1111
--
1112

    
1113
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1114
    LANGUAGE sql STRICT
1115
    AS $_$
1116
SELECT util.drop_relation('VIEW', $1, $2)
1117
$_$;
1118

    
1119

    
1120
--
1121
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1122
--
1123

    
1124
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1125
idempotent
1126
';
1127

    
1128

    
1129
--
1130
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1131
--
1132

    
1133
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1134
    LANGUAGE sql IMMUTABLE
1135
    AS $_$
1136
SELECT util.array_fill($1, 0)
1137
$_$;
1138

    
1139

    
1140
--
1141
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1142
--
1143

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

    
1148

    
1149
--
1150
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1151
--
1152

    
1153
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1154
    LANGUAGE sql IMMUTABLE
1155
    AS $_$
1156
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1157
$_$;
1158

    
1159

    
1160
--
1161
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1162
--
1163

    
1164
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1165
    LANGUAGE sql IMMUTABLE
1166
    AS $_$
1167
SELECT regexp_replace($2, '("?)$', $1||'\1')
1168
$_$;
1169

    
1170

    
1171
--
1172
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1173
--
1174

    
1175
CREATE FUNCTION eval(sql text) RETURNS void
1176
    LANGUAGE plpgsql STRICT
1177
    AS $$
1178
BEGIN
1179
	PERFORM util.debug_print_sql(sql);
1180
	EXECUTE sql;
1181
END;
1182
$$;
1183

    
1184

    
1185
--
1186
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1187
--
1188

    
1189
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1190
    LANGUAGE plpgsql
1191
    AS $$
1192
BEGIN
1193
	PERFORM util.debug_print_sql(sql);
1194
	RETURN QUERY EXECUTE sql;
1195
END;
1196
$$;
1197

    
1198

    
1199
--
1200
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1201
--
1202

    
1203
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1204
col_type_null (*required*): NULL::col_type
1205
';
1206

    
1207

    
1208
--
1209
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1210
--
1211

    
1212
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1213
    LANGUAGE plpgsql
1214
    AS $$
1215
BEGIN
1216
	PERFORM util.debug_print_sql(sql);
1217
	RETURN QUERY EXECUTE sql;
1218
END;
1219
$$;
1220

    
1221

    
1222
--
1223
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1224
--
1225

    
1226
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1227
    LANGUAGE plpgsql
1228
    AS $$
1229
BEGIN
1230
	PERFORM util.debug_print_sql(sql);
1231
	RETURN QUERY EXECUTE sql;
1232
END;
1233
$$;
1234

    
1235

    
1236
--
1237
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1238
--
1239

    
1240
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1241
ret_type_null: NULL::ret_type
1242
';
1243

    
1244

    
1245
--
1246
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1247
--
1248

    
1249
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1250
    LANGUAGE plpgsql
1251
    AS $$
1252
DECLARE
1253
	ret_val ret_type_null%TYPE;
1254
BEGIN
1255
	PERFORM util.debug_print_sql(sql);
1256
	EXECUTE sql INTO STRICT ret_val;
1257
	RETURN ret_val;
1258
END;
1259
$$;
1260

    
1261

    
1262
--
1263
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1264
--
1265

    
1266
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1267
ret_type_null: NULL::ret_type
1268
';
1269

    
1270

    
1271
--
1272
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1273
--
1274

    
1275
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1276
    LANGUAGE sql
1277
    AS $_$
1278
SELECT util.eval2val($$SELECT $$||$1, $2)
1279
$_$;
1280

    
1281

    
1282
--
1283
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1284
--
1285

    
1286
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1287
ret_type_null: NULL::ret_type
1288
';
1289

    
1290

    
1291
--
1292
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1293
--
1294

    
1295
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1296
    LANGUAGE sql
1297
    AS $_$
1298
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1299
$_$;
1300

    
1301

    
1302
--
1303
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1304
--
1305

    
1306
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1307
sql: can be NULL, which will be passed through
1308
ret_type_null: NULL::ret_type
1309
';
1310

    
1311

    
1312
--
1313
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1314
--
1315

    
1316
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1317
    LANGUAGE sql STABLE STRICT
1318
    AS $_$
1319
SELECT col_name
1320
FROM unnest($2) s (col_name)
1321
WHERE util.col_exists(($1, col_name))
1322
$_$;
1323

    
1324

    
1325
--
1326
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1327
--
1328

    
1329
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1330
    LANGUAGE sql
1331
    AS $_$
1332
SELECT util.eval2set($$EXPLAIN $$||$1)
1333
$_$;
1334

    
1335

    
1336
--
1337
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1338
--
1339

    
1340
CREATE FUNCTION explain2notice(sql text) RETURNS void
1341
    LANGUAGE plpgsql
1342
    AS $_$
1343
BEGIN
1344
	RAISE NOTICE '%', $$EXPLAIN:
1345
$$||util.explain2str(sql);
1346
END;
1347
$_$;
1348

    
1349

    
1350
--
1351
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1352
--
1353

    
1354
CREATE FUNCTION explain2str(sql text) RETURNS text
1355
    LANGUAGE sql
1356
    AS $_$
1357
SELECT util.join_strs(explain, $$
1358
$$) FROM util.explain($1)
1359
$_$;
1360

    
1361

    
1362
SET default_tablespace = '';
1363

    
1364
SET default_with_oids = false;
1365

    
1366
--
1367
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1368
--
1369

    
1370
CREATE TABLE explain (
1371
    line text NOT NULL
1372
);
1373

    
1374

    
1375
--
1376
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1377
--
1378

    
1379
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1380
    LANGUAGE sql
1381
    AS $_$
1382
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1383
$$||quote_nullable($1)||$$
1384
)$$)
1385
$_$;
1386

    
1387

    
1388
--
1389
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1390
--
1391

    
1392
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1393
usage:
1394
PERFORM util.explain2table($$
1395
query
1396
$$);
1397
';
1398

    
1399

    
1400
--
1401
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1402
--
1403

    
1404
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1405
    LANGUAGE sql IMMUTABLE
1406
    AS $_$
1407
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1408
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1409
) END
1410
$_$;
1411

    
1412

    
1413
--
1414
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1415
--
1416

    
1417
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1418
ensures that an array will always have proper non-NULL dimensions
1419
';
1420

    
1421

    
1422
--
1423
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1424
--
1425

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

    
1446

    
1447
--
1448
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1449
--
1450

    
1451
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1452
idempotent
1453

    
1454
users: not necessary to provide this because it will be autopopulated
1455
';
1456

    
1457

    
1458
--
1459
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1460
--
1461

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

    
1482

    
1483
--
1484
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1485
--
1486

    
1487
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1488
idempotent
1489
';
1490

    
1491

    
1492
--
1493
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1494
--
1495

    
1496
CREATE FUNCTION grants_users() RETURNS SETOF text
1497
    LANGUAGE sql IMMUTABLE
1498
    AS $$
1499
VALUES ('bien_read'), ('public_')
1500
$$;
1501

    
1502

    
1503
--
1504
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1505
--
1506

    
1507
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1508
    LANGUAGE sql IMMUTABLE
1509
    AS $_$
1510
SELECT substring($2 for length($1)) = $1
1511
$_$;
1512

    
1513

    
1514
--
1515
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1516
--
1517

    
1518
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1519
    LANGUAGE sql STABLE
1520
    AS $_$
1521
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1522
$_$;
1523

    
1524

    
1525
--
1526
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1527
--
1528

    
1529
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1530
    LANGUAGE sql IMMUTABLE
1531
    AS $_$
1532
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1533
$_$;
1534

    
1535

    
1536
--
1537
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1538
--
1539

    
1540
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1541
avoids repeating the same value for each key
1542
';
1543

    
1544

    
1545
--
1546
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1547
--
1548

    
1549
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1550
    LANGUAGE sql IMMUTABLE
1551
    AS $_$
1552
SELECT COALESCE($1, $2)
1553
$_$;
1554

    
1555

    
1556
--
1557
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1558
--
1559

    
1560
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1561
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1562
';
1563

    
1564

    
1565
--
1566
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1567
--
1568

    
1569
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1570
    LANGUAGE sql
1571
    AS $_$
1572
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1573
$_$;
1574

    
1575

    
1576
--
1577
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1578
--
1579

    
1580
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1581
    LANGUAGE sql STABLE STRICT
1582
    AS $_$
1583
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1584
$_$;
1585

    
1586

    
1587
--
1588
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1589
--
1590

    
1591
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1592
    LANGUAGE sql IMMUTABLE
1593
    AS $_$
1594
SELECT util.array_length($1) = 0
1595
$_$;
1596

    
1597

    
1598
--
1599
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1600
--
1601

    
1602
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1603
    LANGUAGE sql IMMUTABLE
1604
    AS $_$
1605
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1606
$_$;
1607

    
1608

    
1609
--
1610
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1611
--
1612

    
1613
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1614
    LANGUAGE sql IMMUTABLE
1615
    AS $_$
1616
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1617
$_$;
1618

    
1619

    
1620
--
1621
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1622
--
1623

    
1624
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1625
    LANGUAGE sql STABLE
1626
    AS $_$
1627
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1628
$_$;
1629

    
1630

    
1631
--
1632
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1633
--
1634

    
1635
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1636
    LANGUAGE sql STABLE
1637
    AS $_$
1638
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1639
$_$;
1640

    
1641

    
1642
--
1643
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1644
--
1645

    
1646
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1647
    LANGUAGE sql IMMUTABLE STRICT
1648
    AS $_$
1649
SELECT $1 || $3 || $2
1650
$_$;
1651

    
1652

    
1653
--
1654
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1655
--
1656

    
1657
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1658
    LANGUAGE sql IMMUTABLE
1659
    AS $_$
1660
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1661
$_$;
1662

    
1663

    
1664
--
1665
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1666
--
1667

    
1668
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1669
    LANGUAGE sql IMMUTABLE
1670
    AS $_$
1671
SELECT ltrim($1, $$
1672
$$)
1673
$_$;
1674

    
1675

    
1676
--
1677
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1678
--
1679

    
1680
CREATE FUNCTION map_filter_insert() RETURNS trigger
1681
    LANGUAGE plpgsql
1682
    AS $$
1683
BEGIN
1684
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1685
	RETURN new;
1686
END;
1687
$$;
1688

    
1689

    
1690
--
1691
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1692
--
1693

    
1694
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1695
    LANGUAGE plpgsql STABLE STRICT
1696
    AS $_$
1697
DECLARE
1698
    value text;
1699
BEGIN
1700
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1701
        INTO value USING key;
1702
    RETURN value;
1703
END;
1704
$_$;
1705

    
1706

    
1707
--
1708
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1709
--
1710

    
1711
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1712
    LANGUAGE sql IMMUTABLE
1713
    AS $_$
1714
SELECT util._map(util.nulls_map($1), $2)
1715
$_$;
1716

    
1717

    
1718
--
1719
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1720
--
1721

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

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

    
1734

    
1735
--
1736
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1737
--
1738

    
1739
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1740
    LANGUAGE plpgsql STABLE STRICT
1741
    AS $_$
1742
BEGIN
1743
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1744
END;
1745
$_$;
1746

    
1747

    
1748
--
1749
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1750
--
1751

    
1752
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1753
    LANGUAGE sql
1754
    AS $_$
1755
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1756
$$||util.ltrim_nl($2));
1757
-- make sure the created table has the correct estimated row count
1758
SELECT util.analyze_($1);
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1764
--
1765

    
1766
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1767
idempotent
1768
';
1769

    
1770

    
1771
--
1772
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1773
--
1774

    
1775
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1776
    LANGUAGE sql
1777
    AS $_$
1778
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1779
$_$;
1780

    
1781

    
1782
--
1783
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1784
--
1785

    
1786
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1787
idempotent
1788
';
1789

    
1790

    
1791
--
1792
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794

    
1795
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1796
    LANGUAGE sql STRICT
1797
    AS $_$
1798
SELECT util.create_if_not_exists($$
1799
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1800
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1801
||quote_literal($2)||$$;
1802
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1803
constant
1804
';
1805
$$)
1806
$_$;
1807

    
1808

    
1809
--
1810
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1811
--
1812

    
1813
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1814
idempotent
1815
';
1816

    
1817

    
1818
--
1819
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1820
--
1821

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

    
1837

    
1838
--
1839
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1840
--
1841

    
1842
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1843
idempotent
1844
';
1845

    
1846

    
1847
--
1848
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1849
--
1850

    
1851
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1852
    LANGUAGE sql STRICT
1853
    AS $_$
1854
SELECT util.create_if_not_exists($$
1855
CREATE TABLE $$||$1||$$
1856
(
1857
    LIKE util.map INCLUDING ALL
1858
);
1859

    
1860
CREATE TRIGGER map_filter_insert
1861
  BEFORE INSERT
1862
  ON $$||$1||$$
1863
  FOR EACH ROW
1864
  EXECUTE PROCEDURE util.map_filter_insert();
1865
$$)
1866
$_$;
1867

    
1868

    
1869
--
1870
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1871
--
1872

    
1873
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1874
    LANGUAGE sql IMMUTABLE
1875
    AS $_$
1876
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1877
$_$;
1878

    
1879

    
1880
--
1881
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1882
--
1883

    
1884
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1885
    LANGUAGE sql IMMUTABLE
1886
    AS $_$
1887
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1888
$_$;
1889

    
1890

    
1891
--
1892
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1893
--
1894

    
1895
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1896
usage:
1897
for *1* schema arg:
1898
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1899
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1900
';
1901

    
1902

    
1903
--
1904
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1905
--
1906

    
1907
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1908
    LANGUAGE sql IMMUTABLE
1909
    AS $_$
1910
SELECT $$SET LOCAL search_path TO $$||$1
1911
$_$;
1912

    
1913

    
1914
--
1915
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1916
--
1917

    
1918
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1919
    LANGUAGE sql STRICT
1920
    AS $_$
1921
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1922
$_$;
1923

    
1924

    
1925
--
1926
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1927
--
1928

    
1929
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1930
idempotent
1931
';
1932

    
1933

    
1934
--
1935
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1936
--
1937

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

    
1961

    
1962
--
1963
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1964
--
1965

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

    
2005

    
2006
--
2007
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2008
--
2009

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

    
2038

    
2039
--
2040
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2041
--
2042

    
2043
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2044
creates subset function which turns off enable_sort
2045
';
2046

    
2047

    
2048
--
2049
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2050
--
2051

    
2052
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2053
    LANGUAGE sql IMMUTABLE
2054
    AS $_$
2055
SELECT util.mk_set_search_path(util.schema_esc($1))
2056
$_$;
2057

    
2058

    
2059
--
2060
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2061
--
2062

    
2063
CREATE FUNCTION name(table_ regclass) RETURNS text
2064
    LANGUAGE sql STABLE
2065
    AS $_$
2066
SELECT relname::text FROM pg_class WHERE oid = $1
2067
$_$;
2068

    
2069

    
2070
--
2071
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2072
--
2073

    
2074
CREATE FUNCTION name(type regtype) RETURNS text
2075
    LANGUAGE sql STABLE STRICT
2076
    AS $_$
2077
SELECT typname::text FROM pg_type WHERE oid = $1
2078
$_$;
2079

    
2080

    
2081
--
2082
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2083
--
2084

    
2085
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2086
    LANGUAGE sql IMMUTABLE
2087
    AS $_$
2088
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2089
$_$;
2090

    
2091

    
2092
--
2093
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2094
--
2095

    
2096
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2097
    LANGUAGE sql IMMUTABLE
2098
    AS $_$
2099
SELECT $1 IS NOT NULL
2100
$_$;
2101

    
2102

    
2103
--
2104
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2105
--
2106

    
2107
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2108
    LANGUAGE sql IMMUTABLE
2109
    AS $_$
2110
SELECT util.hstore($1, NULL) || '*=>*'
2111
$_$;
2112

    
2113

    
2114
--
2115
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2116
--
2117

    
2118
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2119
for use with _map()
2120
';
2121

    
2122

    
2123
--
2124
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2125
--
2126

    
2127
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2128
    LANGUAGE sql IMMUTABLE
2129
    AS $_$
2130
SELECT $2 + COALESCE($1, 0)
2131
$_$;
2132

    
2133

    
2134
--
2135
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2136
--
2137

    
2138
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2139
    LANGUAGE sql IMMUTABLE
2140
    AS $_$
2141
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2142
$_$;
2143

    
2144

    
2145
--
2146
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2147
--
2148

    
2149
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2150
    LANGUAGE sql STABLE STRICT
2151
    SET search_path TO pg_temp
2152
    AS $_$
2153
SELECT $1::text
2154
$_$;
2155

    
2156

    
2157
--
2158
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2159
--
2160

    
2161
CREATE FUNCTION qual_name(type regtype) RETURNS text
2162
    LANGUAGE sql STABLE STRICT
2163
    SET search_path TO pg_temp
2164
    AS $_$
2165
SELECT $1::text
2166
$_$;
2167

    
2168

    
2169
--
2170
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2171
--
2172

    
2173
COMMENT ON FUNCTION qual_name(type regtype) IS '
2174
a type''s schema-qualified name
2175
';
2176

    
2177

    
2178
--
2179
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2180
--
2181

    
2182
CREATE FUNCTION qual_name(type unknown) RETURNS text
2183
    LANGUAGE sql STABLE STRICT
2184
    AS $_$
2185
SELECT util.qual_name($1::text::regtype)
2186
$_$;
2187

    
2188

    
2189
--
2190
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2191
--
2192

    
2193
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2194
    LANGUAGE sql IMMUTABLE STRICT
2195
    AS $_$
2196
SELECT util.raise_notice('ERROR:  '||$1)
2197
$_$;
2198

    
2199

    
2200
--
2201
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2202
--
2203

    
2204
CREATE FUNCTION raise_notice(msg text) RETURNS void
2205
    LANGUAGE plpgsql IMMUTABLE STRICT
2206
    AS $$
2207
BEGIN
2208
	RAISE NOTICE '%', msg;
2209
END;
2210
$$;
2211

    
2212

    
2213
--
2214
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2215
--
2216

    
2217
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2218
    LANGUAGE plpgsql IMMUTABLE STRICT
2219
    AS $$
2220
BEGIN
2221
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2222
END;
2223
$$;
2224

    
2225

    
2226
--
2227
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2228
--
2229

    
2230
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2231
    LANGUAGE sql IMMUTABLE
2232
    AS $_$
2233
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2234
$_$;
2235

    
2236

    
2237
--
2238
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2239
--
2240

    
2241
CREATE FUNCTION regexp_quote(str text) RETURNS text
2242
    LANGUAGE sql IMMUTABLE
2243
    AS $_$
2244
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2245
$_$;
2246

    
2247

    
2248
--
2249
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2250
--
2251

    
2252
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2253
    LANGUAGE sql STABLE
2254
    AS $_$
2255
SELECT util.relation_type(util.relation_type_char($1))
2256
$_$;
2257

    
2258

    
2259
--
2260
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2261
--
2262

    
2263
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2264
    LANGUAGE sql IMMUTABLE
2265
    AS $_$
2266
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2267
$_$;
2268

    
2269

    
2270
--
2271
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2272
--
2273

    
2274
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2275
    LANGUAGE sql STABLE
2276
    AS $_$
2277
SELECT relkind FROM pg_class WHERE oid = $1
2278
$_$;
2279

    
2280

    
2281
--
2282
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2283
--
2284

    
2285
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2286
    LANGUAGE sql
2287
    AS $_$
2288
/* can't have in_table/out_table inherit from *each other*, because inheritance
2289
also causes the rows of the parent table to be included in the child table.
2290
instead, they need to inherit from a common, empty table. */
2291
SELECT util.drop_table($4, force := true);
2292
SELECT util.copy_struct($2, $4);
2293
SELECT util.inherit($2, $4);
2294
SELECT util.inherit($3, $4);
2295

    
2296
SELECT util.rematerialize_query($1, $$
2297
SELECT * FROM util.diff(
2298
  $$||quote_nullable($2)||$$::regclass
2299
, $$||quote_nullable($3)||$$::regclass
2300
, NULL::$$||$4||$$)
2301
$$);
2302

    
2303
/* the table unfortunately cannot be *materialized* in human-readable form,
2304
because this would create column name collisions between the two sides */
2305
SELECT util.set_comment($1, '
2306
to view this table in human-readable form (with each side''s tuple column
2307
expanded to its component fields):
2308
SELECT (left_).*, (right_).* FROM '||$1||';
2309
');
2310
$_$;
2311

    
2312

    
2313
--
2314
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2315
--
2316

    
2317
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2318
type_table (*required*): table to create as the shared base type
2319
';
2320

    
2321

    
2322
--
2323
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2324
--
2325

    
2326
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2327
    LANGUAGE sql
2328
    AS $_$
2329
SELECT util.drop_table($1);
2330
SELECT util.materialize_query($1, $2);
2331
$_$;
2332

    
2333

    
2334
--
2335
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2336
--
2337

    
2338
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2339
idempotent, but repeats action each time
2340
';
2341

    
2342

    
2343
--
2344
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2345
--
2346

    
2347
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2348
    LANGUAGE sql
2349
    AS $_$
2350
SELECT util.drop_table($1);
2351
SELECT util.materialize_view($1, $2);
2352
$_$;
2353

    
2354

    
2355
--
2356
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2357
--
2358

    
2359
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2360
idempotent, but repeats action each time
2361
';
2362

    
2363

    
2364
--
2365
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2366
--
2367

    
2368
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2369
    LANGUAGE sql STRICT
2370
    AS $_$
2371
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2372
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2373
FROM util.col_names($1::text::regtype) f (name);
2374
SELECT NULL::void; -- don't fold away functions called in previous query
2375
$_$;
2376

    
2377

    
2378
--
2379
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2380
--
2381

    
2382
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2383
idempotent
2384
';
2385

    
2386

    
2387
--
2388
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2389
--
2390

    
2391
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2392
    LANGUAGE sql STRICT
2393
    AS $_$
2394
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2395
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2396
SELECT util.set_col_names($1, $2);
2397
$_$;
2398

    
2399

    
2400
--
2401
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2402
--
2403

    
2404
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2405
idempotent.
2406
alters the names table, so it will need to be repopulated after running this function.
2407
';
2408

    
2409

    
2410
--
2411
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2412
--
2413

    
2414
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2415
    LANGUAGE sql STRICT
2416
    AS $_$
2417
SELECT util.drop_table($1);
2418
SELECT util.mk_map_table($1);
2419
$_$;
2420

    
2421

    
2422
--
2423
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2424
--
2425

    
2426
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2427
    LANGUAGE plpgsql STRICT
2428
    AS $_$
2429
DECLARE
2430
	result text = NULL;
2431
BEGIN
2432
	BEGIN
2433
		result = util.show_create_view(view_);
2434
		PERFORM util.eval($$DROP VIEW $$||view_);
2435
	EXCEPTION
2436
		WHEN undefined_table THEN NULL;
2437
	END;
2438
	RETURN result;
2439
END;
2440
$_$;
2441

    
2442

    
2443
--
2444
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2445
--
2446

    
2447
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2448
    LANGUAGE sql
2449
    AS $_$
2450
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2451
$_$;
2452

    
2453

    
2454
--
2455
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2456
--
2457

    
2458
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2459
    LANGUAGE sql STABLE
2460
    AS $_$
2461
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2462
$_$;
2463

    
2464

    
2465
--
2466
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2467
--
2468

    
2469
CREATE FUNCTION schema(table_ regclass) RETURNS text
2470
    LANGUAGE sql STABLE
2471
    AS $_$
2472
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2473
$_$;
2474

    
2475

    
2476
--
2477
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2478
--
2479

    
2480
CREATE FUNCTION schema(type regtype) RETURNS text
2481
    LANGUAGE sql STABLE
2482
    AS $_$
2483
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2484
$_$;
2485

    
2486

    
2487
--
2488
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2489
--
2490

    
2491
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2492
    LANGUAGE sql STABLE
2493
    AS $_$
2494
SELECT util.schema(pg_typeof($1))
2495
$_$;
2496

    
2497

    
2498
--
2499
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2500
--
2501

    
2502
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2503
    LANGUAGE sql STABLE
2504
    AS $_$
2505
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2506
$_$;
2507

    
2508

    
2509
--
2510
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2511
--
2512

    
2513
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2514
a schema bundle is a group of schemas with a common prefix
2515
';
2516

    
2517

    
2518
--
2519
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2520
--
2521

    
2522
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2523
    LANGUAGE sql
2524
    AS $_$
2525
SELECT util.schema_rename(old_schema,
2526
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2527
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2528
SELECT NULL::void; -- don't fold away functions called in previous query
2529
$_$;
2530

    
2531

    
2532
--
2533
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2534
--
2535

    
2536
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2537
    LANGUAGE plpgsql
2538
    AS $$
2539
BEGIN
2540
	-- don't schema_bundle_rm() the schema_bundle to keep!
2541
	IF replace = with_ THEN RETURN; END IF;
2542
	
2543
	PERFORM util.schema_bundle_rm(replace);
2544
	PERFORM util.schema_bundle_rename(with_, replace);
2545
END;
2546
$$;
2547

    
2548

    
2549
--
2550
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2551
--
2552

    
2553
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2554
    LANGUAGE sql
2555
    AS $_$
2556
SELECT util.schema_rm(schema)
2557
FROM util.schema_bundle_get_schemas($1) f (schema);
2558
SELECT NULL::void; -- don't fold away functions called in previous query
2559
$_$;
2560

    
2561

    
2562
--
2563
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2564
--
2565

    
2566
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2567
    LANGUAGE sql STABLE
2568
    AS $_$
2569
SELECT quote_ident(util.schema($1))
2570
$_$;
2571

    
2572

    
2573
--
2574
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2575
--
2576

    
2577
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2578
    LANGUAGE sql IMMUTABLE
2579
    AS $_$
2580
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2581
$_$;
2582

    
2583

    
2584
--
2585
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2586
--
2587

    
2588
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2589
    LANGUAGE sql STABLE
2590
    AS $_$
2591
SELECT oid FROM pg_namespace WHERE nspname = $1
2592
$_$;
2593

    
2594

    
2595
--
2596
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2597
--
2598

    
2599
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2600
    LANGUAGE sql
2601
    AS $_$
2602
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2603
$_$;
2604

    
2605

    
2606
--
2607
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2608
--
2609

    
2610
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2611
    LANGUAGE plpgsql
2612
    AS $$
2613
BEGIN
2614
	-- don't schema_rm() the schema to keep!
2615
	IF replace = with_ THEN RETURN; END IF;
2616
	
2617
	PERFORM util.schema_rm(replace);
2618
	PERFORM util.schema_rename(with_, replace);
2619
END;
2620
$$;
2621

    
2622

    
2623
--
2624
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2625
--
2626

    
2627
CREATE FUNCTION schema_rm(schema text) RETURNS void
2628
    LANGUAGE sql
2629
    AS $_$
2630
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2631
$_$;
2632

    
2633

    
2634
--
2635
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2636
--
2637

    
2638
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2639
    LANGUAGE sql STRICT
2640
    AS $_$
2641
SELECT util.eval(
2642
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2643
$_$;
2644

    
2645

    
2646
--
2647
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2648
--
2649

    
2650
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2651
    LANGUAGE plpgsql STRICT
2652
    AS $_$
2653
DECLARE
2654
    old text[] = ARRAY(SELECT util.col_names(table_));
2655
    new text[] = ARRAY(SELECT util.map_values(names));
2656
BEGIN
2657
    old = old[1:array_length(new, 1)]; -- truncate to same length
2658
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2659
||$$ TO $$||quote_ident(value))
2660
    FROM each(hstore(old, new))
2661
    WHERE value != key -- not same name
2662
    ;
2663
END;
2664
$_$;
2665

    
2666

    
2667
--
2668
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2669
--
2670

    
2671
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2672
idempotent
2673
';
2674

    
2675

    
2676
--
2677
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2678
--
2679

    
2680
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2681
    LANGUAGE plpgsql STRICT
2682
    AS $_$
2683
DECLARE
2684
	row_ util.map;
2685
BEGIN
2686
	-- rename any metadata cols rather than re-adding them with new names
2687
	BEGIN
2688
		PERFORM util.set_col_names(table_, names);
2689
	EXCEPTION
2690
		WHEN array_subscript_error THEN -- selective suppress
2691
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2692
				-- metadata cols not yet added
2693
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2694
			END IF;
2695
	END;
2696
	
2697
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2698
	LOOP
2699
		PERFORM util.mk_const_col((table_, row_."to"),
2700
			substring(row_."from" from 2));
2701
	END LOOP;
2702
	
2703
	PERFORM util.set_col_names(table_, names);
2704
END;
2705
$_$;
2706

    
2707

    
2708
--
2709
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2710
--
2711

    
2712
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2713
idempotent.
2714
the metadata mappings must be *last* in the names table.
2715
';
2716

    
2717

    
2718
--
2719
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2720
--
2721

    
2722
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2723
    LANGUAGE plpgsql STRICT
2724
    AS $_$
2725
DECLARE
2726
    sql text = $$ALTER TABLE $$||table_||$$
2727
$$||NULLIF(array_to_string(ARRAY(
2728
    SELECT
2729
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2730
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2731
    FROM
2732
    (
2733
        SELECT
2734
          quote_ident(col_name) AS col_name_sql
2735
        , util.col_type((table_, col_name)) AS curr_type
2736
        , type AS target_type
2737
        FROM unnest(col_casts)
2738
    ) s
2739
    WHERE curr_type != target_type
2740
), '
2741
, '), '');
2742
BEGIN
2743
    PERFORM util.debug_print_sql(sql);
2744
    EXECUTE COALESCE(sql, '');
2745
END;
2746
$_$;
2747

    
2748

    
2749
--
2750
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2751
--
2752

    
2753
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2754
idempotent
2755
';
2756

    
2757

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

    
2762
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2763
    LANGUAGE sql STRICT
2764
    AS $_$
2765
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2766
$_$;
2767

    
2768

    
2769
--
2770
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2774
    LANGUAGE sql STABLE
2775
    AS $_$
2776
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2777
$$||util.show_grants_for($1)
2778
$_$;
2779

    
2780

    
2781
--
2782
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2783
--
2784

    
2785
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2786
    LANGUAGE sql STABLE
2787
    AS $_$
2788
SELECT string_agg(cmd, '')
2789
FROM
2790
(
2791
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2792
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2793
$$ ELSE '' END) AS cmd
2794
	FROM util.grants_users() f (user_)
2795
) s
2796
$_$;
2797

    
2798

    
2799
--
2800
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2801
--
2802

    
2803
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2804
    LANGUAGE sql STABLE
2805
    AS $_$
2806
SELECT oid FROM pg_class
2807
WHERE relkind = ANY($3) AND relname ~ $1
2808
AND util.schema_matches(util.schema(relnamespace), $2)
2809
ORDER BY relname
2810
$_$;
2811

    
2812

    
2813
--
2814
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
2815
--
2816

    
2817
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2818
    LANGUAGE sql STABLE
2819
    AS $_$
2820
SELECT view_
2821
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2822
WHERE util.schema(view_) = $2
2823
$_$;
2824

    
2825

    
2826
--
2827
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2828
--
2829

    
2830
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2831
    LANGUAGE plpgsql STABLE STRICT
2832
    AS $_$
2833
DECLARE
2834
    hstore hstore;
2835
BEGIN
2836
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2837
        table_||$$))$$ INTO STRICT hstore;
2838
    RETURN hstore;
2839
END;
2840
$_$;
2841

    
2842

    
2843
--
2844
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2845
--
2846

    
2847
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2848
    LANGUAGE sql STABLE STRICT
2849
    AS $_$
2850
SELECT COUNT(*) > 0 FROM pg_constraint
2851
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2852
$_$;
2853

    
2854

    
2855
--
2856
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2857
--
2858

    
2859
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2860
gets whether a status flag is set by the presence of a table constraint
2861
';
2862

    
2863

    
2864
--
2865
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2866
--
2867

    
2868
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2869
    LANGUAGE sql STRICT
2870
    AS $_$
2871
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2872
||quote_ident($2)||$$ CHECK (true)$$)
2873
$_$;
2874

    
2875

    
2876
--
2877
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2878
--
2879

    
2880
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2881
stores a status flag by the presence of a table constraint.
2882
idempotent.
2883
';
2884

    
2885

    
2886
--
2887
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2888
--
2889

    
2890
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2891
    LANGUAGE sql STABLE STRICT
2892
    AS $_$
2893
SELECT util.table_flag__get($1, 'nulls_mapped')
2894
$_$;
2895

    
2896

    
2897
--
2898
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2899
--
2900

    
2901
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2902
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2903
';
2904

    
2905

    
2906
--
2907
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2908
--
2909

    
2910
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2911
    LANGUAGE sql STRICT
2912
    AS $_$
2913
SELECT util.table_flag__set($1, 'nulls_mapped')
2914
$_$;
2915

    
2916

    
2917
--
2918
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2919
--
2920

    
2921
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2922
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2923
idempotent.
2924
';
2925

    
2926

    
2927
--
2928
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2929
--
2930

    
2931
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2932
    LANGUAGE plpgsql STRICT
2933
    AS $_$
2934
DECLARE
2935
    row record;
2936
BEGIN
2937
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2938
    LOOP
2939
        IF row.global_name != row.name THEN
2940
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2941
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2942
        END IF;
2943
    END LOOP;
2944
END;
2945
$_$;
2946

    
2947

    
2948
--
2949
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2950
--
2951

    
2952
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2953
idempotent
2954
';
2955

    
2956

    
2957
--
2958
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2959
--
2960

    
2961
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2962
    LANGUAGE sql STRICT
2963
    AS $_$
2964
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2965
SELECT NULL::void; -- don't fold away functions called in previous query
2966
$_$;
2967

    
2968

    
2969
--
2970
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2971
--
2972

    
2973
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2974
trims table_ to include only columns in the original data.
2975
idempotent.
2976
';
2977

    
2978

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

    
2983
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2984
    LANGUAGE plpgsql STRICT
2985
    AS $_$
2986
BEGIN
2987
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2988
END;
2989
$_$;
2990

    
2991

    
2992
--
2993
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2994
--
2995

    
2996
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2997
idempotent
2998
';
2999

    
3000

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

    
3005
CREATE FUNCTION try_create(sql text) RETURNS void
3006
    LANGUAGE plpgsql STRICT
3007
    AS $$
3008
BEGIN
3009
    PERFORM util.eval(sql);
3010
EXCEPTION
3011
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3012
    WHEN undefined_column THEN NULL;
3013
    WHEN duplicate_column THEN NULL;
3014
END;
3015
$$;
3016

    
3017

    
3018
--
3019
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3020
--
3021

    
3022
COMMENT ON FUNCTION try_create(sql text) IS '
3023
idempotent
3024
';
3025

    
3026

    
3027
--
3028
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3029
--
3030

    
3031
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3032
    LANGUAGE sql STRICT
3033
    AS $_$
3034
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3035
$_$;
3036

    
3037

    
3038
--
3039
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3040
--
3041

    
3042
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3043
idempotent
3044
';
3045

    
3046

    
3047
--
3048
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3049
--
3050

    
3051
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3052
    LANGUAGE sql IMMUTABLE
3053
    AS $_$
3054
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3055
$_$;
3056

    
3057

    
3058
--
3059
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3060
--
3061

    
3062
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3063
a type''s NOT NULL qualifier
3064
';
3065

    
3066

    
3067
--
3068
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3069
--
3070

    
3071
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3072
    LANGUAGE plpgsql STABLE
3073
    AS $_$
3074
DECLARE
3075
    type regtype;
3076
BEGIN
3077
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3078
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3079
    RETURN type;
3080
END;
3081
$_$;
3082

    
3083

    
3084
--
3085
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3086
--
3087

    
3088
CREATE AGGREGATE all_same(anyelement) (
3089
    SFUNC = all_same_transform,
3090
    STYPE = anyarray,
3091
    FINALFUNC = all_same_final
3092
);
3093

    
3094

    
3095
--
3096
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3097
--
3098

    
3099
COMMENT ON AGGREGATE all_same(anyelement) IS '
3100
includes NULLs in comparison
3101
';
3102

    
3103

    
3104
--
3105
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3106
--
3107

    
3108
CREATE AGGREGATE join_strs(text, text) (
3109
    SFUNC = join_strs_transform,
3110
    STYPE = text
3111
);
3112

    
3113

    
3114
--
3115
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3116
--
3117

    
3118
CREATE OPERATOR -> (
3119
    PROCEDURE = map_get,
3120
    LEFTARG = regclass,
3121
    RIGHTARG = text
3122
);
3123

    
3124

    
3125
--
3126
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3127
--
3128

    
3129
CREATE OPERATOR => (
3130
    PROCEDURE = hstore,
3131
    LEFTARG = text[],
3132
    RIGHTARG = text
3133
);
3134

    
3135

    
3136
--
3137
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3138
--
3139

    
3140
COMMENT ON OPERATOR => (text[], text) IS '
3141
usage: array[''key1'', ...]::text[] => ''value''
3142
';
3143

    
3144

    
3145
--
3146
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3147
--
3148

    
3149
CREATE OPERATOR ?*>= (
3150
    PROCEDURE = is_populated_more_often_than,
3151
    LEFTARG = anyelement,
3152
    RIGHTARG = anyelement
3153
);
3154

    
3155

    
3156
--
3157
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3158
--
3159

    
3160
CREATE OPERATOR ?>= (
3161
    PROCEDURE = is_more_complete_than,
3162
    LEFTARG = anyelement,
3163
    RIGHTARG = anyelement
3164
);
3165

    
3166

    
3167
--
3168
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3169
--
3170

    
3171
CREATE OPERATOR ||% (
3172
    PROCEDURE = concat_esc,
3173
    LEFTARG = text,
3174
    RIGHTARG = text
3175
);
3176

    
3177

    
3178
--
3179
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3180
--
3181

    
3182
COMMENT ON OPERATOR ||% (text, text) IS '
3183
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3184
';
3185

    
3186

    
3187
--
3188
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3189
--
3190

    
3191
CREATE TABLE map (
3192
    "from" text NOT NULL,
3193
    "to" text,
3194
    filter text,
3195
    notes text
3196
);
3197

    
3198

    
3199
--
3200
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3201
--
3202

    
3203

    
3204

    
3205
--
3206
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3207
--
3208

    
3209

    
3210

    
3211
--
3212
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3213
--
3214

    
3215
ALTER TABLE ONLY map
3216
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3217

    
3218

    
3219
--
3220
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3221
--
3222

    
3223
ALTER TABLE ONLY map
3224
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3225

    
3226

    
3227
--
3228
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3229
--
3230

    
3231
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3232

    
3233

    
3234
--
3235
-- PostgreSQL database dump complete
3236
--
3237

    
(19-19/29)