Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

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

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

    
104

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

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

    
113

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

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

    
133

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

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

    
152

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

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

    
170

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

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

    
181

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

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

    
192

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

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

    
205

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

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

    
216

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

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

    
227

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

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

    
238

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

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

    
249

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

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

    
260

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

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

    
271

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

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

    
286

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

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

    
311

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

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

    
322

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

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

    
361

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

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

    
372

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

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

    
411

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

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

    
422

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

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

    
433

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

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

    
444

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

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

    
455

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

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

    
481

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

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

    
501

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

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

    
510

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

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

    
521

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

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

    
532

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

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

    
550

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

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

    
559

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

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

    
570

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

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

    
587

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

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

    
598

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

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

    
609

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

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

    
620

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

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

    
631

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

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

    
640

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

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

    
651

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

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

    
667

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

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

    
676

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

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

    
692

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

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

    
716

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

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

    
739

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

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

    
750

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

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

    
759

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

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

    
775

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

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

    
792

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

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

    
806

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

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

    
819

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

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

    
842

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

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

    
853

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

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

    
864

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

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

    
875

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

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

    
896

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

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

    
905

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

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

    
920

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

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

    
936

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

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

    
945

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

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

    
957

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

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

    
968

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

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

    
990

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

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

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

    
1006

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

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

    
1017

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

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

    
1026

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

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

    
1038

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

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

    
1047

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

    
1052
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1053
    LANGUAGE sql
1054
    AS $_$
