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: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
604
    LANGUAGE sql STRICT
605
    AS $_$
606
SELECT util.set_comment($1, concat(util.comment($1), $2))
607
$_$;
608

    
609

    
610
--
611
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
612
--
613

    
614
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
615
comment: must start and end with a newline
616
';
617

    
618

    
619
--
620
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
621
--
622

    
623
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
624
    LANGUAGE sql IMMUTABLE
625
    AS $_$
626
SELECT pg_catalog.array_fill($1, ARRAY[$2])
627
$_$;
628

    
629

    
630
--
631
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
635
    LANGUAGE sql IMMUTABLE
636
    AS $_$
637
SELECT util.array_length($1, 1)
638
$_$;
639

    
640

    
641
--
642
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
643
--
644

    
645
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
646
    LANGUAGE sql IMMUTABLE
647
    AS $_$
648
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
649
$_$;
650

    
651

    
652
--
653
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
654
--
655

    
656
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
657
returns 0 instead of NULL for empty arrays
658
';
659

    
660

    
661
--
662
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
663
--
664

    
665
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
666
    LANGUAGE sql STABLE STRICT
667
    AS $_$
668
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
669
$_$;
670

    
671

    
672
--
673
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
674
--
675

    
676
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
677
    LANGUAGE plpgsql STRICT
678
    AS $_$
679
BEGIN
680
    -- not yet clustered (ARRAY[] compares NULLs literally)
681
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
682
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
683
    END IF;
684
END;
685
$_$;
686

    
687

    
688
--
689
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
690
--
691

    
692
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
693
idempotent
694
';
695

    
696

    
697
--
698
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
699
--
700

    
701
CREATE FUNCTION col__min(col col_ref) RETURNS integer
702
    LANGUAGE sql STABLE
703
    AS $_$
704
SELECT util.eval2val($$
705
SELECT $$||quote_ident($1.name)||$$
706
FROM $$||$1.table_||$$
707
ORDER BY $$||quote_ident($1.name)||$$ ASC
708
LIMIT 1
709
$$, NULL::integer)
710
$_$;
711

    
712

    
713
--
714
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
715
--
716

    
717
CREATE FUNCTION col_comment(col col_ref) RETURNS text
718
    LANGUAGE plpgsql STABLE STRICT
719
    AS $$
720
DECLARE
721
	comment text;
722
BEGIN
723
	SELECT description
724
	FROM pg_attribute
725
	LEFT JOIN pg_description ON objoid = attrelid
726
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
727
	WHERE attrelid = col.table_ AND attname = col.name
728
	INTO STRICT comment
729
	;
730
	RETURN comment;
731
EXCEPTION
732
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
733
END;
734
$$;
735

    
736

    
737
--
738
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
739
--
740

    
741
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
742
    LANGUAGE plpgsql STABLE STRICT
743
    AS $$
744
DECLARE
745
	default_sql text;
746
BEGIN
747
	SELECT adsrc
748
	FROM pg_attribute
749
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
750
	WHERE attrelid = col.table_ AND attname = col.name
751
	INTO STRICT default_sql
752
	;
753
	RETURN default_sql;
754
EXCEPTION
755
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
756
END;
757
$$;
758

    
759

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

    
764
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
765
    LANGUAGE sql STABLE
766
    AS $_$
767
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
768
$_$;
769

    
770

    
771
--
772
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
773
--
774

    
775
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
776
ret_type_null: NULL::ret_type
777
';
778

    
779

    
780
--
781
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
782
--
783

    
784
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
785
    LANGUAGE plpgsql STRICT
786
    AS $$
787
BEGIN
788
    PERFORM util.col_type(col);
789
    RETURN true;
790
EXCEPTION
791
    WHEN undefined_column THEN RETURN false;
792
END;
793
$$;
794

    
795

    
796
--
797
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
798
--
799

    
800
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
801
    LANGUAGE plpgsql STABLE STRICT
802
    AS $$
803
DECLARE
804
    prefix text := util.name(type)||'.';
805
BEGIN
806
    RETURN QUERY
807
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
808
        FROM util.col_names(type) f (name_);
809
END;
810
$$;
811

    
812

    
813
--
814
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
815
--
816

    
817
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
818
    LANGUAGE sql STABLE STRICT
819
    AS $_$
820
SELECT attname::text
821
FROM pg_attribute
822
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
823
ORDER BY attnum
824
$_$;
825

    
826

    
827
--
828
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
829
--
830

    
831
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
832
    LANGUAGE plpgsql STABLE STRICT
833
    AS $_$
834
BEGIN
835
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
836
END;
837
$_$;
838

    
839

    
840
--
841
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
842
--
843

    
844
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
845
    LANGUAGE plpgsql STABLE STRICT
846
    AS $$
847
DECLARE
848
    type regtype;
849
BEGIN
850
    SELECT atttypid FROM pg_attribute
851
    WHERE attrelid = col.table_ AND attname = col.name
852
    INTO STRICT type
853
    ;
854
    RETURN type;
855
EXCEPTION
856
    WHEN no_data_found THEN
857
        RAISE undefined_column USING MESSAGE =
858
            concat('undefined column: ', col.name);
859
END;
860
$$;
861

    
862

    
863
--
864
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
865
--
866

    
867
CREATE FUNCTION comment(element oid) RETURNS text
868
    LANGUAGE sql STABLE STRICT
869
    AS $_$
870
SELECT description FROM pg_description WHERE objoid = $1
871
$_$;
872

    
873

    
874
--
875
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
876
--
877

    
878
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
879
    LANGUAGE sql IMMUTABLE
880
    AS $_$
881
SELECT util.esc_name__append($2, $1)
882
$_$;
883

    
884

    
885
--
886
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
887
--
888

    
889
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
890
    LANGUAGE sql IMMUTABLE
891
    AS $_$
892
SELECT position($1 in $2) > 0 /*1-based offset*/
893
$_$;
894

    
895

    
896
--
897
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
898
--
899

    
900
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
901
    LANGUAGE sql
902
    AS $_$
903
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
904
$_$;
905

    
906

    
907
--
908
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
909
--
910

    
911
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
912
    LANGUAGE plpgsql STRICT
913
    AS $$
914
BEGIN
915
    PERFORM util.eval(sql);
916
EXCEPTION
917
    WHEN duplicate_table  THEN NULL;
918
    WHEN duplicate_object THEN NULL; -- e.g. constraint
919
    WHEN duplicate_column THEN NULL;
920
    WHEN invalid_table_definition THEN
921
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
922
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
923
        END IF;
924
END;
925
$$;
926

    
927

    
928
--
929
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
930
--
931

    
932
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
933
idempotent
934
';
935

    
936

    
937
--
938
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
939
--
940

    
941
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
942
    LANGUAGE sql IMMUTABLE
943
    AS $_$
944
/* newline before so the query starts at the beginning of the line.
945
newline after to visually separate queries from one another. */
946
SELECT util.raise_notice($$
947
$$||$1||$$
948
$$)
949
$_$;
950

    
951

    
952
--
953
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
954
--
955

    
956
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
957
    LANGUAGE sql STABLE STRICT
958
    AS $_$
