Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

    
23
COMMENT ON SCHEMA util IS '
24
IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
25

    
26
NOTE: IMMUTABLE SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding.
27
';
28

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

    
78
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
79
    LANGUAGE sql IMMUTABLE
80
    AS $_$
81
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
82
$_$;
83

    
84

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

    
89
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
90
    LANGUAGE sql IMMUTABLE
91
    AS $_$
92
SELECT bool_and(value)
93
FROM
94
(VALUES
95
      ($1)
96
    , ($2)
97
    , ($3)
98
    , ($4)
99
    , ($5)
100
)
101
AS v (value)
102
$_$;
103

    
104

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

    
109
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
110
_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.
111
';
112

    
113

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

    
118
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
119
    LANGUAGE sql IMMUTABLE
120
    AS $_$
121
SELECT avg(value)
122
FROM
123
(VALUES
124
      ($1)
125
    , ($2)
126
    , ($3)
127
    , ($4)
128
    , ($5)
129
)
130
AS v (value)
131
$_$;
132

    
133

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

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

    
152

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

    
157
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
161
FROM
162
(VALUES
163
      ($1)
164
    , ($2/60)
165
    , ($3/60/60)
166
)
167
AS v (value)
168
$_$;
169

    
170

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

    
175
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
176
    LANGUAGE sql IMMUTABLE
177
    AS $_$
178
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
179
$_$;
180

    
181

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

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

    
192

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

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

    
205

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

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

    
216

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

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

    
227

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

    
232
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
233
    LANGUAGE sql IMMUTABLE
234
    AS $_$
235
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
236
$_$;
237

    
238

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

    
243
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
244
    LANGUAGE sql IMMUTABLE
245
    AS $_$
246
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
247
$_$;
248

    
249

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

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

    
260

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

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

    
271

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

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

    
286

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

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

    
311

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

    
316
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
317
    LANGUAGE sql IMMUTABLE
318
    AS $_$
319
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
320
$_$;
321

    
322

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

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

    
361

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

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

    
372

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

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

    
411

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

    
416
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
420
$_$;
421

    
422

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

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

    
433

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

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

    
444

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

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

    
455

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

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

    
481

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

    
486
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
487
    LANGUAGE sql IMMUTABLE
488
    AS $_$
489
SELECT bool_or(value)
490
FROM
491
(VALUES
492
      ($1)
493
    , ($2)
494
    , ($3)
495
    , ($4)
496
    , ($5)
497
)
498
AS v (value)
499
$_$;
500

    
501

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

    
506
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
507
_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.
508
';
509

    
510

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

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

    
521

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

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

    
532

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

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

    
550

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

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

    
559

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

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

    
570

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

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

    
587

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

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

    
598

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

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

    
609

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

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

    
620

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

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

    
631

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

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

    
640

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

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

    
651

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

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

    
667

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

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

    
676

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

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

    
692

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

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

    
716

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

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

    
739

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

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

    
750

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

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

    
759

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

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

    
775

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

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

    
792

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

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

    
806

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

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

    
819

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

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

    
842

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

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

    
853

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

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

    
864

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

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

    
875

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

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

    
896

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

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

    
905

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

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

    
920

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

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

    
936

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

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

    
945

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

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

    
957

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

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

    
968

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

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

    
990

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

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

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

    
1006

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

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

    
1017

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

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

    
1026

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

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

    
1038

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

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

    
1047

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

    
1052
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1053
    LANGUAGE sql
1054
    AS $_$
1055
SELECT (CASE
1056
WHEN util.is_table($1) THEN util.drop_table($1::text, $2)
1057
WHEN util.is_view($1)  THEN util.drop_view ($1::text, $2)
1058
-- otherwise, throw case_not_found error
1059
END)
1060
$_$;
1061

    
1062

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

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

    
1071

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

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

    
1083

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

    
1088
COMMENT ON FUNCTION drop_relation(relation text, type text, force boolean) IS '
1089
idempotent
1090
';
1091

    
1092

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

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

    
1104

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

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

    
1113

    
1114
--
1115
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117

    
1118
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1119
    LANGUAGE sql STRICT
1120
    AS $_$
1121
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1
1122
||util._if($2, $$ CASCADE$$, ''::text))
1123
$_$;
1124

    
1125

    
1126
--
1127
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1128
--
1129

    
1130
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1131
idempotent
1132
';
1133

    
1134

    
1135
--
1136
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1137
--
1138

    
1139
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1140
    LANGUAGE sql IMMUTABLE