1055
SELECT util.drop_relation($1::text, util.relation_type($1), $2)
1056
$_$;
1057

    
1058

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

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

    
1067

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

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

    
1079

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

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

    
1088

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

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

    
1100

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

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

    
1109

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

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

    
1121

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

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

    
1130

    
1131
--
1132
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1133
--
1134

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

    
1141

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

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

    
1150

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

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

    
1161

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

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

    
1172

    
1173
--
1174
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1175
--
1176

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

    
1186

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

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

    
1200

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

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

    
1209

    
1210
--
1211
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1212
--
1213

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

    
1223

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

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

    
1237

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

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

    
1246

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

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

    
1263

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

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

    
1272

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

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

    
1283

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

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

    
1292

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

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

    
1303

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

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

    
1313

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

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

    
1326

    
1327
--
1328
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1329
--
1330

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

    
1337

    
1338
--
1339
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1340
--
1341

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

    
1351

    
1352
--
1353
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1354
--
1355

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

    
1363

    
1364
SET default_tablespace = '';
1365

    
1366
SET default_with_oids = false;
1367

    
1368
--
1369
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1370
--
1371

    
1372
CREATE TABLE explain (
1373
    line text NOT NULL
1374
);
1375

    
1376

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

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

    
1389

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

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

    
1401

    
1402
--
1403
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1404
--
1405

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

    
1414

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

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

    
1423

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

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

    
1448

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

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

    
1456
users: not necessary to provide this because it will be autopopulated
1457
';
1458

    
1459

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

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

    
1484

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

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

    
1493

    
1494
--
1495
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1496
--
1497

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

    
1504

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

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

    
1515

    
1516
--
1517
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1518
--
1519

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

    
1526

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

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

    
1537

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

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

    
1546

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

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

    
1557

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

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

    
1566

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

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

    
1577

    
1578
--
1579
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1580
--
1581

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

    
1588

    
1589
--
1590
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1591
--
1592

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

    
1599

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

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

    
1610

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

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

    
1621

    
1622
--
1623
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1624
--
1625

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

    
1632

    
1633
--
1634
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1635
--
1636

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

    
1643

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

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

    
1654

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

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

    
1665

    
1666
--
1667
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1668
--
1669

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

    
1677

    
1678
--
1679
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1680
--
1681

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

    
1691

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

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

    
1708

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

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

    
1719

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

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

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

    
1736

    
1737
--
1738
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1739
--
1740

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

    
1749

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

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

    
1763

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

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

    
1772

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

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

    
1783

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

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

    
1792

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

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

    
1810

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

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

    
1819

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

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

    
1839

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

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

    
1848

    
1849
--
1850
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1851
--
1852

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

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

    
1870

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

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

    
1881

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

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

    
1892

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

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

    
1904

    
1905
--
1906
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1907
--
1908

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

    
1915

    
1916
--
1917
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1918
--
1919

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

    
1926

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

    
1931
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1932
idempotent
1933
';
1934

    
1935

    
1936
--
1937
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1938
--
1939

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

    
1963

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

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

    
2007

    
2008
--
2009
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2010
--
2011

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

    
2040

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

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

    
2049

    
2050
--
2051
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2052
--
2053

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

    
2060

    
2061
--
2062
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2063
--
2064

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

    
2071

    
2072
--
2073
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2074
--
2075

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

    
2082

    
2083
--
2084
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2085
--
2086

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

    
2093

    
2094
--
2095
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2096
--
2097

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

    
2104

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

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

    
2115

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

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

    
2124

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

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

    
2135

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

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

    
2146

    
2147
--
2148
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2149
--
2150

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

    
2158

    
2159
--
2160
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2161
--
2162

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

    
2170

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

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

    
2179

    
2180
--
2181
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2182
--
2183

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

    
2190

    
2191
--
2192
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2193
--
2194

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

    
2201

    
2202
--
2203
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2204
--
2205

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

    
2214

    
2215
--
2216
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2217
--
2218

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

    
2227

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

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

    
2238

    
2239
--
2240
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2241
--
2242

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

    
2249

    
2250
--
2251
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2252
--
2253

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

    
2260

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

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

    
2271

    
2272
--
2273
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2274
--
2275

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

    
2282

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

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

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

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

    
2314

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

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

    
2323

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

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

    
2335

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

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

    
2344

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

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

    
2356

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

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

    
2365

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

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

    
2379

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

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

    
2388

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

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

    
2401

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

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

    
2411

    
2412
--
2413
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2414
--
2415

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

    
2423

    
2424
--
2425
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2426
--
2427

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

    
2444

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

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

    
2455

    
2456
--
2457
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2458
--
2459

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

    
2466

    
2467
--
2468
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2469
--
2470

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

    
2477

    
2478
--
2479
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2480
--
2481

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

    
2488

    
2489
--
2490
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2491
--
2492

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

    
2499

    
2500
--
2501
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2502
--
2503

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

    
2510

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

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

    
2519

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

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

    
2533

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

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

    
2550

    
2551
--
2552
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2553
--
2554

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

    
2563

    
2564
--
2565
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2566
--
2567

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

    
2574

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

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

    
2585

    
2586
--
2587
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2588
--
2589

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

    
2596

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

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

    
2607

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

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

    
2624

    
2625
--
2626
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2627
--
2628

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

    
2635

    
2636
--
2637
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2638
--
2639

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

    
2647

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

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

    
2668

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

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

    
2677

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

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

    
2709

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

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

    
2719

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

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

    
2750

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

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

    
2759

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

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

    
2770

    
2771
--
2772
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2773
--
2774

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

    
2782

    
2783
--
2784
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2785
--
2786

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

    
2800

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

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

    
2814

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

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

    
2827

    
2828
--
2829
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2830
--
2831

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

    
2844

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

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

    
2856

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

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

    
2865

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

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

    
2877

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

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

    
2887

    
2888
--
2889
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2890
--
2891

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

    
2898

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

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

    
2907

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

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

    
2918

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

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

    
2928

    
2929
--
2930
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2931
--
2932

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

    
2949

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

    
2954
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2955
idempotent
2956
';
2957

    
2958

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

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

    
2970

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

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

    
2980

    
2981
--
2982
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2983
--
2984

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

    
2993

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

    
2998
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2999
idempotent
3000
';
3001

    
3002

    
3003
--
3004
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3005
--
3006

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

    
3019

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

    
3024
COMMENT ON FUNCTION try_create(sql text) IS '
3025
idempotent
3026
';
3027

    
3028

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

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

    
3039

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

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

    
3048

    
3049
--
3050
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3051
--
3052

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

    
3059

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

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

    
3068

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

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

    
3085

    
3086
--
3087
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3088
--
3089

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

    
3096

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

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

    
3105

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

    
3110
CREATE AGGREGATE join_strs(text, text) (
3111
    SFUNC = join_strs_transform,
3112
    STYPE = text
3113
);
3114

    
3115

    
3116
--
3117
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3118
--
3119

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

    
3126

    
3127
--
3128
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3129
--
3130

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

    
3137

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

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

    
3146

    
3147
--
3148
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3149
--
3150

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

    
3157

    
3158
--
3159
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3160
--
3161

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

    
3168

    
3169
--
3170
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3171
--
3172

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

    
3179

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

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

    
3188

    
3189
--
3190
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3191
--
3192

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

    
3200

    
3201
--
3202
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3203
--
3204

    
3205

    
3206

    
3207
--
3208
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3209
--
3210

    
3211

    
3212

    
3213
--
3214
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3215
--
3216

    
3217
ALTER TABLE ONLY map
3218
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3219

    
3220

    
3221
--
3222
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3223
--
3224

    
3225
ALTER TABLE ONLY map
3226
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3227

    
3228

    
3229
--
3230
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3231
--
3232

    
3233
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3234

    
3235

    
3236
--
3237
-- PostgreSQL database dump complete
3238
--
3239

    
(19-19/29)