959
SELECT util.eval2set($$
960
SELECT col
961
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
962
LEFT JOIN $$||$2||$$ ON "to" = col
963
WHERE "from" IS NULL
964
$$, NULL::text)
965
$_$;
966

    
967

    
968
--
969
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
970
--
971

    
972
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
973
gets table_''s derived columns (all the columns not in the names table)
974
';
975

    
976

    
977
--
978
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
979
--
980

    
981
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
982
    LANGUAGE sql STABLE
983
    AS $_$
984
SELECT * FROM util.diff($1::text, $2::text, $3,
985
	util.has_single_row($1) AND util.has_single_row($2))
986
$_$;
987

    
988

    
989
--
990
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
991
--
992

    
993
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
994
col_type_null (*required*): NULL::shared_base_type
995
usage:
996
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
997
';
998

    
999

    
1000
--
1001
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1002
--
1003

    
1004
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
1005
    LANGUAGE sql STABLE
1006
    AS $_$
1007
SELECT * FROM
1008
util.eval2col_pair($$
1009
/* need to explicitly cast each side to the return type because this does not
1010
happen automatically even when an implicit cast is available */
1011
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
1012
FROM $$||$1||$$ left_
1013
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
1014
$$||util._if($4, ''::text, $$ON left_ = right_
1015
$$)||
1016
$$WHERE left_ IS DISTINCT FROM right_
1017
ORDER BY left_, right_
1018
$$, $3)
1019
$_$;
1020

    
1021

    
1022
--
1023
-- 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: -
1024
--
1025

    
1026
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1027
col_type_null (*required*): NULL::col_type
1028
single_row: whether the tables consist of a single row, which should be
1029
	displayed side-by-side
1030

    
1031
to run EXPLAIN on the FULL JOIN query:
1032
# run this function
1033
# look for a NOTICE containing the expanded query that it ran
1034
# run EXPLAIN on this expanded query
1035
';
1036

    
1037

    
1038
--
1039
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1040
--
1041

    
1042
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1043
    LANGUAGE sql STRICT
1044
    AS $_$
1045
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1046
$_$;
1047

    
1048

    
1049
--
1050
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1051
--
1052

    
1053
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1054
idempotent
1055
';
1056

    
1057

    
1058
--
1059
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1060
--
1061

    
1062
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1063
    LANGUAGE sql STRICT
1064
    AS $_$
1065
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1066
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1067
$_$;
1068

    
1069

    
1070
--
1071
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1072
--
1073

    
1074
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1075
idempotent
1076
';
1077

    
1078

    
1079
--
1080
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1081
--
1082

    
1083
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1084
    LANGUAGE sql
1085
    AS $_$
1086
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1087
included in the debug SQL */
1088
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1089
$_$;
1090

    
1091

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

    
1096
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1097
    LANGUAGE sql
1098
    AS $_$
1099
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1100
||util._if($3, $$ CASCADE$$, ''::text))
1101
$_$;
1102

    
1103

    
1104
--
1105
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1106
--
1107

    
1108
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1109
idempotent
1110
';
1111

    
1112

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

    
1117
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1118
    LANGUAGE sql STRICT
1119
    AS $_$
1120
SELECT util.drop_relation('TABLE', $1, $2)
1121
$_$;
1122

    
1123

    
1124
--
1125
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1126
--
1127

    
1128
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1129
idempotent
1130
';
1131

    
1132

    
1133
--
1134
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1135
--
1136

    
1137
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1138
    LANGUAGE sql STRICT
1139
    AS $_$
1140
SELECT util.drop_relation('VIEW', $1, $2)
1141
$_$;
1142

    
1143

    
1144
--
1145
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1146
--
1147

    
1148
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1149
idempotent
1150
';
1151

    
1152

    
1153
--
1154
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1155
--
1156

    
1157
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1158
    LANGUAGE sql IMMUTABLE
1159
    AS $_$
1160
SELECT util.array_fill($1, 0)
1161
$_$;
1162

    
1163

    
1164
--
1165
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1166
--
1167

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

    
1172

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

    
1177
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1178
    LANGUAGE sql IMMUTABLE
1179
    AS $_$
1180
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1181
$_$;
1182

    
1183

    
1184
--
1185
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1186
--
1187

    
1188
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1189
    LANGUAGE sql IMMUTABLE
1190
    AS $_$
1191
SELECT regexp_replace($2, '("?)$', $1||'\1')
1192
$_$;
1193

    
1194

    
1195
--
1196
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1197
--
1198

    
1199
CREATE FUNCTION eval(sql text) RETURNS void
1200
    LANGUAGE plpgsql STRICT
1201
    AS $$
1202
BEGIN
1203
	PERFORM util.debug_print_sql(sql);
1204
	EXECUTE sql;
1205
END;
1206
$$;
1207

    
1208

    
1209
--
1210
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1211
--
1212

    
1213
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1214
    LANGUAGE plpgsql
1215
    AS $$
1216
BEGIN
1217
	PERFORM util.debug_print_sql(sql);
1218
	RETURN QUERY EXECUTE sql;
1219
END;
1220
$$;
1221

    
1222

    
1223
--
1224
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1225
--
1226

    
1227
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1228
col_type_null (*required*): NULL::col_type
1229
';
1230

    
1231

    
1232
--
1233
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1234
--
1235

    
1236
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1237
    LANGUAGE plpgsql
1238
    AS $$
1239
BEGIN
1240
	PERFORM util.debug_print_sql(sql);
1241
	RETURN QUERY EXECUTE sql;
1242
END;
1243
$$;
1244

    
1245

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

    
1250
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1251
    LANGUAGE plpgsql
1252
    AS $$
1253
BEGIN
1254
	PERFORM util.debug_print_sql(sql);
1255
	RETURN QUERY EXECUTE sql;
1256
END;
1257
$$;
1258

    
1259

    
1260
--
1261
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1262
--
1263

    
1264
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1265
ret_type_null: NULL::ret_type
1266
';
1267

    
1268

    
1269
--
1270
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1271
--
1272

    
1273
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1274
    LANGUAGE plpgsql
1275
    AS $$
1276
DECLARE
1277
	ret_val ret_type_null%TYPE;
1278
BEGIN
1279
	PERFORM util.debug_print_sql(sql);
1280
	EXECUTE sql INTO STRICT ret_val;
1281
	RETURN ret_val;
1282
END;
1283
$$;
1284

    
1285

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

    
1290
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1291
ret_type_null: NULL::ret_type
1292
';
1293

    
1294

    
1295
--
1296
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1297
--
1298

    
1299
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1300
    LANGUAGE sql
1301
    AS $_$
1302
SELECT util.eval2val($$SELECT $$||$1, $2)
1303
$_$;
1304

    
1305

    
1306
--
1307
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1308
--
1309

    
1310
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1311
ret_type_null: NULL::ret_type
1312
';
1313

    
1314

    
1315
--
1316
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1317
--
1318

    
1319
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1320
    LANGUAGE sql
1321
    AS $_$