1141
    AS $_$
1142
SELECT util.array_fill($1, 0)
1143
$_$;
1144

    
1145

    
1146
--
1147
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1148
--
1149

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

    
1154

    
1155
--
1156
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1157
--
1158

    
1159
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1160
    LANGUAGE sql IMMUTABLE
1161
    AS $_$
1162
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1163
$_$;
1164

    
1165

    
1166
--
1167
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1168
--
1169

    
1170
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1171
    LANGUAGE sql IMMUTABLE
1172
    AS $_$
1173
SELECT regexp_replace($2, '("?)$', $1||'\1')
1174
$_$;
1175

    
1176

    
1177
--
1178
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1179
--
1180

    
1181
CREATE FUNCTION eval(sql text) RETURNS void
1182
    LANGUAGE plpgsql STRICT
1183
    AS $$
1184
BEGIN
1185
	PERFORM util.debug_print_sql(sql);
1186
	EXECUTE sql;
1187
END;
1188
$$;
1189

    
1190

    
1191
--
1192
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1193
--
1194

    
1195
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1196
    LANGUAGE plpgsql
1197
    AS $$
1198
BEGIN
1199
	PERFORM util.debug_print_sql(sql);
1200
	RETURN QUERY EXECUTE sql;
1201
END;
1202
$$;
1203

    
1204

    
1205
--
1206
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1207
--
1208

    
1209
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1210
col_type_null (*required*): NULL::col_type
1211
';
1212

    
1213

    
1214
--
1215
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1216
--
1217

    
1218
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1219
    LANGUAGE plpgsql
1220
    AS $$
1221
BEGIN
1222
	PERFORM util.debug_print_sql(sql);
1223
	RETURN QUERY EXECUTE sql;
1224
END;
1225
$$;
1226

    
1227

    
1228
--
1229
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1230
--
1231

    
1232
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1233
    LANGUAGE plpgsql
1234
    AS $$
1235
BEGIN
1236
	PERFORM util.debug_print_sql(sql);
1237
	RETURN QUERY EXECUTE sql;
1238
END;
1239
$$;
1240

    
1241

    
1242
--
1243
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1244
--
1245

    
1246
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1247
ret_type_null: NULL::ret_type
1248
';
1249

    
1250

    
1251
--
1252
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1253
--
1254

    
1255
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1256
    LANGUAGE plpgsql
1257
    AS $$
1258
DECLARE
1259
	ret_val ret_type_null%TYPE;
1260
BEGIN
1261
	PERFORM util.debug_print_sql(sql);
1262
	EXECUTE sql INTO STRICT ret_val;
1263
	RETURN ret_val;
1264
END;
1265
$$;
1266

    
1267

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

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

    
1276

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

    
1281
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1282
    LANGUAGE sql
1283
    AS $_$
1284
SELECT util.eval2val($$SELECT $$||$1, $2)
1285
$_$;
1286

    
1287

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

    
1292
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1293
ret_type_null: NULL::ret_type
1294
';
1295

    
1296

    
1297
--
1298
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1299
--
1300

    
1301
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1302
    LANGUAGE sql
1303
    AS $_$
1304
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1305
$_$;
1306

    
1307

    
1308
--
1309
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1310
--
1311

    
1312
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1313
sql: can be NULL, which will be passed through
1314
ret_type_null: NULL::ret_type
1315
';
1316

    
1317

    
1318
--
1319
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1320
--
1321

    
1322
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1323
    LANGUAGE sql STABLE STRICT
1324
    AS $_$
1325
SELECT col_name
1326
FROM unnest($2) s (col_name)
1327
WHERE util.col_exists(($1, col_name))
1328
$_$;
1329

    
1330

    
1331
--
1332
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1333
--
1334

    
1335
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1336
    LANGUAGE sql
1337
    AS $_$
1338
SELECT util.eval2set($$EXPLAIN $$||$1)
1339
$_$;
1340

    
1341

    
1342
--
1343
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1344
--
1345

    
1346
CREATE FUNCTION explain2notice(sql text) RETURNS void
1347
    LANGUAGE plpgsql
1348
    AS $_$
1349
BEGIN
1350
	RAISE NOTICE '%', $$EXPLAIN:
1351
$$||util.explain2str(sql);
1352
END;
1353
$_$;
1354

    
1355

    
1356
--
1357
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1358
--
1359

    
1360
CREATE FUNCTION explain2str(sql text) RETURNS text
1361
    LANGUAGE sql
1362
    AS $_$
1363
SELECT util.join_strs(explain, $$
1364
$$) FROM util.explain($1)
1365
$_$;
1366

    
1367

    
1368
SET default_tablespace = '';
1369

    
1370
SET default_with_oids = false;
1371

    
1372
--
1373
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1374
--
1375

    
1376
CREATE TABLE explain (
1377
    line text NOT NULL
1378
);
1379

    
1380

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

    
1385
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1386
    LANGUAGE sql
1387
    AS $_$
1388
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1389
$$||quote_nullable($1)||$$
1390
)$$)
1391
$_$;
1392

    
1393

    
1394
--
1395
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1396
--
1397

    
1398
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1399
usage:
1400
PERFORM util.explain2table($$
1401
query
1402
$$);
1403
';
1404

    
1405

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

    
1410
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1411
    LANGUAGE sql IMMUTABLE
1412
    AS $_$
1413
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1414
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1415
) END
1416
$_$;
1417

    
1418

    
1419
--
1420
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1421
--
1422

    
1423
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1424
ensures that an array will always have proper non-NULL dimensions
1425
';
1426

    
1427

    
1428
--
1429
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1430
--
1431

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

    
1452

    
1453
--
1454
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1455
--
1456

    
1457
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1458
idempotent
1459

    
1460
users: not necessary to provide this because it will be autopopulated
1461
';
1462

    
1463

    
1464
--
1465
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1466
--
1467

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

    
1488

    
1489
--
1490
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1491
--
1492

    
1493
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1494
idempotent
1495
';
1496

    
1497

    
1498
--
1499
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1500
--
1501

    
1502
CREATE FUNCTION grants_users() RETURNS SETOF text
1503
    LANGUAGE sql IMMUTABLE
1504
    AS $$
1505
VALUES ('bien_read'), ('public_')
1506
$$;
1507

    
1508

    
1509
--
1510
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1511
--
1512

    
1513
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1514
    LANGUAGE sql IMMUTABLE
1515
    AS $_$
1516
SELECT substring($2 for length($1)) = $1
1517
$_$;
1518

    
1519

    
1520
--
1521
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1522
--
1523

    
1524
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1525
    LANGUAGE sql STABLE
1526
    AS $_$
1527
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1528
$_$;
1529

    
1530

    
1531
--
1532
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1533
--
1534

    
1535
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1536
    LANGUAGE sql IMMUTABLE
1537
    AS $_$
1538
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1539
$_$;
1540

    
1541

    
1542
--
1543
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1544
--
1545

    
1546
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1547
avoids repeating the same value for each key
1548
';
1549

    
1550

    
1551
--
1552
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1553
--
1554

    
1555
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1556
    LANGUAGE sql IMMUTABLE
1557
    AS $_$
1558
SELECT COALESCE($1, $2)
1559
$_$;
1560

    
1561

    
1562
--
1563
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1564
--
1565

    
1566
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1567
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1568
';
1569

    
1570

    
1571
--
1572
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1573
--
1574

    
1575
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1576
    LANGUAGE sql
1577
    AS $_$
1578
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1579
$_$;
1580

    
1581

    
1582
--
1583
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1584
--
1585

    
1586
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1587
    LANGUAGE sql STABLE STRICT
1588
    AS $_$
1589
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1590
$_$;
1591

    
1592

    
1593
--
1594
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1595
--
1596

    
1597
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1598
    LANGUAGE sql IMMUTABLE
1599
    AS $_$
1600
SELECT util.array_length($1) = 0
1601
$_$;
1602

    
1603

    
1604
--
1605
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1606
--
1607

    
1608
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1609
    LANGUAGE sql IMMUTABLE
1610
    AS $_$
1611
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1612
$_$;
1613

    
1614

    
1615
--
1616
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1617
--
1618

    
1619
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1620
    LANGUAGE sql IMMUTABLE
1621
    AS $_$
1622
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1623
$_$;
1624

    
1625

    
1626
--
1627
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1628
--
1629

    
1630
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1631
    LANGUAGE sql STABLE
1632
    AS $_$
1633
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1634
$_$;
1635

    
1636

    
1637
--
1638
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1639
--
1640

    
1641
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1642
    LANGUAGE sql STABLE
1643
    AS $_$