1322
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1323
$_$;
1324

    
1325

    
1326
--
1327
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1328
--
1329

    
1330
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1331
sql: can be NULL, which will be passed through
1332
ret_type_null: NULL::ret_type
1333
';
1334

    
1335

    
1336
--
1337
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1338
--
1339

    
1340
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1341
    LANGUAGE sql STABLE STRICT
1342
    AS $_$
1343
SELECT col_name
1344
FROM unnest($2) s (col_name)
1345
WHERE util.col_exists(($1, col_name))
1346
$_$;
1347

    
1348

    
1349
--
1350
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1351
--
1352

    
1353
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1354
    LANGUAGE sql
1355
    AS $_$
1356
SELECT util.eval2set($$EXPLAIN $$||$1)
1357
$_$;
1358

    
1359

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

    
1364
CREATE FUNCTION explain2notice(sql text) RETURNS void
1365
    LANGUAGE plpgsql
1366
    AS $_$
1367
BEGIN
1368
	RAISE NOTICE '%', $$EXPLAIN:
1369
$$||util.explain2str(sql);
1370
END;
1371
$_$;
1372

    
1373

    
1374
--
1375
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1376
--
1377

    
1378
CREATE FUNCTION explain2str(sql text) RETURNS text
1379
    LANGUAGE sql
1380
    AS $_$
1381
SELECT util.join_strs(explain, $$
1382
$$) FROM util.explain($1)
1383
$_$;
1384

    
1385

    
1386
SET default_tablespace = '';
1387

    
1388
SET default_with_oids = false;
1389

    
1390
--
1391
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1392
--
1393

    
1394
CREATE TABLE explain (
1395
    line text NOT NULL
1396
);
1397

    
1398

    
1399
--
1400
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1401
--
1402

    
1403
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1404
    LANGUAGE sql
1405
    AS $_$
1406
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1407
$$||quote_nullable($1)||$$
1408
)$$)
1409
$_$;
1410

    
1411

    
1412
--
1413
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1414
--
1415

    
1416
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1417
usage:
1418
PERFORM util.explain2table($$
1419
query
1420
$$);
1421
';
1422

    
1423

    
1424
--
1425
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1426
--
1427

    
1428
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1429
    LANGUAGE sql IMMUTABLE
1430
    AS $_$
1431
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1432
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1433
) END
1434
$_$;
1435

    
1436

    
1437
--
1438
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1439
--
1440

    
1441
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1442
ensures that an array will always have proper non-NULL dimensions
1443
';
1444

    
1445

    
1446
--
1447
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1448
--
1449

    
1450
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1451
    LANGUAGE plpgsql
1452
    AS $_$
1453
DECLARE
1454
	PG_EXCEPTION_DETAIL text;
1455
	recreate_users_cmd text = util.save_drop_views(users);
1456
BEGIN
1457
	PERFORM util.eval(cmd);
1458
	PERFORM util.eval(recreate_users_cmd);
1459
EXCEPTION
1460
WHEN dependent_objects_still_exist THEN
1461
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1462
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1463
	users = array(SELECT * FROM util.regexp_matches_group(
1464
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1465
	IF util.is_empty(users) THEN RAISE; END IF;
1466
	PERFORM util.force_recreate(cmd, users);
1467
END;
1468
$_$;
1469

    
1470

    
1471
--
1472
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1473
--
1474

    
1475
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1476
idempotent
1477

    
1478
users: not necessary to provide this because it will be autopopulated
1479
';
1480

    
1481

    
1482
--
1483
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1484
--
1485

    
1486
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1487
    LANGUAGE plpgsql STRICT
1488
    AS $_$
1489
DECLARE
1490
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1491
$$||query;
1492
BEGIN
1493
	EXECUTE mk_view;
1494
EXCEPTION
1495
WHEN invalid_table_definition THEN
1496
	IF SQLERRM = 'cannot drop columns from view'
1497
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1498
	THEN
1499
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1500
		EXECUTE mk_view;
1501
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1502
	END IF;
1503
END;
1504
$_$;
1505

    
1506

    
1507
--
1508
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1509
--
1510

    
1511
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1512
idempotent
1513
';
1514

    
1515

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

    
1520
CREATE FUNCTION grants_users() RETURNS SETOF text
1521
    LANGUAGE sql IMMUTABLE
1522
    AS $$
1523
VALUES ('bien_read'), ('public_')
1524
$$;
1525

    
1526

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

    
1531
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1532
    LANGUAGE sql IMMUTABLE
1533
    AS $_$
1534
SELECT substring($2 for length($1)) = $1
1535
$_$;
1536

    
1537

    
1538
--
1539
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1540
--
1541

    
1542
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1543
    LANGUAGE sql STABLE
1544
    AS $_$
1545
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1546
$_$;
1547

    
1548

    
1549
--
1550
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1551
--
1552

    
1553
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1554
    LANGUAGE sql IMMUTABLE
1555
    AS $_$
1556
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1557
$_$;
1558

    
1559

    
1560
--
1561
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1562
--
1563

    
1564
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1565
avoids repeating the same value for each key
1566
';
1567

    
1568

    
1569
--
1570
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1571
--
1572

    
1573
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1574
    LANGUAGE sql IMMUTABLE
1575
    AS $_$
1576
SELECT COALESCE($1, $2)
1577
$_$;
1578

    
1579

    
1580
--
1581
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1582
--
1583

    
1584
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1585
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1586
';
1587

    
1588

    
1589
--
1590
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1591
--
1592

    
1593
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1594
    LANGUAGE sql
1595
    AS $_$
1596
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1597
$_$;
1598

    
1599

    
1600
--
1601
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1602
--
1603

    
1604
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1605
    LANGUAGE sql STABLE STRICT
1606
    AS $_$
1607
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1608
$_$;
1609

    
1610

    
1611
--
1612
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1613
--
1614

    
1615
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1616
    LANGUAGE sql IMMUTABLE
1617
    AS $_$
1618
SELECT util.array_length($1) = 0
1619
$_$;
1620

    
1621

    
1622
--
1623
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1624
--
1625

    
1626
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1627
    LANGUAGE sql IMMUTABLE
1628
    AS $_$
1629
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1630
$_$;
1631

    
1632

    
1633
--
1634
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1635
--
1636

    
1637
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1638
    LANGUAGE sql IMMUTABLE
1639
    AS $_$
1640
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1641
$_$;
1642

    
1643

    
1644
--
1645
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1646
--
1647

    
1648
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1649
    LANGUAGE sql STABLE
1650
    AS $_$
1651
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1652
$_$;
1653

    
1654

    
1655
--
1656
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1657
--
1658

    
1659
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1660
    LANGUAGE sql STABLE
1661
    AS $_$
1662
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1663
$_$;
1664

    
1665

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

    
1670
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1671
    LANGUAGE sql IMMUTABLE STRICT
1672
    AS $_$
1673
SELECT $1 || $3 || $2
1674
$_$;
1675

    
1676

    
1677
--
1678
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1679
--
1680

    
1681
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1682
    LANGUAGE sql IMMUTABLE
1683
    AS $_$
1684
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1685
$_$;
1686

    
1687

    
1688
--
1689
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1690
--
1691

    
1692
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1693
    LANGUAGE sql IMMUTABLE
1694
    AS $_$
1695
SELECT ltrim($1, $$
1696
$$)
1697
$_$;
1698

    
1699

    
1700
--
1701
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1702
--
1703

    
1704
CREATE FUNCTION map_filter_insert() RETURNS trigger
1705
    LANGUAGE plpgsql
1706
    AS $$
1707
BEGIN
1708
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1709
	RETURN new;
1710
END;
1711
$$;
1712

    
1713

    
1714
--
1715
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1716
--
1717

    
1718
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1719
    LANGUAGE plpgsql STABLE STRICT
1720
    AS $_$
1721
DECLARE
1722
    value text;
1723
BEGIN
1724
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1725
        INTO value USING key;
1726
    RETURN value;
1727
END;
1728
$_$;
1729

    
1730

    
1731
--
1732
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1733
--
1734

    
1735
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1736
    LANGUAGE sql IMMUTABLE
1737
    AS $_$
1738
SELECT util._map(util.nulls_map($1), $2)
1739
$_$;
1740

    
1741

    
1742
--
1743
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1744
--
1745

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

    
1749
[1] inlining of function calls, which is different from constant folding
1750
[2] _map()''s profiling query
1751
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1752
and map_nulls()''s profiling query
1753
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1754
both take ~920 ms.
1755
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.
1756
';
1757

    
1758

    
1759
--
1760
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1761
--
1762

    
1763
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1764
    LANGUAGE plpgsql STABLE STRICT
1765
    AS $_$
1766
BEGIN
1767
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1768
END;
1769
$_$;
1770

    
1771

    
1772
--
1773
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1774
--
1775

    
1776
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1777
    LANGUAGE sql
1778
    AS $_$
1779
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1780
$$||util.ltrim_nl($2));
1781
-- make sure the created table has the correct estimated row count
1782
SELECT util.analyze_($1);
1783
$_$;
1784

    
1785

    
1786
--
1787
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1788
--
1789

    
1790
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1791
idempotent
1792
';
1793

    
1794

    
1795
--
1796
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1797
--
1798

    
1799
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1800
    LANGUAGE sql
1801
    AS $_$
1802
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1803
$_$;
1804

    
1805

    
1806
--
1807
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1808
--
1809

    
1810
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1811
idempotent
1812
';
1813

    
1814

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

    
1819
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1820
    LANGUAGE sql STRICT
1821
    AS $_$
1822
SELECT util.create_if_not_exists($$
1823
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1824
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1825
||quote_literal($2)||$$;
1826
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1827
constant
1828
';
1829
$$)
1830
$_$;
1831

    
1832

    
1833
--
1834
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1835
--
1836

    
1837
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1838
idempotent
1839
';
1840

    
1841

    
1842
--
1843
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1844
--
1845

    
1846
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1847
    LANGUAGE plpgsql STRICT
1848
    AS $_$
1849
DECLARE
1850
    type regtype = util.typeof(expr, col.table_::text::regtype);
1851
    col_name_sql text = quote_ident(col.name);
1852
BEGIN
1853
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1854
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1855
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1856
$$||expr||$$;
1857
$$);
1858
END;
1859
$_$;
1860

    
1861

    
1862
--
1863
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1864
--
1865

    
1866
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1867
idempotent
1868
';
1869

    
1870

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

    
1875
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1876
    LANGUAGE sql STRICT
1877
    AS $_$
1878
SELECT util.create_if_not_exists($$
1879
CREATE TABLE $$||$1||$$
1880
(
1881
    LIKE util.map INCLUDING ALL
1882
);
1883

    
1884
CREATE TRIGGER map_filter_insert
1885
  BEFORE INSERT
1886
  ON $$||$1||$$
1887
  FOR EACH ROW
1888
  EXECUTE PROCEDURE util.map_filter_insert();
1889
$$)
1890
$_$;
1891

    
1892

    
1893
--
1894
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1895
--
1896

    
1897
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1898
    LANGUAGE sql IMMUTABLE
1899
    AS $_$
1900
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1901
$_$;
1902

    
1903

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

    
1908
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1909
    LANGUAGE sql IMMUTABLE
1910
    AS $_$
1911
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1912
$_$;
1913

    
1914

    
1915
--
1916
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1917
--
1918

    
1919
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1920
usage:
1921
for *1* schema arg:
1922
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1923
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1924
';
1925

    
1926

    
1927
--
1928
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1929
--
1930

    
1931
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1932
    LANGUAGE sql IMMUTABLE
1933
    AS $_$
1934
SELECT $$SET LOCAL search_path TO $$||$1
1935
$_$;
1936

    
1937

    
1938
--
1939
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1940
--
1941

    
1942
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1943
    LANGUAGE sql STRICT
1944
    AS $_$
1945
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1946
$_$;
1947

    
1948

    
1949
--
1950
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1951
--
1952

    
1953
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1954
idempotent
1955
';
1956

    
1957

    
1958
--
1959
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1960
--
1961

    
1962
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1963
    LANGUAGE plpgsql STRICT
1964
    AS $_$
1965
DECLARE
1966
	view_qual_name text = util.qual_name(view_);
1967
BEGIN
1968
	EXECUTE $$
1969
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1970
  RETURNS SETOF $$||view_||$$ AS
1971
$BODY1$
1972
SELECT * FROM $$||view_qual_name||$$
1973
ORDER BY sort_col
1974
LIMIT $1 OFFSET $2
1975
$BODY1$
1976
  LANGUAGE sql STABLE
1977
  COST 100
1978
  ROWS 1000
1979
$$;
1980
	
1981
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1982
END;
1983
$_$;
1984

    
1985

    
1986
--
1987
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1988
--
1989

    
1990
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1991
    LANGUAGE plpgsql STRICT
1992
    AS $_$
1993
DECLARE
1994
	view_qual_name text = util.qual_name(view_);
1995
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1996
BEGIN
1997
	EXECUTE $$
1998
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1999
  RETURNS integer AS
2000
$BODY1$
2001
SELECT $$||quote_ident(row_num_col)||$$
2002
FROM $$||view_qual_name||$$
2003
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2004
LIMIT 1
2005
$BODY1$
2006
  LANGUAGE sql STABLE
2007
  COST 100;
2008
$$;
2009
	
2010
	EXECUTE $$
2011
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2012
  RETURNS SETOF $$||view_||$$ AS
2013
$BODY1$
2014
SELECT * FROM $$||view_qual_name||$$
2015
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2016
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2017
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2018
ORDER BY $$||quote_ident(row_num_col)||$$
2019
$BODY1$
2020
  LANGUAGE sql STABLE
2021
  COST 100
2022
  ROWS 1000
2023
$$;
2024
	
2025
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2026
END;
2027
$_$;
2028

    
2029

    
2030
--
2031
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2032
--
2033

    
2034
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2035
    LANGUAGE plpgsql STRICT
2036
    AS $_$
2037
DECLARE
2038
	view_qual_name text = util.qual_name(view_);
2039
BEGIN
2040
	EXECUTE $$
2041
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2042
  RETURNS SETOF $$||view_||$$
2043
  SET enable_sort TO 'off'
2044
  AS