1644
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1645
$_$;
1646

    
1647

    
1648
--
1649
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1650
--
1651

    
1652
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1653
    LANGUAGE sql IMMUTABLE STRICT
1654
    AS $_$
1655
SELECT $1 || $3 || $2
1656
$_$;
1657

    
1658

    
1659
--
1660
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1661
--
1662

    
1663
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1664
    LANGUAGE sql IMMUTABLE
1665
    AS $_$
1666
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1667
$_$;
1668

    
1669

    
1670
--
1671
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1672
--
1673

    
1674
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1675
    LANGUAGE sql IMMUTABLE
1676
    AS $_$
1677
SELECT ltrim($1, $$
1678
$$)
1679
$_$;
1680

    
1681

    
1682
--
1683
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1684
--
1685

    
1686
CREATE FUNCTION map_filter_insert() RETURNS trigger
1687
    LANGUAGE plpgsql
1688
    AS $$
1689
BEGIN
1690
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1691
	RETURN new;
1692
END;
1693
$$;
1694

    
1695

    
1696
--
1697
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1698
--
1699

    
1700
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1701
    LANGUAGE plpgsql STABLE STRICT
1702
    AS $_$
1703
DECLARE
1704
    value text;
1705
BEGIN
1706
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1707
        INTO value USING key;
1708
    RETURN value;
1709
END;
1710
$_$;
1711

    
1712

    
1713
--
1714
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1715
--
1716

    
1717
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1718
    LANGUAGE sql IMMUTABLE
1719
    AS $_$
1720
SELECT util._map(util.nulls_map($1), $2)
1721
$_$;
1722

    
1723

    
1724
--
1725
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1726
--
1727

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

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

    
1740

    
1741
--
1742
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1743
--
1744

    
1745
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1746
    LANGUAGE plpgsql STABLE STRICT
1747
    AS $_$
1748
BEGIN
1749
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1750
END;
1751
$_$;
1752

    
1753

    
1754
--
1755
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1756
--
1757

    
1758
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1759
    LANGUAGE sql
1760
    AS $_$
1761
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1762
$$||util.ltrim_nl($2));
1763
-- make sure the created table has the correct estimated row count
1764
SELECT util.analyze_($1);
1765
$_$;
1766

    
1767

    
1768
--
1769
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1770
--
1771

    
1772
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1773
idempotent
1774
';
1775

    
1776

    
1777
--
1778
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1779
--
1780

    
1781
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1782
    LANGUAGE sql
1783
    AS $_$
1784
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1785
$_$;
1786

    
1787

    
1788
--
1789
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1790
--
1791

    
1792
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1793
idempotent
1794
';
1795

    
1796

    
1797
--
1798
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1799
--
1800

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

    
1814

    
1815
--
1816
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1817
--
1818

    
1819
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1820
idempotent
1821
';
1822

    
1823

    
1824
--
1825
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1826
--
1827

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

    
1843

    
1844
--
1845
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1846
--
1847

    
1848
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1849
idempotent
1850
';
1851

    
1852

    
1853
--
1854
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1858
    LANGUAGE sql STRICT
1859
    AS $_$
1860
SELECT util.create_if_not_exists($$
1861
CREATE TABLE $$||$1||$$
1862
(
1863
    LIKE util.map INCLUDING ALL
1864
);
1865

    
1866
CREATE TRIGGER map_filter_insert
1867
  BEFORE INSERT
1868
  ON $$||$1||$$
1869
  FOR EACH ROW
1870
  EXECUTE PROCEDURE util.map_filter_insert();
1871
$$)
1872
$_$;
1873

    
1874

    
1875
--
1876
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1877
--
1878

    
1879
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1880
    LANGUAGE sql IMMUTABLE
1881
    AS $_$
1882
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1883
$_$;
1884

    
1885

    
1886
--
1887
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1888
--
1889

    
1890
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1891
    LANGUAGE sql IMMUTABLE
1892
    AS $_$
1893
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1894
$_$;
1895

    
1896

    
1897
--
1898
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1899
--
1900

    
1901
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1902
usage:
1903
for *1* schema arg:
1904
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1905
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1906
';
1907

    
1908

    
1909
--
1910
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1911
--
1912

    
1913
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1914
    LANGUAGE sql IMMUTABLE
1915
    AS $_$
1916
SELECT $$SET LOCAL search_path TO $$||$1
1917
$_$;
1918

    
1919

    
1920
--
1921
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1922
--
1923

    
1924
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1925
    LANGUAGE sql STRICT