2045
$BODY1$
2046
SELECT * FROM $$||view_qual_name||$$($2, $3)
2047
$BODY1$
2048
  LANGUAGE sql STABLE
2049
  COST 100
2050
  ROWS 1000
2051
;
2052
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2053
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2054
If you want to run EXPLAIN and get expanded output, use the regular subset
2055
function instead. (When a config param is set on a function, EXPLAIN produces
2056
just a function scan.)
2057
';
2058
$$;
2059
END;
2060
$_$;
2061

    
2062

    
2063
--
2064
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2065
--
2066

    
2067
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2068
creates subset function which turns off enable_sort
2069
';
2070

    
2071

    
2072
--
2073
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2074
--
2075

    
2076
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2077
    LANGUAGE sql IMMUTABLE
2078
    AS $_$
2079
SELECT util.mk_set_search_path(util.schema_esc($1))
2080
$_$;
2081

    
2082

    
2083
--
2084
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2085
--
2086

    
2087
CREATE FUNCTION name(table_ regclass) RETURNS text
2088
    LANGUAGE sql STABLE
2089
    AS $_$
2090
SELECT relname::text FROM pg_class WHERE oid = $1
2091
$_$;
2092

    
2093

    
2094
--
2095
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2096
--
2097

    
2098
CREATE FUNCTION name(type regtype) RETURNS text
2099
    LANGUAGE sql STABLE STRICT
2100
    AS $_$
2101
SELECT typname::text FROM pg_type WHERE oid = $1
2102
$_$;
2103

    
2104

    
2105
--
2106
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2107
--
2108

    
2109
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2110
    LANGUAGE sql IMMUTABLE
2111
    AS $_$
2112
SELECT octet_length($1) >= util.namedatalen() - $2
2113
$_$;
2114

    
2115

    
2116
--
2117
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2118
--
2119

    
2120
CREATE FUNCTION namedatalen() RETURNS integer
2121
    LANGUAGE sql IMMUTABLE
2122
    AS $$
2123
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2124
$$;
2125

    
2126

    
2127
--
2128
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2129
--
2130

    
2131
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2132
    LANGUAGE sql IMMUTABLE
2133
    AS $_$
2134
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2135
$_$;
2136

    
2137

    
2138
--
2139
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2140
--
2141

    
2142
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2143
    LANGUAGE sql IMMUTABLE
2144
    AS $_$
2145
SELECT $1 IS NOT NULL
2146
$_$;
2147

    
2148

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

    
2153
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2154
    LANGUAGE sql IMMUTABLE
2155
    AS $_$
2156
SELECT util.hstore($1, NULL) || '*=>*'
2157
$_$;
2158

    
2159

    
2160
--
2161
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2162
--
2163

    
2164
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2165
for use with _map()
2166
';
2167

    
2168

    
2169
--
2170
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2171
--
2172

    
2173
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2174
    LANGUAGE sql IMMUTABLE
2175
    AS $_$
2176
SELECT $2 + COALESCE($1, 0)
2177
$_$;
2178

    
2179

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

    
2184
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2185
    LANGUAGE sql IMMUTABLE
2186
    AS $_$
2187
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2188
$_$;
2189

    
2190

    
2191
--
2192
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2193
--
2194

    
2195
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2196
    LANGUAGE sql STABLE STRICT
2197
    SET search_path TO pg_temp
2198
    AS $_$
2199
SELECT $1::text
2200
$_$;
2201

    
2202

    
2203
--
2204
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2205
--
2206

    
2207
CREATE FUNCTION qual_name(type regtype) RETURNS text
2208
    LANGUAGE sql STABLE STRICT
2209
    SET search_path TO pg_temp
2210
    AS $_$
2211
SELECT $1::text
2212
$_$;
2213

    
2214

    
2215
--
2216
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2217
--
2218

    
2219
COMMENT ON FUNCTION qual_name(type regtype) IS '
2220
a type''s schema-qualified name
2221
';
2222

    
2223

    
2224
--
2225
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2226
--
2227

    
2228
CREATE FUNCTION qual_name(type unknown) RETURNS text
2229
    LANGUAGE sql STABLE STRICT
2230
    AS $_$
2231
SELECT util.qual_name($1::text::regtype)
2232
$_$;
2233

    
2234

    
2235
--
2236
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2237
--
2238

    
2239
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2240
    LANGUAGE sql IMMUTABLE
2241
    AS $_$
2242
SELECT quote_nullable($1)||$$::$$||pg_typeof($1)
2243
$_$;
2244

    
2245

    
2246
--
2247
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2248
--
2249

    
2250
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2251
    LANGUAGE sql IMMUTABLE STRICT
2252
    AS $_$
2253
SELECT util.raise_notice('ERROR:  '||$1)
2254
$_$;
2255

    
2256

    
2257
--
2258
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2259
--
2260

    
2261
CREATE FUNCTION raise_notice(msg text) RETURNS void
2262
    LANGUAGE plpgsql IMMUTABLE STRICT
2263
    AS $$
2264
BEGIN
2265
	RAISE NOTICE '%', msg;
2266
END;
2267
$$;
2268

    
2269

    
2270
--
2271
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2272
--
2273

    
2274
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2275
    LANGUAGE plpgsql IMMUTABLE STRICT
2276
    AS $$
2277
BEGIN
2278
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2279
END;
2280
$$;
2281

    
2282

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

    
2287
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2288
    LANGUAGE sql IMMUTABLE
2289
    AS $_$
2290
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2291
$_$;
2292

    
2293

    
2294
--
2295
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2296
--
2297

    
2298
CREATE FUNCTION regexp_quote(str text) RETURNS text
2299
    LANGUAGE sql IMMUTABLE
2300
    AS $_$
2301
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2302
$_$;
2303

    
2304

    
2305
--
2306
-- Name: regproc(regprocedure); Type: FUNCTION; Schema: util; Owner: -
2307
--
2308

    
2309
CREATE FUNCTION regproc(func regprocedure) RETURNS regproc
2310
    LANGUAGE sql IMMUTABLE
2311
    AS $_$
2312
SELECT $1::oid::regproc
2313
$_$;
2314

    
2315

    
2316
--
2317
-- Name: regprocedure(regproc); Type: FUNCTION; Schema: util; Owner: -
2318
--
2319

    
2320
CREATE FUNCTION regprocedure(func regproc) RETURNS regprocedure
2321
    LANGUAGE sql IMMUTABLE
2322
    AS $_$
2323
SELECT $1::oid::regprocedure
2324
$_$;
2325

    
2326

    
2327
--
2328
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2329
--
2330

    
2331
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2332
    LANGUAGE sql STABLE
2333
    AS $_$
2334
SELECT util.relation_type(util.relation_type_char($1))
2335
$_$;
2336

    
2337

    
2338
--
2339
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2340
--
2341

    
2342
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2343
    LANGUAGE sql IMMUTABLE
2344
    AS $_$
2345
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2346
$_$;
2347

    
2348

    
2349
--
2350
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2351
--
2352

    
2353
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2354
    LANGUAGE sql STABLE
2355
    AS $_$
2356
SELECT relkind FROM pg_class WHERE oid = $1
2357
$_$;
2358

    
2359

    
2360
--
2361
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2362
--
2363

    
2364
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2365
    LANGUAGE sql