1926
    AS $_$
1927
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1928
$_$;
1929

    
1930

    
1931
--
1932
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1933
--
1934

    
1935
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1936
idempotent
1937
';
1938

    
1939

    
1940
--
1941
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1942
--
1943

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

    
1967

    
1968
--
1969
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1970
--
1971

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

    
2011

    
2012
--
2013
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2014
--
2015

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

    
2044

    
2045
--
2046
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2047
--
2048

    
2049
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2050
creates subset function which turns off enable_sort
2051
';
2052

    
2053

    
2054
--
2055
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2056
--
2057

    
2058
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2059
    LANGUAGE sql IMMUTABLE
2060
    AS $_$
2061
SELECT util.mk_set_search_path(util.schema_esc($1))
2062
$_$;
2063

    
2064

    
2065
--
2066
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2067
--
2068

    
2069
CREATE FUNCTION name(table_ regclass) RETURNS text
2070
    LANGUAGE sql STABLE
2071
    AS $_$
2072
SELECT relname::text FROM pg_class WHERE oid = $1
2073
$_$;
2074

    
2075

    
2076
--
2077
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2078
--
2079

    
2080
CREATE FUNCTION name(type regtype) RETURNS text
2081
    LANGUAGE sql STABLE STRICT
2082
    AS $_$
2083
SELECT typname::text FROM pg_type WHERE oid = $1
2084
$_$;
2085

    
2086

    
2087
--
2088
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2089
--
2090

    
2091
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2092
    LANGUAGE sql IMMUTABLE
2093
    AS $_$
2094
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2095
$_$;
2096

    
2097

    
2098
--
2099
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2100
--
2101

    
2102
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2103
    LANGUAGE sql IMMUTABLE
2104
    AS $_$
2105
SELECT $1 IS NOT NULL
2106
$_$;
2107

    
2108

    
2109
--
2110
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2111
--
2112

    
2113
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2114
    LANGUAGE sql IMMUTABLE
2115
    AS $_$
2116
SELECT util.hstore($1, NULL) || '*=>*'
2117
$_$;
2118

    
2119

    
2120
--
2121
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2122
--
2123

    
2124
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2125
for use with _map()
2126
';
2127

    
2128

    
2129
--
2130
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2131
--
2132

    
2133
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2134
    LANGUAGE sql IMMUTABLE
2135
    AS $_$
2136
SELECT $2 + COALESCE($1, 0)
2137
$_$;
2138

    
2139

    
2140
--
2141
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2142
--
2143

    
2144
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2145
    LANGUAGE sql IMMUTABLE
2146
    AS $_$
2147
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2148
$_$;
2149

    
2150

    
2151
--
2152
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2153
--
2154

    
2155
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2156
    LANGUAGE sql STABLE STRICT
2157
    SET search_path TO pg_temp
2158
    AS $_$
2159
SELECT $1::text
2160
$_$;
2161

    
2162

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

    
2167
CREATE FUNCTION qual_name(type regtype) RETURNS text
2168
    LANGUAGE sql STABLE STRICT
2169
    SET search_path TO pg_temp
2170
    AS $_$
2171
SELECT $1::text
2172
$_$;
2173

    
2174

    
2175
--
2176
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2177
--
2178

    
2179
COMMENT ON FUNCTION qual_name(type regtype) IS '
2180
a type''s schema-qualified name
2181
';
2182

    
2183

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

    
2188
CREATE FUNCTION qual_name(type unknown) RETURNS text
2189
    LANGUAGE sql STABLE STRICT
2190
    AS $_$
2191
SELECT util.qual_name($1::text::regtype)
2192
$_$;
2193

    
2194

    
2195
--
2196
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2197
--
2198

    
2199
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2200
    LANGUAGE sql IMMUTABLE STRICT
2201
    AS $_$
2202
SELECT util.raise_notice('ERROR:  '||$1)
2203
$_$;
2204

    
2205

    
2206
--
2207
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2208
--
2209

    
2210
CREATE FUNCTION raise_notice(msg text) RETURNS void
2211
    LANGUAGE plpgsql IMMUTABLE STRICT
2212
    AS $$
2213
BEGIN
2214
	RAISE NOTICE '%', msg;
2215
END;
2216
$$;
2217

    
2218

    
2219
--
2220
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2221
--
2222

    
2223
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2224
    LANGUAGE plpgsql IMMUTABLE STRICT
2225
    AS $$
2226
BEGIN
2227
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2228
END;
2229
$$;
2230

    
2231

    
2232
--
2233
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2234
--
2235

    
2236
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2237
    LANGUAGE sql IMMUTABLE
2238
    AS $_$
2239
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2240
$_$;
2241

    
2242

    
2243
--
2244
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2245
--
2246

    
2247
CREATE FUNCTION regexp_quote(str text) RETURNS text
2248
    LANGUAGE sql IMMUTABLE
2249
    AS $_$
2250
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2251
$_$;
2252

    
2253

    
2254
--
2255
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2256
--
2257

    
2258
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2259
    LANGUAGE sql IMMUTABLE
2260
    AS $_$
2261
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2262
$_$;
2263

    
2264

    
2265
--
2266
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2267
--
2268

    
2269
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2270
    LANGUAGE sql STABLE
2271
    AS $_$
2272
SELECT relkind FROM pg_class WHERE oid = $1
2273
$_$;
2274

    
2275

    
2276
--
2277
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2278
--
2279

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

    
2291
SELECT util.rematerialize_query($1, $$
2292
SELECT * FROM util.diff(
2293
  $$||quote_nullable($2)||$$::regclass
2294
, $$||quote_nullable($3)||$$::regclass
2295
, NULL::$$||$4||$$)
2296
$$);
2297

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

    
2307

    
2308
--
2309
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2310
--
2311

    
2312
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2313
type_table (*required*): table to create as the shared base type
2314
';
2315

    
2316

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

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

    
2328

    
2329
--
2330
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2331
--
2332

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

    
2337

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

    
2342
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2343
    LANGUAGE sql
2344
    AS $_$
2345
SELECT util.drop_table($1);
2346
SELECT util.materialize_view($1, $2);
2347
$_$;
2348

    
2349

    
2350
--
2351
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2352
--
2353

    
2354
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2355
idempotent, but repeats action each time
2356
';
2357

    
2358

    
2359
--
2360
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2361
--
2362

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

    
2372

    
2373
--
2374
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2375
--
2376

    
2377
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2378
idempotent
2379
';
2380

    
2381

    
2382
--
2383
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2384
--
2385

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

    
2394

    
2395
--
2396
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2397
--
2398

    
2399
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2400
idempotent.
2401
alters the names table, so it will need to be repopulated after running this function.
2402
';
2403

    
2404

    
2405
--
2406
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2407
--
2408

    
2409
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2410
    LANGUAGE sql STRICT
2411
    AS $_$
2412
SELECT util.drop_table($1);
2413
SELECT util.mk_map_table($1);
2414
$_$;
2415

    
2416

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

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

    
2437

    
2438
--
2439
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2440
--
2441

    
2442
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2443
    LANGUAGE sql
2444
    AS $_$
2445
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2446
$_$;
2447

    
2448

    
2449
--
2450
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2451
--
2452

    
2453
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2454
    LANGUAGE sql STABLE
2455
    AS $_$
2456
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2457
$_$;
2458

    
2459

    
2460
--
2461
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2462
--
2463

    
2464
CREATE FUNCTION schema(table_ regclass) RETURNS text
2465
    LANGUAGE sql STABLE
2466
    AS $_$
2467
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2468
$_$;
2469

    
2470

    
2471
--
2472
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2473
--
2474

    
2475
CREATE FUNCTION schema(type regtype) RETURNS text
2476
    LANGUAGE sql STABLE
2477
    AS $_$
2478
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2479
$_$;
2480

    
2481

    
2482
--
2483
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2484
--
2485

    
2486
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2487
    LANGUAGE sql STABLE
2488
    AS $_$
2489
SELECT util.schema(pg_typeof($1))
2490
$_$;
2491

    
2492

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

    
2497
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2498
    LANGUAGE sql STABLE
2499
    AS $_$
2500
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2501
$_$;
2502

    
2503

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

    
2508
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2509
a schema bundle is a group of schemas with a common prefix
2510
';
2511

    
2512

    
2513
--
2514
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2515
--
2516

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

    
2526

    
2527
--
2528
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2529
--
2530

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

    
2543

    
2544
--
2545
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2546
--
2547

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

    
2556

    
2557
--
2558
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2559
--
2560

    
2561
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2562
    LANGUAGE sql STABLE
2563
    AS $_$