2366
    AS $_$
2367
/* can't have in_table/out_table inherit from *each other*, because inheritance
2368
also causes the rows of the parent table to be included in the child table.
2369
instead, they need to inherit from a common, empty table. */
2370
SELECT util.drop_table($4, force := true);
2371
SELECT util.copy_struct($2, $4);
2372
SELECT util.inherit($2, $4);
2373
SELECT util.inherit($3, $4);
2374

    
2375
SELECT util.rematerialize_query($1, $$
2376
SELECT * FROM util.diff(
2377
  $$||quote_nullable($2)||$$::regclass
2378
, $$||quote_nullable($3)||$$::regclass
2379
, NULL::$$||$4||$$)
2380
$$);
2381

    
2382
/* the table unfortunately cannot be *materialized* in human-readable form,
2383
because this would create column name collisions between the two sides */
2384
SELECT util.append_comment($1, '
2385
to view this table in human-readable form (with each side''s tuple column
2386
expanded to its component fields):
2387
SELECT (left_).*, (right_).* FROM '||$1||';
2388
');
2389
$_$;
2390

    
2391

    
2392
--
2393
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2394
--
2395

    
2396
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2397
type_table (*required*): table to create as the shared base type
2398
';
2399

    
2400

    
2401
--
2402
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2403
--
2404

    
2405
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2406
    LANGUAGE sql
2407
    AS $_$
2408
SELECT util.drop_table($1);
2409
SELECT util.materialize_query($1, $2);
2410
$_$;
2411

    
2412

    
2413
--
2414
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2415
--
2416

    
2417
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2418
idempotent, but repeats action each time
2419
';
2420

    
2421

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

    
2426
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2427
    LANGUAGE sql
2428
    AS $_$
2429
SELECT util.drop_table($1);
2430
SELECT util.materialize_view($1, $2);
2431
$_$;
2432

    
2433

    
2434
--
2435
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2436
--
2437

    
2438
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2439
idempotent, but repeats action each time
2440
';
2441

    
2442

    
2443
--
2444
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2445
--
2446

    
2447
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2448
    LANGUAGE sql STRICT
2449
    AS $_$
2450
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2451
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2452
FROM util.col_names($1::text::regtype) f (name);
2453
SELECT NULL::void; -- don't fold away functions called in previous query
2454
$_$;
2455

    
2456

    
2457
--
2458
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2459
--
2460

    
2461
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2462
idempotent
2463
';
2464

    
2465

    
2466
--
2467
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2468
--
2469

    
2470
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2471
    LANGUAGE sql
2472
    AS $_$
2473
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2474
included in the debug SQL */
2475
SELECT util.rename_relation(util.qual_name($1), $2)
2476
$_$;
2477

    
2478

    
2479
--
2480
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2481
--
2482

    
2483
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2484
    LANGUAGE sql
2485
    AS $_$
2486
/* 'ALTER TABLE can be used with views too'
2487
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2488
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2489
||quote_ident($2))
2490
$_$;
2491

    
2492

    
2493
--
2494
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2495
--
2496

    
2497
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2498
idempotent
2499
';
2500

    
2501

    
2502
--
2503
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2504
--
2505

    
2506
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2507
    LANGUAGE sql IMMUTABLE
2508
    AS $_$
2509
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2510
$_$;
2511

    
2512

    
2513
--
2514
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2515
--
2516

    
2517
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2518
max_prefix_len: when str may have been truncated (eg. as a table name) due to the prepending of a prefix, support prefixes up to this length 
2519
';
2520

    
2521

    
2522
--
2523
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2524
--
2525

    
2526
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2527
    LANGUAGE sql STRICT
2528
    AS $_$
2529
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2530
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2531
SELECT util.set_col_names($1, $2);
2532
$_$;
2533

    
2534

    
2535
--
2536
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2537
--
2538

    
2539
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2540
idempotent.
2541
alters the names table, so it will need to be repopulated after running this function.
2542
';
2543

    
2544

    
2545
--
2546
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2547
--
2548

    
2549
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2550
    LANGUAGE sql STRICT
2551
    AS $_$
2552
SELECT util.drop_table($1);
2553
SELECT util.mk_map_table($1);
2554
$_$;
2555

    
2556

    
2557
--
2558
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2559
--
2560

    
2561
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2562
    LANGUAGE sql IMMUTABLE
2563
    AS $_$
2564
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2565
$_$;
2566

    
2567

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

    
2572
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2573
    LANGUAGE plpgsql STRICT
2574
    AS $_$
2575
DECLARE
2576
	result text = NULL;
2577
BEGIN
2578
	BEGIN
2579
		result = util.show_create_view(view_);
2580
		PERFORM util.eval($$DROP VIEW $$||view_);
2581
	EXCEPTION
2582
		WHEN undefined_table THEN NULL;
2583
	END;
2584
	RETURN result;
2585
END;
2586
$_$;
2587

    
2588

    
2589
--
2590
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2591
--
2592

    
2593
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2594
    LANGUAGE sql
2595
    AS $_$
2596
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2597
$_$;
2598

    
2599

    
2600
--
2601
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2602
--
2603

    
2604
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2605
    LANGUAGE sql STABLE
2606
    AS $_$
2607
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2608
$_$;
2609

    
2610

    
2611
--
2612
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2613
--
2614

    
2615
CREATE FUNCTION schema(table_ regclass) RETURNS text
2616
    LANGUAGE sql STABLE
2617
    AS $_$
2618
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2619
$_$;
2620

    
2621

    
2622
--
2623
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2624
--
2625

    
2626
CREATE FUNCTION schema(type regtype) RETURNS text
2627
    LANGUAGE sql STABLE
2628
    AS $_$
2629
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2630
$_$;
2631

    
2632

    
2633
--
2634
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2635
--
2636

    
2637
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2638
    LANGUAGE sql STABLE
2639
    AS $_$
2640
SELECT util.schema(pg_typeof($1))
2641
$_$;
2642

    
2643

    
2644
--
2645
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2646
--
2647

    
2648
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2649
    LANGUAGE sql STABLE
2650
    AS $_$
2651
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2652
$_$;
2653

    
2654

    
2655
--
2656
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2657
--
2658

    
2659
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2660
a schema bundle is a group of schemas with a common prefix
2661
';
2662

    
2663

    
2664
--
2665
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2666
--
2667

    
2668
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2669
    LANGUAGE sql
2670
    AS $_$
2671
SELECT util.schema_rename(old_schema,
2672
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2673
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2674
SELECT NULL::void; -- don't fold away functions called in previous query
2675
$_$;
2676

    
2677

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

    
2682
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2683
    LANGUAGE plpgsql
2684
    AS $$
2685
BEGIN
2686
	-- don't schema_bundle_rm() the schema_bundle to keep!
2687
	IF replace = with_ THEN RETURN; END IF;
2688
	
2689
	PERFORM util.schema_bundle_rm(replace);
2690
	PERFORM util.schema_bundle_rename(with_, replace);
2691
END;
2692
$$;
2693

    
2694

    
2695
--
2696
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2697
--
2698

    
2699
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2700
    LANGUAGE sql
2701
    AS $_$
2702
SELECT util.schema_rm(schema)
2703
FROM util.schema_bundle_get_schemas($1) f (schema);
2704
SELECT NULL::void; -- don't fold away functions called in previous query
2705
$_$;
2706

    
2707

    
2708
--
2709
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2710
--
2711

    
2712
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2713
    LANGUAGE sql STABLE
2714
    AS $_$
2715
SELECT quote_ident(util.schema($1))
2716
$_$;
2717

    
2718

    
2719
--
2720
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2721
--
2722

    
2723
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2724
    LANGUAGE sql IMMUTABLE
2725
    AS $_$
2726
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2727
$_$;
2728

    
2729

    
2730
--
2731
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2732
--
2733

    
2734
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2735
    LANGUAGE sql STABLE
2736
    AS $_$
2737
SELECT oid FROM pg_namespace WHERE nspname = $1
2738
$_$;
2739

    
2740

    
2741
--
2742
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2743
--
2744

    
2745
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2746
    LANGUAGE sql
2747
    AS $_$
2748
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2749
$_$;
2750

    
2751

    
2752
--
2753
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2754
--
2755

    
2756
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2757
    LANGUAGE plpgsql
2758
    AS $$
2759
BEGIN
2760
	-- don't schema_rm() the schema to keep!
2761
	IF replace = with_ THEN RETURN; END IF;
2762
	
2763
	PERFORM util.schema_rm(replace);
2764
	PERFORM util.schema_rename(with_, replace);
2765
END;
2766
$$;
2767

    
2768

    
2769
--
2770
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION schema_rm(schema text) RETURNS void
2774
    LANGUAGE sql
2775
    AS $_$
2776
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2777
$_$;
2778

    
2779

    
2780
--
2781
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2782
--
2783

    
2784
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2785
    LANGUAGE sql STRICT
2786
    AS $_$
2787
SELECT util.eval(
2788
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2789
$_$;
2790

    
2791

    
2792
--
2793
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2794
--
2795

    
2796
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2797
    LANGUAGE plpgsql STRICT
2798
    AS $_$
2799
DECLARE
2800
    old text[] = ARRAY(SELECT util.col_names(table_));
2801
    new text[] = ARRAY(SELECT util.map_values(names));
2802
BEGIN
2803
    old = old[1:array_length(new, 1)]; -- truncate to same length
2804
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2805
||$$ TO $$||quote_ident(value))
2806
    FROM each(hstore(old, new))
2807
    WHERE value != key -- not same name
2808
    ;
2809
END;
2810
$_$;
2811

    
2812

    
2813
--
2814
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2815
--
2816

    
2817
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2818
idempotent
2819
';
2820

    
2821

    
2822
--
2823
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2824
--
2825

    
2826
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2827
    LANGUAGE plpgsql STRICT
2828
    AS $_$
2829
DECLARE
2830
	row_ util.map;
2831
BEGIN
2832
	-- rename any metadata cols rather than re-adding them with new names
2833
	BEGIN
2834
		PERFORM util.set_col_names(table_, names);
2835
	EXCEPTION
2836
		WHEN array_subscript_error THEN -- selective suppress
2837
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2838
				-- metadata cols not yet added
2839
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2840
			END IF;
2841
	END;
2842
	
2843
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2844
	LOOP
2845
		PERFORM util.mk_const_col((table_, row_."to"),
2846
			substring(row_."from" from 2));
2847
	END LOOP;
2848
	
2849
	PERFORM util.set_col_names(table_, names);
2850
END;
2851
$_$;
2852

    
2853

    
2854
--
2855
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2856
--
2857

    
2858
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2859
idempotent.
2860
the metadata mappings must be *last* in the names table.
2861
';
2862

    
2863

    
2864
--
2865
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2866
--
2867

    
2868
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2869
    LANGUAGE plpgsql STRICT
2870
    AS $_$
2871
DECLARE
2872
    sql text = $$ALTER TABLE $$||table_||$$
2873
$$||NULLIF(array_to_string(ARRAY(
2874
    SELECT
2875
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2876
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2877
    FROM
2878
    (
2879
        SELECT
2880
          quote_ident(col_name) AS col_name_sql
2881
        , util.col_type((table_, col_name)) AS curr_type
2882
        , type AS target_type
2883
        FROM unnest(col_casts)
2884
    ) s
2885
    WHERE curr_type != target_type
2886
), '
2887
, '), '');
2888
BEGIN
2889
    PERFORM util.debug_print_sql(sql);
2890
    EXECUTE COALESCE(sql, '');
2891
END;
2892
$_$;
2893

    
2894

    
2895
--
2896
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2897
--
2898

    
2899
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2900
idempotent
2901
';
2902

    
2903

    
2904
--
2905
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2906
--
2907

    
2908
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2909
    LANGUAGE sql STRICT
2910
    AS $_$
2911
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2912
$_$;
2913

    
2914

    
2915
--
2916
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2917
--
2918

    
2919
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2920
    LANGUAGE sql STABLE
2921
    AS $_$
2922
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2923
$$||util.show_grants_for($1)
2924
$_$;
2925

    
2926

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

    
2931
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2932
    LANGUAGE sql STABLE
2933
    AS $_$
2934
SELECT string_agg(cmd, '')
2935
FROM
2936
(
2937
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2938
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2939
$$ ELSE '' END) AS cmd
2940
	FROM util.grants_users() f (user_)
2941
) s
2942
$_$;
2943

    
2944

    
2945
--
2946
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2947
--
2948

    
2949
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2950
    LANGUAGE sql STABLE
2951
    AS $_$
2952
SELECT oid FROM pg_class
2953
WHERE relkind = ANY($3) AND relname ~ $1
2954
AND util.schema_matches(util.schema(relnamespace), $2)
2955
ORDER BY relname
2956
$_$;
2957

    
2958

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

    
2963
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2964
    LANGUAGE sql STABLE
2965
    AS $_$
2966
SELECT view_
2967
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2968
WHERE util.schema(view_) = $2
2969
$_$;
2970

    
2971

    
2972
--
2973
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2974
--
2975

    
2976
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2977
    LANGUAGE plpgsql STABLE STRICT
2978
    AS $_$
2979
DECLARE
2980
    hstore hstore;
2981
BEGIN
2982
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2983
        table_||$$))$$ INTO STRICT hstore;
2984
    RETURN hstore;
2985
END;
2986
$_$;
2987

    
2988

    
2989
--
2990
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2991
--
2992

    
2993
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2994
    LANGUAGE sql STABLE STRICT
2995
    AS $_$
2996
SELECT COUNT(*) > 0 FROM pg_constraint
2997
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2998
$_$;
2999

    
3000

    
3001
--
3002
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3003
--
3004

    
3005
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3006
gets whether a status flag is set by the presence of a table constraint
3007
';
3008

    
3009

    
3010
--
3011
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3012
--
3013

    
3014
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3015
    LANGUAGE sql STRICT
3016
    AS $_$
3017
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3018
||quote_ident($2)||$$ CHECK (true)$$)
3019
$_$;
3020

    
3021

    
3022
--
3023
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3024
--
3025

    
3026
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3027
stores a status flag by the presence of a table constraint.
3028
idempotent.
3029
';
3030

    
3031

    
3032
--
3033
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3034
--
3035

    
3036
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3037
    LANGUAGE sql STABLE STRICT
3038
    AS $_$
3039
SELECT util.table_flag__get($1, 'nulls_mapped')
3040
$_$;
3041

    
3042

    
3043
--
3044
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3045
--
3046

    
3047
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3048
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3049
';
3050

    
3051

    
3052
--
3053
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3054
--
3055

    
3056
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3057
    LANGUAGE sql STRICT
3058
    AS $_$
3059
SELECT util.table_flag__set($1, 'nulls_mapped')
3060
$_$;
3061

    
3062

    
3063
--
3064
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3065
--
3066

    
3067
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3068
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3069
idempotent.
3070
';
3071

    
3072

    
3073
--
3074
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3075
--
3076

    
3077
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3078
    LANGUAGE plpgsql STRICT
3079
    AS $_$
3080
DECLARE
3081
    row record;
3082
BEGIN
3083
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3084
    LOOP
3085
        IF row.global_name != row.name THEN
3086
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3087
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3088
        END IF;
3089
    END LOOP;
3090
END;
3091
$_$;
3092

    
3093

    
3094
--
3095
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3096
--
3097

    
3098
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3099
idempotent
3100
';
3101

    
3102

    
3103
--
3104
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3105
--
3106

    
3107
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3108
    LANGUAGE sql STRICT
3109
    AS $_$
3110
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3111
SELECT NULL::void; -- don't fold away functions called in previous query
3112
$_$;
3113

    
3114

    
3115
--
3116
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3117
--
3118

    
3119
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3120
trims table_ to include only columns in the original data.
3121
idempotent.
3122
';
3123

    
3124

    
3125
--
3126
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3127
--
3128

    
3129
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3130
    LANGUAGE plpgsql STRICT
3131
    AS $_$
3132
BEGIN
3133
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3134
END;
3135
$_$;
3136

    
3137

    
3138
--
3139
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3140
--
3141

    
3142
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3143
idempotent
3144
';
3145

    
3146

    
3147
--
3148
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3149
--
3150

    
3151
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3152
    LANGUAGE sql IMMUTABLE
3153
    AS $_$
3154
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3155
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3156
$_$;
3157

    
3158

    
3159
--
3160
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3161
--
3162

    
3163
CREATE FUNCTION try_create(sql text) RETURNS void
3164
    LANGUAGE plpgsql STRICT
3165
    AS $$
3166
BEGIN
3167
    PERFORM util.eval(sql);
3168
EXCEPTION
3169
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3170
    WHEN undefined_column THEN NULL;
3171
    WHEN duplicate_column THEN NULL;
3172
END;
3173
$$;
3174

    
3175

    
3176
--
3177
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3178
--
3179

    
3180
COMMENT ON FUNCTION try_create(sql text) IS '
3181
idempotent
3182
';
3183

    
3184

    
3185
--
3186
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3187
--
3188

    
3189
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3190
    LANGUAGE sql STRICT
3191
    AS $_$
3192
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3193
$_$;
3194

    
3195

    
3196
--
3197
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3198
--
3199

    
3200
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3201
idempotent
3202
';
3203

    
3204

    
3205
--
3206
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3207
--
3208

    
3209
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3210
    LANGUAGE sql IMMUTABLE
3211
    AS $_$
3212
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3213
$_$;
3214

    
3215

    
3216
--
3217
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3218
--
3219

    
3220
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3221
a type''s NOT NULL qualifier
3222
';
3223

    
3224

    
3225
--
3226
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3227
--
3228

    
3229
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3230
    LANGUAGE plpgsql STABLE
3231
    AS $_$
3232
DECLARE
3233
    type regtype;
3234
BEGIN
3235
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3236
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3237
    RETURN type;
3238
END;
3239
$_$;
3240

    
3241

    
3242
--
3243
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3244
--
3245

    
3246
CREATE AGGREGATE all_same(anyelement) (
3247
    SFUNC = all_same_transform,
3248
    STYPE = anyarray,
3249
    FINALFUNC = all_same_final
3250
);
3251

    
3252

    
3253
--
3254
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3255
--
3256

    
3257
COMMENT ON AGGREGATE all_same(anyelement) IS '
3258
includes NULLs in comparison
3259
';
3260

    
3261

    
3262
--
3263
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3264
--
3265

    
3266
CREATE AGGREGATE join_strs(text, text) (
3267
    SFUNC = join_strs_transform,
3268
    STYPE = text
3269
);
3270

    
3271

    
3272
--
3273
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3274
--
3275

    
3276
CREATE OPERATOR -> (
3277
    PROCEDURE = map_get,
3278
    LEFTARG = regclass,
3279
    RIGHTARG = text
3280
);
3281

    
3282

    
3283
--
3284
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3285
--
3286

    
3287
CREATE OPERATOR => (
3288
    PROCEDURE = hstore,
3289
    LEFTARG = text[],
3290
    RIGHTARG = text
3291
);
3292

    
3293

    
3294
--
3295
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3296
--
3297

    
3298
COMMENT ON OPERATOR => (text[], text) IS '
3299
usage: array[''key1'', ...]::text[] => ''value''
3300
';
3301

    
3302

    
3303
--
3304
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3305
--
3306

    
3307
CREATE OPERATOR ?*>= (
3308
    PROCEDURE = is_populated_more_often_than,
3309
    LEFTARG = anyelement,
3310
    RIGHTARG = anyelement
3311
);
3312

    
3313

    
3314
--
3315
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3316
--
3317

    
3318
CREATE OPERATOR ?>= (
3319
    PROCEDURE = is_more_complete_than,
3320
    LEFTARG = anyelement,
3321
    RIGHTARG = anyelement
3322
);
3323

    
3324

    
3325
--
3326
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3327
--
3328

    
3329
CREATE OPERATOR ||% (
3330
    PROCEDURE = concat_esc,
3331
    LEFTARG = text,
3332
    RIGHTARG = text
3333
);
3334

    
3335

    
3336
--
3337
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3338
--
3339

    
3340
COMMENT ON OPERATOR ||% (text, text) IS '
3341
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3342
';
3343

    
3344

    
3345
--
3346
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3347
--
3348

    
3349
CREATE TABLE map (
3350
    "from" text NOT NULL,
3351
    "to" text,
3352
    filter text,
3353
    notes text
3354
);
3355

    
3356

    
3357
--
3358
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3359
--
3360

    
3361

    
3362

    
3363
--
3364
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3365
--
3366

    
3367

    
3368

    
3369
--
3370
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3371
--
3372

    
3373
ALTER TABLE ONLY map
3374
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3375

    
3376

    
3377
--
3378
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3379
--
3380

    
3381
ALTER TABLE ONLY map
3382
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3383

    
3384

    
3385
--
3386
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3387
--
3388

    
3389
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3390

    
3391

    
3392
--
3393
-- PostgreSQL database dump complete
3394
--
3395

    
(19-19/29)