2564
SELECT quote_ident(util.schema($1))
2565
$_$;
2566

    
2567

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

    
2572
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2573
    LANGUAGE sql IMMUTABLE
2574
    AS $_$
2575
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2576
$_$;
2577

    
2578

    
2579
--
2580
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2581
--
2582

    
2583
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2584
    LANGUAGE sql STABLE
2585
    AS $_$
2586
SELECT oid FROM pg_namespace WHERE nspname = $1
2587
$_$;
2588

    
2589

    
2590
--
2591
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2592
--
2593

    
2594
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2595
    LANGUAGE sql
2596
    AS $_$
2597
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2598
$_$;
2599

    
2600

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

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

    
2617

    
2618
--
2619
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2620
--
2621

    
2622
CREATE FUNCTION schema_rm(schema text) RETURNS void
2623
    LANGUAGE sql
2624
    AS $_$
2625
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2626
$_$;
2627

    
2628

    
2629
--
2630
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2631
--
2632

    
2633
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2634
    LANGUAGE sql STRICT
2635
    AS $_$
2636
SELECT util.eval(
2637
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2638
$_$;
2639

    
2640

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

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

    
2661

    
2662
--
2663
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2664
--
2665

    
2666
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2667
idempotent
2668
';
2669

    
2670

    
2671
--
2672
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2673
--
2674

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

    
2702

    
2703
--
2704
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2705
--
2706

    
2707
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2708
idempotent.
2709
the metadata mappings must be *last* in the names table.
2710
';
2711

    
2712

    
2713
--
2714
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2715
--
2716

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

    
2743

    
2744
--
2745
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2746
--
2747

    
2748
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2749
idempotent
2750
';
2751

    
2752

    
2753
--
2754
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2755
--
2756

    
2757
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2758
    LANGUAGE sql STRICT
2759
    AS $_$
2760
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2761
$_$;
2762

    
2763

    
2764
--
2765
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2766
--
2767

    
2768
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2769
    LANGUAGE sql STABLE
2770
    AS $_$
2771
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2772
$$||util.show_grants_for($1)
2773
$_$;
2774

    
2775

    
2776
--
2777
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2778
--
2779

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

    
2793

    
2794
--
2795
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2796
--
2797

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

    
2807

    
2808
--
2809
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
2810
--
2811

    
2812
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2813
    LANGUAGE sql STABLE
2814
    AS $_$
2815
SELECT view_
2816
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2817
WHERE util.schema(view_) = $2
2818
$_$;
2819

    
2820

    
2821
--
2822
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2823
--
2824

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

    
2837

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

    
2842
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2843
    LANGUAGE sql STABLE STRICT
2844
    AS $_$
2845
SELECT COUNT(*) > 0 FROM pg_constraint
2846
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2847
$_$;
2848

    
2849

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

    
2854
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2855
gets whether a status flag is set by the presence of a table constraint
2856
';
2857

    
2858

    
2859
--
2860
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2861
--
2862

    
2863
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2864
    LANGUAGE sql STRICT
2865
    AS $_$
2866
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2867
||quote_ident($2)||$$ CHECK (true)$$)
2868
$_$;
2869

    
2870

    
2871
--
2872
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2873
--
2874

    
2875
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2876
stores a status flag by the presence of a table constraint.
2877
idempotent.
2878
';
2879

    
2880

    
2881
--
2882
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2883
--
2884

    
2885
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2886
    LANGUAGE sql STABLE STRICT
2887
    AS $_$
2888
SELECT util.table_flag__get($1, 'nulls_mapped')
2889
$_$;
2890

    
2891

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

    
2896
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2897
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2898
';
2899

    
2900

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

    
2905
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2906
    LANGUAGE sql STRICT
2907
    AS $_$
2908
SELECT util.table_flag__set($1, 'nulls_mapped')
2909
$_$;
2910

    
2911

    
2912
--
2913
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2914
--
2915

    
2916
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2917
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2918
idempotent.
2919
';
2920

    
2921

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

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

    
2942

    
2943
--
2944
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2945
--
2946

    
2947
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2948
idempotent
2949
';
2950

    
2951

    
2952
--
2953
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2954
--
2955

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

    
2963

    
2964
--
2965
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2966
--
2967

    
2968
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2969
trims table_ to include only columns in the original data.
2970
idempotent.
2971
';
2972

    
2973

    
2974
--
2975
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2976
--
2977

    
2978
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2979
    LANGUAGE plpgsql STRICT
2980
    AS $_$
2981
BEGIN
2982
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2983
END;
2984
$_$;
2985

    
2986

    
2987
--
2988
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2989
--
2990

    
2991
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2992
idempotent
2993
';
2994

    
2995

    
2996
--
2997
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2998
--
2999

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

    
3012

    
3013
--
3014
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3015
--
3016

    
3017
COMMENT ON FUNCTION try_create(sql text) IS '
3018
idempotent
3019
';
3020

    
3021

    
3022
--
3023
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3024
--
3025

    
3026
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3027
    LANGUAGE sql STRICT
3028
    AS $_$
3029
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3030
$_$;
3031

    
3032

    
3033
--
3034
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3035
--
3036

    
3037
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3038
idempotent
3039
';
3040

    
3041

    
3042
--
3043
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3044
--
3045

    
3046
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3047
    LANGUAGE sql IMMUTABLE
3048
    AS $_$
3049
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3050
$_$;
3051

    
3052

    
3053
--
3054
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3055
--
3056

    
3057
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3058
a type''s NOT NULL qualifier
3059
';
3060

    
3061

    
3062
--
3063
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3064
--
3065

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

    
3078

    
3079
--
3080
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3081
--
3082

    
3083
CREATE AGGREGATE all_same(anyelement) (
3084
    SFUNC = all_same_transform,
3085
    STYPE = anyarray,
3086
    FINALFUNC = all_same_final
3087
);
3088

    
3089

    
3090
--
3091
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3092
--
3093

    
3094
COMMENT ON AGGREGATE all_same(anyelement) IS '
3095
includes NULLs in comparison
3096
';
3097

    
3098

    
3099
--
3100
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3101
--
3102

    
3103
CREATE AGGREGATE join_strs(text, text) (
3104
    SFUNC = join_strs_transform,
3105
    STYPE = text
3106
);
3107

    
3108

    
3109
--
3110
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3111
--
3112

    
3113
CREATE OPERATOR -> (
3114
    PROCEDURE = map_get,
3115
    LEFTARG = regclass,
3116
    RIGHTARG = text
3117
);
3118

    
3119

    
3120
--
3121
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3122
--
3123

    
3124
CREATE OPERATOR => (
3125
    PROCEDURE = hstore,
3126
    LEFTARG = text[],
3127
    RIGHTARG = text
3128
);
3129

    
3130

    
3131
--
3132
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3133
--
3134

    
3135
COMMENT ON OPERATOR => (text[], text) IS '
3136
usage: array[''key1'', ...]::text[] => ''value''
3137
';
3138

    
3139

    
3140
--
3141
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3142
--
3143

    
3144
CREATE OPERATOR ?*>= (
3145
    PROCEDURE = is_populated_more_often_than,
3146
    LEFTARG = anyelement,
3147
    RIGHTARG = anyelement
3148
);
3149

    
3150

    
3151
--
3152
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3153
--
3154

    
3155
CREATE OPERATOR ?>= (
3156
    PROCEDURE = is_more_complete_than,
3157
    LEFTARG = anyelement,
3158
    RIGHTARG = anyelement
3159
);
3160

    
3161

    
3162
--
3163
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3164
--
3165

    
3166
CREATE OPERATOR ||% (
3167
    PROCEDURE = concat_esc,
3168
    LEFTARG = text,
3169
    RIGHTARG = text
3170
);
3171

    
3172

    
3173
--
3174
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3175
--
3176

    
3177
COMMENT ON OPERATOR ||% (text, text) IS '
3178
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3179
';
3180

    
3181

    
3182
--
3183
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3184
--
3185

    
3186
CREATE TABLE map (
3187
    "from" text NOT NULL,
3188
    "to" text,
3189
    filter text,
3190
    notes text
3191
);
3192

    
3193

    
3194
--
3195
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3196
--
3197

    
3198

    
3199

    
3200
--
3201
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3202
--
3203

    
3204

    
3205

    
3206
--
3207
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3208
--
3209

    
3210
ALTER TABLE ONLY map
3211
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3212

    
3213

    
3214
--
3215
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3216
--
3217

    
3218
ALTER TABLE ONLY map
3219
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3220

    
3221

    
3222
--
3223
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3224
--
3225

    
3226
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3227

    
3228

    
3229
--
3230
-- PostgreSQL database dump complete
3231
--
3232

    
(19-19/29)