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: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

    
78
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
79
    LANGUAGE sql IMMUTABLE
80
    AS $_$
81
SELECT $1 = $2
82
$_$;
83

    
84

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

    
89
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
90
    LANGUAGE sql IMMUTABLE
91
    AS $_$
92
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
93
$_$;
94

    
95

    
96
--
97
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
98
--
99

    
100
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
101
    LANGUAGE sql IMMUTABLE
102
    AS $_$
103
SELECT bool_and(value)
104
FROM
105
(VALUES
106
      ($1)
107
    , ($2)
108
    , ($3)
109
    , ($4)
110
    , ($5)
111
)
112
AS v (value)
113
$_$;
114

    
115

    
116
--
117
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
118
--
119

    
120
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
121
_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.
122
';
123

    
124

    
125
--
126
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
127
--
128

    
129
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
130
    LANGUAGE sql IMMUTABLE
131
    AS $_$
132
SELECT avg(value)
133
FROM
134
(VALUES
135
      ($1)
136
    , ($2)
137
    , ($3)
138
    , ($4)
139
    , ($5)
140
)
141
AS v (value)
142
$_$;
143

    
144

    
145
--
146
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
147
--
148

    
149
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
150
    LANGUAGE sql IMMUTABLE STRICT
151
    AS $_$
152
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)
153
FROM 
154
(
155
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
156
    UNION ALL
157
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
158
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
159
)
160
matches (g)
161
$_$;
162

    
163

    
164
--
165
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
166
--
167

    
168
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
169
    LANGUAGE sql IMMUTABLE
170
    AS $_$
171
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
172
FROM
173
(VALUES
174
      ($1)
175
    , ($2/60)
176
    , ($3/60/60)
177
)
178
AS v (value)
179
$_$;
180

    
181

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

    
186
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
187
    LANGUAGE sql IMMUTABLE
188
    AS $_$
189
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
190
$_$;
191

    
192

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

    
197
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
198
    LANGUAGE sql IMMUTABLE
199
    AS $_$
200
SELECT $1 = $2
201
$_$;
202

    
203

    
204
--
205
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
206
--
207

    
208
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
209
    LANGUAGE sql IMMUTABLE
210
    AS $_$
211
-- Fix dates after threshold date
212
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
213
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
214
$_$;
215

    
216

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

    
221
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
222
    LANGUAGE sql IMMUTABLE
223
    AS $_$
224
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
225
$_$;
226

    
227

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

    
232
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
233
    LANGUAGE sql IMMUTABLE
234
    AS $_$
235
SELECT util._if($1 != '', $2, $3)
236
$_$;
237

    
238

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

    
243
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
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: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
252
--
253

    
254
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
255
    LANGUAGE sql IMMUTABLE
256
    AS $_$
257
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
258
$_$;
259

    
260

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

    
265
CREATE FUNCTION _label(label text, value text) RETURNS text
266
    LANGUAGE sql IMMUTABLE
267
    AS $_$
268
SELECT coalesce($1 || ': ', '') || $2
269
$_$;
270

    
271

    
272
--
273
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
274
--
275

    
276
CREATE FUNCTION _lowercase(value text) RETURNS text
277
    LANGUAGE sql IMMUTABLE
278
    AS $_$
279
SELECT lower($1)
280
$_$;
281

    
282

    
283
--
284
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
285
--
286

    
287
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
288
    LANGUAGE plpgsql IMMUTABLE STRICT
289
    AS $$
290
DECLARE
291
    result value%TYPE := util._map(map, value::text)::unknown;
292
BEGIN
293
    RETURN result;
294
END;
295
$$;
296

    
297

    
298
--
299
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
300
--
301

    
302
CREATE FUNCTION _map(map hstore, value text) RETURNS text
303
    LANGUAGE plpgsql IMMUTABLE STRICT
304
    AS $$
305
DECLARE
306
    match text := map -> value;
307
BEGIN
308
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
309
        match := map -> '*'; -- use default entry
310
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
311
        END IF;
312
    END IF;
313
    
314
    -- Interpret result
315
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
316
    ELSIF match = '*' THEN RETURN value;
317
    ELSE RETURN match;
318
    END IF;
319
END;
320
$$;
321

    
322

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

    
327
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
328
    LANGUAGE sql IMMUTABLE
329
    AS $_$
330
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
331
$_$;
332

    
333

    
334
--
335
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
336
--
337

    
338
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
339
    LANGUAGE sql IMMUTABLE
340
    AS $_$
341
SELECT util.join_strs(value, '; ')
342
FROM
343
(
344
    SELECT *
345
    FROM
346
    (
347
        SELECT
348
        DISTINCT ON (value)
349
        *
350
        FROM
351
        (VALUES
352
              (1, $1)
353
            , (2, $2)
354
            , (3, $3)
355
            , (4, $4)
356
            , (5, $5)
357
            , (6, $6)
358
            , (7, $7)
359
            , (8, $8)
360
            , (9, $9)
361
            , (10, $10)
362
        )
363
        AS v (sort_order, value)
364
        WHERE value IS NOT NULL
365
    )
366
    AS v
367
    ORDER BY sort_order
368
)
369
AS v
370
$_$;
371

    
372

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

    
377
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
378
    LANGUAGE sql IMMUTABLE
379
    AS $_$
380
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
381
$_$;
382

    
383

    
384
--
385
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
386
--
387

    
388
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
389
    LANGUAGE sql IMMUTABLE
390
    AS $_$
391
SELECT util.join_strs(value, ' ')
392
FROM
393
(
394
    SELECT *
395
    FROM
396
    (
397
        SELECT
398
        DISTINCT ON (value)
399
        *
400
        FROM
401
        (VALUES
402
              (1, $1)
403
            , (2, $2)
404
            , (3, $3)
405
            , (4, $4)
406
            , (5, $5)
407
            , (6, $6)
408
            , (7, $7)
409
            , (8, $8)
410
            , (9, $9)
411
            , (10, $10)
412
        )
413
        AS v (sort_order, value)
414
        WHERE value IS NOT NULL
415
    )
416
    AS v
417
    ORDER BY sort_order
418
)
419
AS v
420
$_$;
421

    
422

    
423
--
424
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
425
--
426

    
427
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
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
431
$_$;
432

    
433

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

    
438
CREATE FUNCTION _not(value boolean) RETURNS boolean
439
    LANGUAGE sql IMMUTABLE
440
    AS $_$
441
SELECT NOT $1
442
$_$;
443

    
444

    
445
--
446
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
447
--
448

    
449
CREATE FUNCTION _now() RETURNS timestamp with time zone
450
    LANGUAGE sql STABLE
451
    AS $$
452
SELECT now()
453
$$;
454

    
455

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

    
460
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
461
    LANGUAGE sql IMMUTABLE
462
    AS $_$
463
SELECT util."_nullIf"($1, $2, $3::util.datatype)
464
$_$;
465

    
466

    
467
--
468
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
469
--
470

    
471
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
472
    LANGUAGE plpgsql IMMUTABLE
473
    AS $$
474
DECLARE
475
    type util.datatype NOT NULL := type; -- add NOT NULL
476
BEGIN
477
    IF type = 'str' THEN RETURN nullif(value::text, "null");
478
    -- Invalid value is ignored, but invalid null value generates error
479
    ELSIF type = 'float' THEN
480
        DECLARE
481
            -- Outside the try block so that invalid null value generates error
482
            "null" double precision := "null"::double precision;
483
        BEGIN
484
            RETURN nullif(value::double precision, "null");
485
        EXCEPTION
486
            WHEN data_exception THEN RETURN value; -- ignore invalid value
487
        END;
488
    END IF;
489
END;
490
$$;
491

    
492

    
493
--
494
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
495
--
496

    
497
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
498
    LANGUAGE sql IMMUTABLE
499
    AS $_$
500
SELECT bool_or(value)
501
FROM
502
(VALUES
503
      ($1)
504
    , ($2)
505
    , ($3)
506
    , ($4)
507
    , ($5)
508
)
509
AS v (value)
510
$_$;
511

    
512

    
513
--
514
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
515
--
516

    
517
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
518
_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.
519
';
520

    
521

    
522
--
523
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
524
--
525

    
526
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
527
    LANGUAGE sql IMMUTABLE
528
    AS $_$
529
SELECT $2 - $1
530
$_$;
531

    
532

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

    
537
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
538
    LANGUAGE sql IMMUTABLE
539
    AS $_$
540
SELECT regexp_split_to_table($1, $2)
541
$_$;
542

    
543

    
544
--
545
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
546
--
547

    
548
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
549
    LANGUAGE sql STABLE STRICT
550
    AS $_$
551
SELECT util.derived_cols($1, $2)
552
UNION
553
SELECT util.eval2set($$
554
SELECT col
555
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
556
JOIN $$||$2||$$ ON "to" = col
557
WHERE "from" LIKE ':%'
558
$$, NULL::text)
559
$_$;
560

    
561

    
562
--
563
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
564
--
565

    
566
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
567
gets table_''s added columns (all the columns not in the original data)
568
';
569

    
570

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

    
575
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
576
    LANGUAGE sql IMMUTABLE
577
    AS $_$
578
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
579
$_$;
580

    
581

    
582
--
583
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
584
--
585

    
586
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
587
    LANGUAGE plpgsql IMMUTABLE
588
    AS $$
589
DECLARE
590
	value_cmp         state%TYPE = ARRAY[value];
591
	state             state%TYPE = COALESCE(state, value_cmp);
592
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
593
BEGIN
594
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
595
END;
596
$$;
597

    
598

    
599
--
600
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
604
    LANGUAGE sql
605
    AS $_$
606
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
607
$_$;
608

    
609

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

    
614
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
615
    LANGUAGE sql STRICT
616
    AS $_$
617
SELECT util.set_comment($1, concat(util.comment($1), $2))
618
$_$;
619

    
620

    
621
--
622
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
623
--
624

    
625
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
626
comment: must start and end with a newline
627
';
628

    
629

    
630
--
631
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
635
    LANGUAGE sql IMMUTABLE
636
    AS $_$
637
SELECT pg_catalog.array_fill($1, ARRAY[$2])
638
$_$;
639

    
640

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

    
645
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
646
    LANGUAGE sql IMMUTABLE
647
    AS $_$
648
SELECT util.array_length($1, 1)
649
$_$;
650

    
651

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

    
656
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
657
    LANGUAGE sql IMMUTABLE
658
    AS $_$
659
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
660
$_$;
661

    
662

    
663
--
664
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
665
--
666

    
667
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
668
returns 0 instead of NULL for empty arrays
669
';
670

    
671

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

    
676
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
677
    LANGUAGE sql STABLE STRICT
678
    AS $_$
679
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
680
$_$;
681

    
682

    
683
--
684
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
685
--
686

    
687
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
688
    LANGUAGE plpgsql STRICT
689
    AS $_$
690
BEGIN
691
    -- not yet clustered (ARRAY[] compares NULLs literally)
692
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
693
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
694
    END IF;
695
END;
696
$_$;
697

    
698

    
699
--
700
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
701
--
702

    
703
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
704
idempotent
705
';
706

    
707

    
708
--
709
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
710
--
711

    
712
CREATE FUNCTION col__min(col col_ref) RETURNS integer
713
    LANGUAGE sql STABLE
714
    AS $_$
715
SELECT util.eval2val($$
716
SELECT $$||quote_ident($1.name)||$$
717
FROM $$||$1.table_||$$
718
ORDER BY $$||quote_ident($1.name)||$$ ASC
719
LIMIT 1
720
$$, NULL::integer)
721
$_$;
722

    
723

    
724
--
725
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
726
--
727

    
728
CREATE FUNCTION col_comment(col col_ref) RETURNS text
729
    LANGUAGE plpgsql STABLE STRICT
730
    AS $$
731
DECLARE
732
	comment text;
733
BEGIN
734
	SELECT description
735
	FROM pg_attribute
736
	LEFT JOIN pg_description ON objoid = attrelid
737
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
738
	WHERE attrelid = col.table_ AND attname = col.name
739
	INTO STRICT comment
740
	;
741
	RETURN comment;
742
EXCEPTION
743
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
744
END;
745
$$;
746

    
747

    
748
--
749
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
750
--
751

    
752
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
753
    LANGUAGE plpgsql STABLE STRICT
754
    AS $$
755
DECLARE
756
	default_sql text;
757
BEGIN
758
	SELECT adsrc
759
	FROM pg_attribute
760
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
761
	WHERE attrelid = col.table_ AND attname = col.name
762
	INTO STRICT default_sql
763
	;
764
	RETURN default_sql;
765
EXCEPTION
766
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
767
END;
768
$$;
769

    
770

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

    
775
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
776
    LANGUAGE sql STABLE
777
    AS $_$
778
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
779
$_$;
780

    
781

    
782
--
783
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
784
--
785

    
786
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
787
ret_type_null: NULL::ret_type
788
';
789

    
790

    
791
--
792
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
793
--
794

    
795
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
796
    LANGUAGE plpgsql STRICT
797
    AS $$
798
BEGIN
799
    PERFORM util.col_type(col);
800
    RETURN true;
801
EXCEPTION
802
    WHEN undefined_column THEN RETURN false;
803
END;
804
$$;
805

    
806

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

    
811
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
812
    LANGUAGE plpgsql STABLE STRICT
813
    AS $$
814
DECLARE
815
    prefix text := util.name(type)||'.';
816
BEGIN
817
    RETURN QUERY
818
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
819
        FROM util.col_names(type) f (name_);
820
END;
821
$$;
822

    
823

    
824
--
825
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
826
--
827

    
828
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
829
    LANGUAGE sql STABLE STRICT
830
    AS $_$
831
SELECT attname::text
832
FROM pg_attribute
833
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
834
ORDER BY attnum
835
$_$;
836

    
837

    
838
--
839
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
840
--
841

    
842
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
843
    LANGUAGE plpgsql STABLE STRICT
844
    AS $_$
845
BEGIN
846
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
847
END;
848
$_$;
849

    
850

    
851
--
852
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
853
--
854

    
855
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
856
    LANGUAGE plpgsql STABLE STRICT
857
    AS $$
858
DECLARE
859
    type regtype;
860
BEGIN
861
    SELECT atttypid FROM pg_attribute
862
    WHERE attrelid = col.table_ AND attname = col.name
863
    INTO STRICT type
864
    ;
865
    RETURN type;
866
EXCEPTION
867
    WHEN no_data_found THEN
868
        RAISE undefined_column USING MESSAGE =
869
            concat('undefined column: ', col.name);
870
END;
871
$$;
872

    
873

    
874
--
875
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
876
--
877

    
878
CREATE FUNCTION comment(element oid) RETURNS text
879
    LANGUAGE sql STABLE STRICT
880
    AS $_$
881
SELECT description FROM pg_description WHERE objoid = $1
882
$_$;
883

    
884

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

    
889
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
890
    LANGUAGE sql IMMUTABLE
891
    AS $_$
892
SELECT util.esc_name__append($2, $1)
893
$_$;
894

    
895

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

    
900
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
901
    LANGUAGE sql IMMUTABLE
902
    AS $_$
903
SELECT position($1 in $2) > 0 /*1-based offset*/
904
$_$;
905

    
906

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

    
911
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
912
    LANGUAGE sql
913
    AS $_$
914
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
915
$_$;
916

    
917

    
918
--
919
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
920
--
921

    
922
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
923
    LANGUAGE plpgsql STRICT
924
    AS $$
925
BEGIN
926
    PERFORM util.eval(sql);
927
EXCEPTION
928
    WHEN duplicate_table  THEN NULL;
929
    WHEN duplicate_object THEN NULL; -- e.g. constraint
930
    WHEN duplicate_column THEN NULL;
931
    WHEN invalid_table_definition THEN
932
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
933
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
934
        END IF;
935
END;
936
$$;
937

    
938

    
939
--
940
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
941
--
942

    
943
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
944
idempotent
945
';
946

    
947

    
948
--
949
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
950
--
951

    
952
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
953
    LANGUAGE sql IMMUTABLE
954
    AS $$
955
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
956
$$;
957

    
958

    
959
--
960
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
961
--
962

    
963
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
964
    LANGUAGE sql IMMUTABLE
965
    AS $_$
966
SELECT util.raise_notice('returns: '
967
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
968
SELECT $1;
969
$_$;
970

    
971

    
972
--
973
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
974
--
975

    
976
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
977
    LANGUAGE sql IMMUTABLE
978
    AS $_$
979
/* newline before so the query starts at the beginning of the line.
980
newline after to visually separate queries from one another. */
981
SELECT util.raise_notice($$
982
$$||$1||$$
983
$$)
984
$_$;
985

    
986

    
987
--
988
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
989
--
990

    
991
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
992
    LANGUAGE sql STABLE STRICT
993
    AS $_$
994
SELECT util.eval2set($$
995
SELECT col
996
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
997
LEFT JOIN $$||$2||$$ ON "to" = col
998
WHERE "from" IS NULL
999
$$, NULL::text)
1000
$_$;
1001

    
1002

    
1003
--
1004
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1005
--
1006

    
1007
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1008
gets table_''s derived columns (all the columns not in the names table)
1009
';
1010

    
1011

    
1012
--
1013
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1014
--
1015

    
1016
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1017
    LANGUAGE sql
1018
    AS $_$
1019
SELECT * FROM util.diff($1::text, $2::text, $3,
1020
	single_row := util.has_single_row($1) AND util.has_single_row($2),
1021
	search_path := util.schema($3))
1022
$_$;
1023

    
1024

    
1025
--
1026
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1027
--
1028

    
1029
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1030
col_type_null (*required*): NULL::shared_base_type
1031
usage:
1032
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1033
';
1034

    
1035

    
1036
--
1037
-- Name: diff(text, text, anyelement, boolean, text); Type: FUNCTION; Schema: util; Owner: -
1038
--
1039

    
1040
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, search_path text DEFAULT NULL::text, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1041
    LANGUAGE plpgsql
1042
    SET search_path TO pg_temp
1043
    AS $_$
1044
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1045
changes of search_path (schema elements are bound at inline time rather than
1046
runtime) */
1047
/* function option search_path is needed to limit the effects of
1048
`SET LOCAL search_path` (mk_set_search_path()) to the current function */
1049
BEGIN
1050
	EXECUTE util.mk_set_search_path(concat_ws(', ', search_path, 'util'));
1051
		-- need util.%== as default/fallback
1052
	
1053
	RETURN QUERY
1054
		SELECT * FROM
1055
		util.eval2col_pair($$
1056
/* need to explicitly cast each side to the return type because this does not
1057
happen automatically even when an implicit cast is available */
1058
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
1059
FROM $$||$1||$$ left_
1060
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
1061
$$||util._if($4, ''::text,
1062
$$ON left_::$$||pg_typeof($3)||$$ %== right_::$$||pg_typeof($3)||$$
1063
$$)||
1064
$$WHERE left_::$$||pg_typeof($3)||$$ IS DISTINCT FROM right_::$$||pg_typeof($3)||$$
1065
ORDER BY left_, right_
1066
$$, $3)
1067
	;
1068
END;
1069
$_$;
1070

    
1071

    
1072
--
1073
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1074
--
1075

    
1076
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement) IS '
1077
col_type_null (*required*): NULL::col_type
1078
single_row: whether the tables consist of a single row, which should be
1079
	displayed side-by-side
1080

    
1081
to run EXPLAIN on the FULL JOIN query:
1082
# run this function
1083
# look for a NOTICE containing the expanded query that it ran
1084
# run EXPLAIN on this expanded query
1085
';
1086

    
1087

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

    
1092
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1093
    LANGUAGE sql STRICT
1094
    AS $_$
1095
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1096
$_$;
1097

    
1098

    
1099
--
1100
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1101
--
1102

    
1103
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1104
idempotent
1105
';
1106

    
1107

    
1108
--
1109
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1110
--
1111

    
1112
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1113
    LANGUAGE sql STRICT
1114
    AS $_$
1115
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1116
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1117
$_$;
1118

    
1119

    
1120
--
1121
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1122
--
1123

    
1124
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1125
idempotent
1126
';
1127

    
1128

    
1129
--
1130
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1131
--
1132

    
1133
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1134
    LANGUAGE sql
1135
    AS $_$
1136
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1137
included in the debug SQL */
1138
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1139
$_$;
1140

    
1141

    
1142
--
1143
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1144
--
1145

    
1146
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1147
    LANGUAGE sql
1148
    AS $_$
1149
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1150
||util._if($3, $$ CASCADE$$, ''::text))
1151
$_$;
1152

    
1153

    
1154
--
1155
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1156
--
1157

    
1158
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1159
idempotent
1160
';
1161

    
1162

    
1163
--
1164
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1165
--
1166

    
1167
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1168
    LANGUAGE sql
1169
    AS $_$
1170
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1171
$3)
1172
$_$;
1173

    
1174

    
1175
--
1176
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1177
--
1178

    
1179
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1180
    LANGUAGE sql
1181
    AS $_$
1182
SELECT util.drop_relation(relation, $3)
1183
FROM util.show_relations_like($1, $2) relation
1184
;
1185
SELECT NULL::void; -- don't fold away functions called in previous query
1186
$_$;
1187

    
1188

    
1189
--
1190
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1191
--
1192

    
1193
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1194
    LANGUAGE sql STRICT
1195
    AS $_$
1196
SELECT util.drop_relation('TABLE', $1, $2)
1197
$_$;
1198

    
1199

    
1200
--
1201
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1202
--
1203

    
1204
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1205
idempotent
1206
';
1207

    
1208

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

    
1213
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1214
    LANGUAGE sql STRICT
1215
    AS $_$
1216
SELECT util.drop_relation('VIEW', $1, $2)
1217
$_$;
1218

    
1219

    
1220
--
1221
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1222
--
1223

    
1224
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1225
idempotent
1226
';
1227

    
1228

    
1229
--
1230
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1231
--
1232

    
1233
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1234
    LANGUAGE sql IMMUTABLE
1235
    AS $_$
1236
SELECT util.array_fill($1, 0)
1237
$_$;
1238

    
1239

    
1240
--
1241
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1242
--
1243

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

    
1248

    
1249
--
1250
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1251
--
1252

    
1253
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1254
    LANGUAGE sql IMMUTABLE
1255
    AS $_$
1256
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1257
$_$;
1258

    
1259

    
1260
--
1261
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263

    
1264
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1265
    LANGUAGE sql IMMUTABLE
1266
    AS $_$
1267
SELECT regexp_replace($2, '("?)$', $1||'\1')
1268
$_$;
1269

    
1270

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

    
1275
CREATE FUNCTION eval(sql text) RETURNS void
1276
    LANGUAGE plpgsql STRICT
1277
    AS $$
1278
BEGIN
1279
	PERFORM util.debug_print_sql(sql);
1280
	EXECUTE sql;
1281
END;
1282
$$;
1283

    
1284

    
1285
--
1286
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1287
--
1288

    
1289
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1290
    LANGUAGE plpgsql
1291
    AS $$
1292
BEGIN
1293
	PERFORM util.debug_print_sql(sql);
1294
	RETURN QUERY EXECUTE sql;
1295
END;
1296
$$;
1297

    
1298

    
1299
--
1300
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1301
--
1302

    
1303
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1304
col_type_null (*required*): NULL::col_type
1305
';
1306

    
1307

    
1308
--
1309
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1310
--
1311

    
1312
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1313
    LANGUAGE plpgsql
1314
    AS $$
1315
BEGIN
1316
	PERFORM util.debug_print_sql(sql);
1317
	RETURN QUERY EXECUTE sql;
1318
END;
1319
$$;
1320

    
1321

    
1322
--
1323
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1324
--
1325

    
1326
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1327
    LANGUAGE plpgsql
1328
    AS $$
1329
BEGIN
1330
	PERFORM util.debug_print_sql(sql);
1331
	RETURN QUERY EXECUTE sql;
1332
END;
1333
$$;
1334

    
1335

    
1336
--
1337
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1338
--
1339

    
1340
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1341
ret_type_null: NULL::ret_type
1342
';
1343

    
1344

    
1345
--
1346
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1347
--
1348

    
1349
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1350
    LANGUAGE plpgsql
1351
    AS $$
1352
DECLARE
1353
	ret_val ret_type_null%TYPE;
1354
BEGIN
1355
	PERFORM util.debug_print_sql(sql);
1356
	EXECUTE sql INTO STRICT ret_val;
1357
	RETURN ret_val;
1358
END;
1359
$$;
1360

    
1361

    
1362
--
1363
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1364
--
1365

    
1366
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1367
ret_type_null: NULL::ret_type
1368
';
1369

    
1370

    
1371
--
1372
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1373
--
1374

    
1375
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1376
    LANGUAGE sql
1377
    AS $_$
1378
SELECT util.eval2val($$SELECT $$||$1, $2)
1379
$_$;
1380

    
1381

    
1382
--
1383
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1384
--
1385

    
1386
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1387
ret_type_null: NULL::ret_type
1388
';
1389

    
1390

    
1391
--
1392
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1393
--
1394

    
1395
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1396
    LANGUAGE sql
1397
    AS $_$
1398
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1399
$_$;
1400

    
1401

    
1402
--
1403
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1404
--
1405

    
1406
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1407
sql: can be NULL, which will be passed through
1408
ret_type_null: NULL::ret_type
1409
';
1410

    
1411

    
1412
--
1413
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1414
--
1415

    
1416
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1417
    LANGUAGE sql STABLE STRICT
1418
    AS $_$
1419
SELECT col_name
1420
FROM unnest($2) s (col_name)
1421
WHERE util.col_exists(($1, col_name))
1422
$_$;
1423

    
1424

    
1425
--
1426
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1427
--
1428

    
1429
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1430
    LANGUAGE sql
1431
    AS $_$
1432
SELECT util.eval2set($$EXPLAIN $$||$1)
1433
$_$;
1434

    
1435

    
1436
--
1437
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1438
--
1439

    
1440
CREATE FUNCTION explain2notice(sql text) RETURNS void
1441
    LANGUAGE plpgsql
1442
    AS $_$
1443
BEGIN
1444
	RAISE NOTICE '%', $$EXPLAIN:
1445
$$||util.explain2str(sql);
1446
END;
1447
$_$;
1448

    
1449

    
1450
--
1451
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1452
--
1453

    
1454
CREATE FUNCTION explain2str(sql text) RETURNS text
1455
    LANGUAGE sql
1456
    AS $_$
1457
SELECT util.join_strs(explain, $$
1458
$$) FROM util.explain($1)
1459
$_$;
1460

    
1461

    
1462
SET default_tablespace = '';
1463

    
1464
SET default_with_oids = false;
1465

    
1466
--
1467
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1468
--
1469

    
1470
CREATE TABLE explain (
1471
    line text NOT NULL
1472
);
1473

    
1474

    
1475
--
1476
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1477
--
1478

    
1479
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1480
    LANGUAGE sql
1481
    AS $_$
1482
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1483
$$||quote_nullable($1)||$$
1484
)$$)
1485
$_$;
1486

    
1487

    
1488
--
1489
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1490
--
1491

    
1492
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1493
usage:
1494
PERFORM util.explain2table($$
1495
query
1496
$$);
1497
';
1498

    
1499

    
1500
--
1501
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1502
--
1503

    
1504
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1505
    LANGUAGE sql IMMUTABLE
1506
    AS $_$
1507
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1508
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1509
) END
1510
$_$;
1511

    
1512

    
1513
--
1514
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1515
--
1516

    
1517
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1518
ensures that an array will always have proper non-NULL dimensions
1519
';
1520

    
1521

    
1522
--
1523
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1524
--
1525

    
1526
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1527
    LANGUAGE plpgsql
1528
    AS $_$
1529
DECLARE
1530
	PG_EXCEPTION_DETAIL text;
1531
	recreate_users_cmd text = util.save_drop_views(users);
1532
BEGIN
1533
	PERFORM util.eval(cmd);
1534
	PERFORM util.eval(recreate_users_cmd);
1535
EXCEPTION
1536
WHEN dependent_objects_still_exist THEN
1537
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1538
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1539
	users = array(SELECT * FROM util.regexp_matches_group(
1540
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1541
	IF util.is_empty(users) THEN RAISE; END IF;
1542
	PERFORM util.force_recreate(cmd, users);
1543
END;
1544
$_$;
1545

    
1546

    
1547
--
1548
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1549
--
1550

    
1551
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1552
idempotent
1553

    
1554
users: not necessary to provide this because it will be autopopulated
1555
';
1556

    
1557

    
1558
--
1559
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1560
--
1561

    
1562
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1563
    LANGUAGE plpgsql STRICT
1564
    AS $_$
1565
DECLARE
1566
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1567
$$||query;
1568
BEGIN
1569
	EXECUTE mk_view;
1570
EXCEPTION
1571
WHEN invalid_table_definition THEN
1572
	IF SQLERRM = 'cannot drop columns from view'
1573
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1574
	THEN
1575
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1576
		EXECUTE mk_view;
1577
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1578
	END IF;
1579
END;
1580
$_$;
1581

    
1582

    
1583
--
1584
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1585
--
1586

    
1587
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1588
idempotent
1589
';
1590

    
1591

    
1592
--
1593
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1594
--
1595

    
1596
CREATE FUNCTION grants_users() RETURNS SETOF text
1597
    LANGUAGE sql IMMUTABLE
1598
    AS $$
1599
VALUES ('bien_read'), ('public_')
1600
$$;
1601

    
1602

    
1603
--
1604
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1605
--
1606

    
1607
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1608
    LANGUAGE sql IMMUTABLE
1609
    AS $_$
1610
SELECT substring($2 for length($1)) = $1
1611
$_$;
1612

    
1613

    
1614
--
1615
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1616
--
1617

    
1618
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1619
    LANGUAGE sql STABLE
1620
    AS $_$
1621
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1622
$_$;
1623

    
1624

    
1625
--
1626
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1627
--
1628

    
1629
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1630
    LANGUAGE sql IMMUTABLE
1631
    AS $_$
1632
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1633
$_$;
1634

    
1635

    
1636
--
1637
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1638
--
1639

    
1640
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1641
avoids repeating the same value for each key
1642
';
1643

    
1644

    
1645
--
1646
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1647
--
1648

    
1649
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1650
    LANGUAGE sql IMMUTABLE
1651
    AS $_$
1652
SELECT COALESCE($1, $2)
1653
$_$;
1654

    
1655

    
1656
--
1657
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1658
--
1659

    
1660
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1661
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1662
';
1663

    
1664

    
1665
--
1666
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1667
--
1668

    
1669
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1670
    LANGUAGE sql
1671
    AS $_$
1672
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1673
$_$;
1674

    
1675

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

    
1680
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1681
    LANGUAGE sql STABLE STRICT
1682
    AS $_$
1683
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1684
$_$;
1685

    
1686

    
1687
--
1688
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1689
--
1690

    
1691
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1692
    LANGUAGE sql IMMUTABLE
1693
    AS $_$
1694
SELECT util.array_length($1) = 0
1695
$_$;
1696

    
1697

    
1698
--
1699
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1700
--
1701

    
1702
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1703
    LANGUAGE sql IMMUTABLE
1704
    AS $_$
1705
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1706
$_$;
1707

    
1708

    
1709
--
1710
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1711
--
1712

    
1713
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1714
    LANGUAGE sql IMMUTABLE
1715
    AS $_$
1716
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1717
$_$;
1718

    
1719

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

    
1724
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1725
    LANGUAGE sql STABLE
1726
    AS $_$
1727
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1728
$_$;
1729

    
1730

    
1731
--
1732
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1733
--
1734

    
1735
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1736
    LANGUAGE sql STABLE
1737
    AS $_$
1738
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1739
$_$;
1740

    
1741

    
1742
--
1743
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1744
--
1745

    
1746
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1747
    LANGUAGE sql IMMUTABLE STRICT
1748
    AS $_$
1749
SELECT $1 || $3 || $2
1750
$_$;
1751

    
1752

    
1753
--
1754
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1755
--
1756

    
1757
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1758
    LANGUAGE sql IMMUTABLE
1759
    AS $_$
1760
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1761
$_$;
1762

    
1763

    
1764
--
1765
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767

    
1768
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1769
    LANGUAGE sql IMMUTABLE
1770
    AS $_$
1771
SELECT ltrim($1, $$
1772
$$)
1773
$_$;
1774

    
1775

    
1776
--
1777
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779

    
1780
CREATE FUNCTION map_filter_insert() RETURNS trigger
1781
    LANGUAGE plpgsql
1782
    AS $$
1783
BEGIN
1784
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1785
	RETURN new;
1786
END;
1787
$$;
1788

    
1789

    
1790
--
1791
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1792
--
1793

    
1794
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1795
    LANGUAGE plpgsql STABLE STRICT
1796
    AS $_$
1797
DECLARE
1798
    value text;
1799
BEGIN
1800
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1801
        INTO value USING key;
1802
    RETURN value;
1803
END;
1804
$_$;
1805

    
1806

    
1807
--
1808
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1809
--
1810

    
1811
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1812
    LANGUAGE sql IMMUTABLE
1813
    AS $_$
1814
SELECT util._map(util.nulls_map($1), $2)
1815
$_$;
1816

    
1817

    
1818
--
1819
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1820
--
1821

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

    
1825
[1] inlining of function calls, which is different from constant folding
1826
[2] _map()''s profiling query
1827
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1828
and map_nulls()''s profiling query
1829
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1830
both take ~920 ms.
1831
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.
1832
';
1833

    
1834

    
1835
--
1836
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1837
--
1838

    
1839
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1840
    LANGUAGE plpgsql STABLE STRICT
1841
    AS $_$
1842
BEGIN
1843
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1844
END;
1845
$_$;
1846

    
1847

    
1848
--
1849
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1850
--
1851

    
1852
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1853
    LANGUAGE sql
1854
    AS $_$
1855
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1856
$$||util.ltrim_nl($2));
1857
-- make sure the created table has the correct estimated row count
1858
SELECT util.analyze_($1);
1859
$_$;
1860

    
1861

    
1862
--
1863
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1864
--
1865

    
1866
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1867
idempotent
1868
';
1869

    
1870

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

    
1875
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1876
    LANGUAGE sql
1877
    AS $_$
1878
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1879
$_$;
1880

    
1881

    
1882
--
1883
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1884
--
1885

    
1886
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1887
idempotent
1888
';
1889

    
1890

    
1891
--
1892
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1893
--
1894

    
1895
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1896
    LANGUAGE sql STRICT
1897
    AS $_$
1898
SELECT util.create_if_not_exists($$
1899
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1900
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1901
||quote_literal($2)||$$;
1902
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1903
constant
1904
';
1905
$$)
1906
$_$;
1907

    
1908

    
1909
--
1910
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1911
--
1912

    
1913
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1914
idempotent
1915
';
1916

    
1917

    
1918
--
1919
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1920
--
1921

    
1922
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1923
    LANGUAGE plpgsql STRICT
1924
    AS $_$
1925
DECLARE
1926
    type regtype = util.typeof(expr, col.table_::text::regtype);
1927
    col_name_sql text = quote_ident(col.name);
1928
BEGIN
1929
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1930
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1931
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1932
$$||expr||$$;
1933
$$);
1934
END;
1935
$_$;
1936

    
1937

    
1938
--
1939
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1940
--
1941

    
1942
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1943
idempotent
1944
';
1945

    
1946

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

    
1951
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1952
    LANGUAGE sql STRICT
1953
    AS $_$
1954
SELECT util.create_if_not_exists($$
1955
CREATE TABLE $$||$1||$$
1956
(
1957
    LIKE util.map INCLUDING ALL
1958
);
1959

    
1960
CREATE TRIGGER map_filter_insert
1961
  BEFORE INSERT
1962
  ON $$||$1||$$
1963
  FOR EACH ROW
1964
  EXECUTE PROCEDURE util.map_filter_insert();
1965
$$)
1966
$_$;
1967

    
1968

    
1969
--
1970
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1971
--
1972

    
1973
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1974
    LANGUAGE sql IMMUTABLE
1975
    AS $_$
1976
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1977
$_$;
1978

    
1979

    
1980
--
1981
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1982
--
1983

    
1984
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1985
    LANGUAGE sql IMMUTABLE
1986
    AS $_$
1987
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1988
$_$;
1989

    
1990

    
1991
--
1992
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1993
--
1994

    
1995
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1996
usage:
1997
for *1* schema arg:
1998
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1999
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2000
';
2001

    
2002

    
2003
--
2004
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
2005
--
2006

    
2007
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
2008
    LANGUAGE sql IMMUTABLE
2009
    AS $_$
2010
/* debug_print_return_value() needed because this function is used with EXECUTE
2011
rather than util.eval() (in order to affect the calling function), so the
2012
search_path would not otherwise be printed */
2013
SELECT util.debug_print_return_value($$SET LOCAL search_path TO $$||$1)
2014
$_$;
2015

    
2016

    
2017
--
2018
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2019
--
2020

    
2021
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2022
    LANGUAGE sql STRICT
2023
    AS $_$
2024
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2025
$_$;
2026

    
2027

    
2028
--
2029
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2030
--
2031

    
2032
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2033
idempotent
2034
';
2035

    
2036

    
2037
--
2038
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2039
--
2040

    
2041
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2042
    LANGUAGE plpgsql STRICT
2043
    AS $_$
2044
DECLARE
2045
	view_qual_name text = util.qual_name(view_);
2046
BEGIN
2047
	EXECUTE $$
2048
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2049
  RETURNS SETOF $$||view_||$$ AS
2050
$BODY1$
2051
SELECT * FROM $$||view_qual_name||$$
2052
ORDER BY sort_col
2053
LIMIT $1 OFFSET $2
2054
$BODY1$
2055
  LANGUAGE sql STABLE
2056
  COST 100
2057
  ROWS 1000
2058
$$;
2059
	
2060
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2061
END;
2062
$_$;
2063

    
2064

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

    
2069
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2070
    LANGUAGE plpgsql STRICT
2071
    AS $_$
2072
DECLARE
2073
	view_qual_name text = util.qual_name(view_);
2074
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2075
BEGIN
2076
	EXECUTE $$
2077
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2078
  RETURNS integer AS
2079
$BODY1$
2080
SELECT $$||quote_ident(row_num_col)||$$
2081
FROM $$||view_qual_name||$$
2082
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2083
LIMIT 1
2084
$BODY1$
2085
  LANGUAGE sql STABLE
2086
  COST 100;
2087
$$;
2088
	
2089
	EXECUTE $$
2090
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2091
  RETURNS SETOF $$||view_||$$ AS
2092
$BODY1$
2093
SELECT * FROM $$||view_qual_name||$$
2094
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2095
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2096
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2097
ORDER BY $$||quote_ident(row_num_col)||$$
2098
$BODY1$
2099
  LANGUAGE sql STABLE
2100
  COST 100
2101
  ROWS 1000
2102
$$;
2103
	
2104
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2105
END;
2106
$_$;
2107

    
2108

    
2109
--
2110
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2111
--
2112

    
2113
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2114
    LANGUAGE plpgsql STRICT
2115
    AS $_$
2116
DECLARE
2117
	view_qual_name text = util.qual_name(view_);
2118
BEGIN
2119
	EXECUTE $$
2120
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2121
  RETURNS SETOF $$||view_||$$
2122
  SET enable_sort TO 'off'
2123
  AS
2124
$BODY1$
2125
SELECT * FROM $$||view_qual_name||$$($2, $3)
2126
$BODY1$
2127
  LANGUAGE sql STABLE
2128
  COST 100
2129
  ROWS 1000
2130
;
2131
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2132
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2133
If you want to run EXPLAIN and get expanded output, use the regular subset
2134
function instead. (When a config param is set on a function, EXPLAIN produces
2135
just a function scan.)
2136
';
2137
$$;
2138
END;
2139
$_$;
2140

    
2141

    
2142
--
2143
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2144
--
2145

    
2146
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2147
creates subset function which turns off enable_sort
2148
';
2149

    
2150

    
2151
--
2152
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2153
--
2154

    
2155
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2156
    LANGUAGE sql IMMUTABLE
2157
    AS $_$
2158
SELECT util.mk_set_search_path(util.schema_esc($1))
2159
$_$;
2160

    
2161

    
2162
--
2163
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2164
--
2165

    
2166
CREATE FUNCTION name(table_ regclass) RETURNS text
2167
    LANGUAGE sql STABLE
2168
    AS $_$
2169
SELECT relname::text FROM pg_class WHERE oid = $1
2170
$_$;
2171

    
2172

    
2173
--
2174
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2175
--
2176

    
2177
CREATE FUNCTION name(type regtype) RETURNS text
2178
    LANGUAGE sql STABLE STRICT
2179
    AS $_$
2180
SELECT typname::text FROM pg_type WHERE oid = $1
2181
$_$;
2182

    
2183

    
2184
--
2185
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2186
--
2187

    
2188
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2189
    LANGUAGE sql IMMUTABLE
2190
    AS $_$
2191
SELECT octet_length($1) >= util.namedatalen() - $2
2192
$_$;
2193

    
2194

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

    
2199
CREATE FUNCTION namedatalen() RETURNS integer
2200
    LANGUAGE sql IMMUTABLE
2201
    AS $$
2202
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2203
$$;
2204

    
2205

    
2206
--
2207
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2208
--
2209

    
2210
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2211
    LANGUAGE sql IMMUTABLE
2212
    AS $_$
2213
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2214
$_$;
2215

    
2216

    
2217
--
2218
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2219
--
2220

    
2221
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2222
    LANGUAGE sql IMMUTABLE
2223
    AS $_$
2224
SELECT $1 IS NOT NULL
2225
$_$;
2226

    
2227

    
2228
--
2229
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231

    
2232
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2233
    LANGUAGE sql IMMUTABLE
2234
    AS $_$
2235
SELECT util.hstore($1, NULL) || '*=>*'
2236
$_$;
2237

    
2238

    
2239
--
2240
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2241
--
2242

    
2243
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2244
for use with _map()
2245
';
2246

    
2247

    
2248
--
2249
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2250
--
2251

    
2252
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2253
    LANGUAGE sql IMMUTABLE
2254
    AS $_$
2255
SELECT $2 + COALESCE($1, 0)
2256
$_$;
2257

    
2258

    
2259
--
2260
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2261
--
2262

    
2263
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2264
    LANGUAGE sql IMMUTABLE
2265
    AS $_$
2266
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2267
$_$;
2268

    
2269

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

    
2274
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2275
    LANGUAGE sql STABLE STRICT
2276
    SET search_path TO pg_temp
2277
    AS $_$
2278
SELECT $1::text
2279
$_$;
2280

    
2281

    
2282
--
2283
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2284
--
2285

    
2286
CREATE FUNCTION qual_name(type regtype) RETURNS text
2287
    LANGUAGE sql STABLE STRICT
2288
    SET search_path TO pg_temp
2289
    AS $_$
2290
SELECT $1::text
2291
$_$;
2292

    
2293

    
2294
--
2295
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2296
--
2297

    
2298
COMMENT ON FUNCTION qual_name(type regtype) IS '
2299
a type''s schema-qualified name
2300
';
2301

    
2302

    
2303
--
2304
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2305
--
2306

    
2307
CREATE FUNCTION qual_name(type unknown) RETURNS text
2308
    LANGUAGE sql STABLE STRICT
2309
    AS $_$
2310
SELECT util.qual_name($1::text::regtype)
2311
$_$;
2312

    
2313

    
2314
--
2315
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2316
--
2317

    
2318
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2319
    LANGUAGE sql IMMUTABLE
2320
    AS $_$
2321
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2322
$_$;
2323

    
2324

    
2325
--
2326
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2327
--
2328

    
2329
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2330
    LANGUAGE sql IMMUTABLE
2331
    AS $_$
2332
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2333
$_$;
2334

    
2335

    
2336
--
2337
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2338
--
2339

    
2340
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2341
    LANGUAGE sql IMMUTABLE
2342
    AS $_$
2343
SELECT quote_nullable($1)||$$::$$||pg_typeof($1)
2344
$_$;
2345

    
2346

    
2347
--
2348
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2349
--
2350

    
2351
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2352
    LANGUAGE sql IMMUTABLE STRICT
2353
    AS $_$
2354
SELECT util.raise_notice('ERROR:  '||$1)
2355
$_$;
2356

    
2357

    
2358
--
2359
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2360
--
2361

    
2362
CREATE FUNCTION raise_notice(msg text) RETURNS void
2363
    LANGUAGE plpgsql IMMUTABLE STRICT
2364
    AS $$
2365
BEGIN
2366
	RAISE NOTICE '%', msg;
2367
END;
2368
$$;
2369

    
2370

    
2371
--
2372
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2373
--
2374

    
2375
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2376
    LANGUAGE plpgsql IMMUTABLE STRICT
2377
    AS $$
2378
BEGIN
2379
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2380
END;
2381
$$;
2382

    
2383

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

    
2388
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2389
    LANGUAGE sql IMMUTABLE
2390
    AS $_$
2391
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2392
$_$;
2393

    
2394

    
2395
--
2396
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2397
--
2398

    
2399
CREATE FUNCTION regexp_quote(str text) RETURNS text
2400
    LANGUAGE sql IMMUTABLE
2401
    AS $_$
2402
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2403
$_$;
2404

    
2405

    
2406
--
2407
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2408
--
2409

    
2410
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2411
    LANGUAGE sql IMMUTABLE
2412
    AS $_$
2413
SELECT (CASE WHEN right($1, 1) = ')'
2414
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2415
$_$;
2416

    
2417

    
2418
--
2419
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2420
--
2421

    
2422
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2423
    LANGUAGE sql STABLE
2424
    AS $_$
2425
SELECT util.relation_type(util.relation_type_char($1))
2426
$_$;
2427

    
2428

    
2429
--
2430
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2431
--
2432

    
2433
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2434
    LANGUAGE sql IMMUTABLE
2435
    AS $_$
2436
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2437
$_$;
2438

    
2439

    
2440
--
2441
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2442
--
2443

    
2444
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2445
    LANGUAGE sql STABLE
2446
    AS $_$
2447
SELECT relkind FROM pg_class WHERE oid = $1
2448
$_$;
2449

    
2450

    
2451
--
2452
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2453
--
2454

    
2455
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2456
    LANGUAGE sql
2457
    AS $_$
2458
/* can't have in_table/out_table inherit from *each other*, because inheritance
2459
also causes the rows of the parent table to be included in the child table.
2460
instead, they need to inherit from a common, empty table. */
2461
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2462
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2463
SELECT util.inherit($2, $4);
2464
SELECT util.inherit($3, $4);
2465

    
2466
SELECT util.rematerialize_query($1, $$
2467
SELECT * FROM util.diff(
2468
  $$||util.quote_typed($2)||$$
2469
, $$||util.quote_typed($3)||$$
2470
, NULL::$$||$4||$$)
2471
$$);
2472

    
2473
/* the table unfortunately cannot be *materialized* in human-readable form,
2474
because this would create column name collisions between the two sides */
2475
SELECT util.append_comment($1, '
2476
to view this table in human-readable form (with each side''s tuple column
2477
expanded to its component fields):
2478
SELECT (left_).*, (right_).* FROM '||$1||';
2479
');
2480
$_$;
2481

    
2482

    
2483
--
2484
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2485
--
2486

    
2487
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2488
type_table (*required*): table to create as the shared base type
2489
';
2490

    
2491

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

    
2496
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2497
    LANGUAGE sql
2498
    AS $_$
2499
SELECT util.drop_table($1);
2500
SELECT util.materialize_query($1, $2);
2501
$_$;
2502

    
2503

    
2504
--
2505
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2506
--
2507

    
2508
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2509
idempotent, but repeats action each time
2510
';
2511

    
2512

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

    
2517
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2518
    LANGUAGE sql
2519
    AS $_$
2520
SELECT util.drop_table($1);
2521
SELECT util.materialize_view($1, $2);
2522
$_$;
2523

    
2524

    
2525
--
2526
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2527
--
2528

    
2529
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2530
idempotent, but repeats action each time
2531
';
2532

    
2533

    
2534
--
2535
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2536
--
2537

    
2538
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2539
    LANGUAGE sql STRICT
2540
    AS $_$
2541
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2542
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2543
FROM util.col_names($1::text::regtype) f (name);
2544
SELECT NULL::void; -- don't fold away functions called in previous query
2545
$_$;
2546

    
2547

    
2548
--
2549
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2550
--
2551

    
2552
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2553
idempotent
2554
';
2555

    
2556

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

    
2561
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2562
    LANGUAGE sql
2563
    AS $_$
2564
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2565
included in the debug SQL */
2566
SELECT util.rename_relation(util.qual_name($1), $2)
2567
$_$;
2568

    
2569

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

    
2574
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2575
    LANGUAGE sql
2576
    AS $_$
2577
/* 'ALTER TABLE can be used with views too'
2578
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2579
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2580
||quote_ident($2))
2581
$_$;
2582

    
2583

    
2584
--
2585
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2586
--
2587

    
2588
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2589
idempotent
2590
';
2591

    
2592

    
2593
--
2594
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2595
--
2596

    
2597
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2598
    LANGUAGE sql IMMUTABLE
2599
    AS $_$
2600
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2601
$_$;
2602

    
2603

    
2604
--
2605
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2606
--
2607

    
2608
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2609
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 
2610
';
2611

    
2612

    
2613
--
2614
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2615
--
2616

    
2617
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2618
    LANGUAGE sql STRICT
2619
    AS $_$
2620
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2621
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2622
SELECT util.set_col_names($1, $2);
2623
$_$;
2624

    
2625

    
2626
--
2627
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2628
--
2629

    
2630
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2631
idempotent.
2632
alters the names table, so it will need to be repopulated after running this function.
2633
';
2634

    
2635

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

    
2640
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2641
    LANGUAGE sql STRICT
2642
    AS $_$
2643
SELECT util.drop_table($1);
2644
SELECT util.mk_map_table($1);
2645
$_$;
2646

    
2647

    
2648
--
2649
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2650
--
2651

    
2652
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2653
    LANGUAGE sql IMMUTABLE
2654
    AS $_$
2655
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2656
$_$;
2657

    
2658

    
2659
--
2660
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2661
--
2662

    
2663
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2664
    LANGUAGE plpgsql STRICT
2665
    AS $_$
2666
DECLARE
2667
	result text = NULL;
2668
BEGIN
2669
	BEGIN
2670
		result = util.show_create_view(view_);
2671
		PERFORM util.eval($$DROP VIEW $$||view_);
2672
	EXCEPTION
2673
		WHEN undefined_table THEN NULL;
2674
	END;
2675
	RETURN result;
2676
END;
2677
$_$;
2678

    
2679

    
2680
--
2681
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2682
--
2683

    
2684
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2685
    LANGUAGE sql
2686
    AS $_$
2687
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2688
$_$;
2689

    
2690

    
2691
--
2692
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2693
--
2694

    
2695
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2696
    LANGUAGE sql STABLE
2697
    AS $_$
2698
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2699
$_$;
2700

    
2701

    
2702
--
2703
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2704
--
2705

    
2706
CREATE FUNCTION schema(table_ regclass) RETURNS text
2707
    LANGUAGE sql STABLE
2708
    AS $_$
2709
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2710
$_$;
2711

    
2712

    
2713
--
2714
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2715
--
2716

    
2717
CREATE FUNCTION schema(type regtype) RETURNS text
2718
    LANGUAGE sql STABLE
2719
    AS $_$
2720
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2721
$_$;
2722

    
2723

    
2724
--
2725
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2726
--
2727

    
2728
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2729
    LANGUAGE sql STABLE
2730
    AS $_$
2731
SELECT util.schema(pg_typeof($1))
2732
$_$;
2733

    
2734

    
2735
--
2736
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2737
--
2738

    
2739
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2740
    LANGUAGE sql STABLE
2741
    AS $_$
2742
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2743
$_$;
2744

    
2745

    
2746
--
2747
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2748
--
2749

    
2750
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2751
a schema bundle is a group of schemas with a common prefix
2752
';
2753

    
2754

    
2755
--
2756
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2757
--
2758

    
2759
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2760
    LANGUAGE sql
2761
    AS $_$
2762
SELECT util.schema_rename(old_schema,
2763
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2764
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2765
SELECT NULL::void; -- don't fold away functions called in previous query
2766
$_$;
2767

    
2768

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

    
2773
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2774
    LANGUAGE plpgsql
2775
    AS $$
2776
BEGIN
2777
	-- don't schema_bundle_rm() the schema_bundle to keep!
2778
	IF replace = with_ THEN RETURN; END IF;
2779
	
2780
	PERFORM util.schema_bundle_rm(replace);
2781
	PERFORM util.schema_bundle_rename(with_, replace);
2782
END;
2783
$$;
2784

    
2785

    
2786
--
2787
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2788
--
2789

    
2790
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2791
    LANGUAGE sql
2792
    AS $_$
2793
SELECT util.schema_rm(schema)
2794
FROM util.schema_bundle_get_schemas($1) f (schema);
2795
SELECT NULL::void; -- don't fold away functions called in previous query
2796
$_$;
2797

    
2798

    
2799
--
2800
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2801
--
2802

    
2803
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2804
    LANGUAGE sql STABLE
2805
    AS $_$
2806
SELECT quote_ident(util.schema($1))
2807
$_$;
2808

    
2809

    
2810
--
2811
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2812
--
2813

    
2814
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2815
    LANGUAGE sql IMMUTABLE
2816
    AS $_$
2817
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2818
$_$;
2819

    
2820

    
2821
--
2822
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2823
--
2824

    
2825
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2826
    LANGUAGE sql STABLE
2827
    AS $_$
2828
SELECT oid FROM pg_namespace WHERE nspname = $1
2829
$_$;
2830

    
2831

    
2832
--
2833
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2834
--
2835

    
2836
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2837
    LANGUAGE sql
2838
    AS $_$
2839
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2840
$_$;
2841

    
2842

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

    
2847
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2848
    LANGUAGE plpgsql
2849
    AS $$
2850
BEGIN
2851
	-- don't schema_rm() the schema to keep!
2852
	IF replace = with_ THEN RETURN; END IF;
2853
	
2854
	PERFORM util.schema_rm(replace);
2855
	PERFORM util.schema_rename(with_, replace);
2856
END;
2857
$$;
2858

    
2859

    
2860
--
2861
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2862
--
2863

    
2864
CREATE FUNCTION schema_rm(schema text) RETURNS void
2865
    LANGUAGE sql
2866
    AS $_$
2867
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2868
$_$;
2869

    
2870

    
2871
--
2872
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2873
--
2874

    
2875
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2876
    LANGUAGE sql STRICT
2877
    AS $_$
2878
SELECT util.eval(
2879
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2880
$_$;
2881

    
2882

    
2883
--
2884
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2885
--
2886

    
2887
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2888
    LANGUAGE plpgsql STRICT
2889
    AS $_$
2890
DECLARE
2891
    old text[] = ARRAY(SELECT util.col_names(table_));
2892
    new text[] = ARRAY(SELECT util.map_values(names));
2893
BEGIN
2894
    old = old[1:array_length(new, 1)]; -- truncate to same length
2895
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2896
||$$ TO $$||quote_ident(value))
2897
    FROM each(hstore(old, new))
2898
    WHERE value != key -- not same name
2899
    ;
2900
END;
2901
$_$;
2902

    
2903

    
2904
--
2905
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2906
--
2907

    
2908
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2909
idempotent
2910
';
2911

    
2912

    
2913
--
2914
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2915
--
2916

    
2917
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2918
    LANGUAGE plpgsql STRICT
2919
    AS $_$
2920
DECLARE
2921
	row_ util.map;
2922
BEGIN
2923
	-- rename any metadata cols rather than re-adding them with new names
2924
	BEGIN
2925
		PERFORM util.set_col_names(table_, names);
2926
	EXCEPTION
2927
		WHEN array_subscript_error THEN -- selective suppress
2928
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2929
				-- metadata cols not yet added
2930
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2931
			END IF;
2932
	END;
2933
	
2934
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2935
	LOOP
2936
		PERFORM util.mk_const_col((table_, row_."to"),
2937
			substring(row_."from" from 2));
2938
	END LOOP;
2939
	
2940
	PERFORM util.set_col_names(table_, names);
2941
END;
2942
$_$;
2943

    
2944

    
2945
--
2946
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2947
--
2948

    
2949
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2950
idempotent.
2951
the metadata mappings must be *last* in the names table.
2952
';
2953

    
2954

    
2955
--
2956
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2957
--
2958

    
2959
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2960
    LANGUAGE plpgsql STRICT
2961
    AS $_$
2962
DECLARE
2963
    sql text = $$ALTER TABLE $$||table_||$$
2964
$$||NULLIF(array_to_string(ARRAY(
2965
    SELECT
2966
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2967
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2968
    FROM
2969
    (
2970
        SELECT
2971
          quote_ident(col_name) AS col_name_sql
2972
        , util.col_type((table_, col_name)) AS curr_type
2973
        , type AS target_type
2974
        FROM unnest(col_casts)
2975
    ) s
2976
    WHERE curr_type != target_type
2977
), '
2978
, '), '');
2979
BEGIN
2980
    PERFORM util.debug_print_sql(sql);
2981
    EXECUTE COALESCE(sql, '');
2982
END;
2983
$_$;
2984

    
2985

    
2986
--
2987
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2988
--
2989

    
2990
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2991
idempotent
2992
';
2993

    
2994

    
2995
--
2996
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2997
--
2998

    
2999
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3000
    LANGUAGE sql STRICT
3001
    AS $_$
3002
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3003
$_$;
3004

    
3005

    
3006
--
3007
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3008
--
3009

    
3010
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3011
    LANGUAGE sql STABLE
3012
    AS $_$
3013
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3014
$$||util.show_grants_for($1)
3015
$_$;
3016

    
3017

    
3018
--
3019
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3020
--
3021

    
3022
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3023
    LANGUAGE sql STABLE
3024
    AS $_$
3025
SELECT string_agg(cmd, '')
3026
FROM
3027
(
3028
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3029
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3030
$$ ELSE '' END) AS cmd
3031
	FROM util.grants_users() f (user_)
3032
) s
3033
$_$;
3034

    
3035

    
3036
--
3037
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3038
--
3039

    
3040
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3041
    LANGUAGE sql STABLE
3042
    AS $_$
3043
SELECT oid FROM pg_class
3044
WHERE relkind = ANY($3) AND relname ~ $1
3045
AND util.schema_matches(util.schema(relnamespace), $2)
3046
ORDER BY relname
3047
$_$;
3048

    
3049

    
3050
--
3051
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3052
--
3053

    
3054
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3055
    LANGUAGE sql STABLE
3056
    AS $_$
3057
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3058
$_$;
3059

    
3060

    
3061
--
3062
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3063
--
3064

    
3065
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3066
    LANGUAGE sql IMMUTABLE
3067
    AS $_$
3068
SELECT '^'||util.regexp_quote($1)||'$'
3069
$_$;
3070

    
3071

    
3072
--
3073
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3074
--
3075

    
3076
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3077
    LANGUAGE plpgsql STABLE STRICT
3078
    AS $_$
3079
DECLARE
3080
    hstore hstore;
3081
BEGIN
3082
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3083
        table_||$$))$$ INTO STRICT hstore;
3084
    RETURN hstore;
3085
END;
3086
$_$;
3087

    
3088

    
3089
--
3090
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3091
--
3092

    
3093
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3094
    LANGUAGE sql STABLE STRICT
3095
    AS $_$
3096
SELECT COUNT(*) > 0 FROM pg_constraint
3097
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3098
$_$;
3099

    
3100

    
3101
--
3102
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3103
--
3104

    
3105
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3106
gets whether a status flag is set by the presence of a table constraint
3107
';
3108

    
3109

    
3110
--
3111
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3112
--
3113

    
3114
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3115
    LANGUAGE sql STRICT
3116
    AS $_$
3117
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3118
||quote_ident($2)||$$ CHECK (true)$$)
3119
$_$;
3120

    
3121

    
3122
--
3123
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3124
--
3125

    
3126
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3127
stores a status flag by the presence of a table constraint.
3128
idempotent.
3129
';
3130

    
3131

    
3132
--
3133
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3134
--
3135

    
3136
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3137
    LANGUAGE sql STABLE STRICT
3138
    AS $_$
3139
SELECT util.table_flag__get($1, 'nulls_mapped')
3140
$_$;
3141

    
3142

    
3143
--
3144
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3145
--
3146

    
3147
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3148
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3149
';
3150

    
3151

    
3152
--
3153
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3154
--
3155

    
3156
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3157
    LANGUAGE sql STRICT
3158
    AS $_$
3159
SELECT util.table_flag__set($1, 'nulls_mapped')
3160
$_$;
3161

    
3162

    
3163
--
3164
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3165
--
3166

    
3167
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3168
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3169
idempotent.
3170
';
3171

    
3172

    
3173
--
3174
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3175
--
3176

    
3177
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3178
    LANGUAGE plpgsql STRICT
3179
    AS $_$
3180
DECLARE
3181
    row record;
3182
BEGIN
3183
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3184
    LOOP
3185
        IF row.global_name != row.name THEN
3186
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3187
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3188
        END IF;
3189
    END LOOP;
3190
END;
3191
$_$;
3192

    
3193

    
3194
--
3195
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3196
--
3197

    
3198
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3199
idempotent
3200
';
3201

    
3202

    
3203
--
3204
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3205
--
3206

    
3207
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3208
    LANGUAGE sql STRICT
3209
    AS $_$
3210
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3211
SELECT NULL::void; -- don't fold away functions called in previous query
3212
$_$;
3213

    
3214

    
3215
--
3216
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3217
--
3218

    
3219
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3220
trims table_ to include only columns in the original data.
3221
idempotent.
3222
';
3223

    
3224

    
3225
--
3226
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3227
--
3228

    
3229
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3230
    LANGUAGE plpgsql STRICT
3231
    AS $_$
3232
BEGIN
3233
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3234
END;
3235
$_$;
3236

    
3237

    
3238
--
3239
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3240
--
3241

    
3242
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3243
idempotent
3244
';
3245

    
3246

    
3247
--
3248
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3249
--
3250

    
3251
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3252
    LANGUAGE sql IMMUTABLE
3253
    AS $_$
3254
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3255
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3256
$_$;
3257

    
3258

    
3259
--
3260
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3261
--
3262

    
3263
CREATE FUNCTION try_create(sql text) RETURNS void
3264
    LANGUAGE plpgsql STRICT
3265
    AS $$
3266
BEGIN
3267
    PERFORM util.eval(sql);
3268
EXCEPTION
3269
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3270
    WHEN undefined_column THEN NULL;
3271
    WHEN duplicate_column THEN NULL;
3272
END;
3273
$$;
3274

    
3275

    
3276
--
3277
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3278
--
3279

    
3280
COMMENT ON FUNCTION try_create(sql text) IS '
3281
idempotent
3282
';
3283

    
3284

    
3285
--
3286
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3287
--
3288

    
3289
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3290
    LANGUAGE sql STRICT
3291
    AS $_$
3292
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3293
$_$;
3294

    
3295

    
3296
--
3297
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3298
--
3299

    
3300
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3301
idempotent
3302
';
3303

    
3304

    
3305
--
3306
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3307
--
3308

    
3309
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3310
    LANGUAGE sql IMMUTABLE
3311
    AS $_$
3312
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3313
$_$;
3314

    
3315

    
3316
--
3317
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3318
--
3319

    
3320
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3321
a type''s NOT NULL qualifier
3322
';
3323

    
3324

    
3325
--
3326
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3327
--
3328

    
3329
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3330
    LANGUAGE plpgsql STABLE
3331
    AS $_$
3332
DECLARE
3333
    type regtype;
3334
BEGIN
3335
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3336
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3337
    RETURN type;
3338
END;
3339
$_$;
3340

    
3341

    
3342
--
3343
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3344
--
3345

    
3346
CREATE AGGREGATE all_same(anyelement) (
3347
    SFUNC = all_same_transform,
3348
    STYPE = anyarray,
3349
    FINALFUNC = all_same_final
3350
);
3351

    
3352

    
3353
--
3354
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3355
--
3356

    
3357
COMMENT ON AGGREGATE all_same(anyelement) IS '
3358
includes NULLs in comparison
3359
';
3360

    
3361

    
3362
--
3363
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3364
--
3365

    
3366
CREATE AGGREGATE join_strs(text, text) (
3367
    SFUNC = join_strs_transform,
3368
    STYPE = text
3369
);
3370

    
3371

    
3372
--
3373
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3374
--
3375

    
3376
CREATE OPERATOR %== (
3377
    PROCEDURE = "%==",
3378
    LEFTARG = anyelement,
3379
    RIGHTARG = anyelement
3380
);
3381

    
3382

    
3383
--
3384
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3385
--
3386

    
3387
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3388
returns whether the map-keys of the compared values are the same
3389
(mnemonic: % is the Perl symbol for a hash map)
3390

    
3391
should be overridden for types that store both keys and values
3392

    
3393
used in a FULL JOIN to select which columns to join on
3394
';
3395

    
3396

    
3397
--
3398
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3399
--
3400

    
3401
CREATE OPERATOR -> (
3402
    PROCEDURE = map_get,
3403
    LEFTARG = regclass,
3404
    RIGHTARG = text
3405
);
3406

    
3407

    
3408
--
3409
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3410
--
3411

    
3412
CREATE OPERATOR => (
3413
    PROCEDURE = hstore,
3414
    LEFTARG = text[],
3415
    RIGHTARG = text
3416
);
3417

    
3418

    
3419
--
3420
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3421
--
3422

    
3423
COMMENT ON OPERATOR => (text[], text) IS '
3424
usage: array[''key1'', ...]::text[] => ''value''
3425
';
3426

    
3427

    
3428
--
3429
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3430
--
3431

    
3432
CREATE OPERATOR ?*>= (
3433
    PROCEDURE = is_populated_more_often_than,
3434
    LEFTARG = anyelement,
3435
    RIGHTARG = anyelement
3436
);
3437

    
3438

    
3439
--
3440
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3441
--
3442

    
3443
CREATE OPERATOR ?>= (
3444
    PROCEDURE = is_more_complete_than,
3445
    LEFTARG = anyelement,
3446
    RIGHTARG = anyelement
3447
);
3448

    
3449

    
3450
--
3451
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3452
--
3453

    
3454
CREATE OPERATOR ||% (
3455
    PROCEDURE = concat_esc,
3456
    LEFTARG = text,
3457
    RIGHTARG = text
3458
);
3459

    
3460

    
3461
--
3462
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3463
--
3464

    
3465
COMMENT ON OPERATOR ||% (text, text) IS '
3466
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3467
';
3468

    
3469

    
3470
--
3471
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3472
--
3473

    
3474
CREATE TABLE map (
3475
    "from" text NOT NULL,
3476
    "to" text,
3477
    filter text,
3478
    notes text
3479
);
3480

    
3481

    
3482
--
3483
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3484
--
3485

    
3486

    
3487

    
3488
--
3489
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3490
--
3491

    
3492

    
3493

    
3494
--
3495
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3496
--
3497

    
3498
ALTER TABLE ONLY map
3499
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3500

    
3501

    
3502
--
3503
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3504
--
3505

    
3506
ALTER TABLE ONLY map
3507
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3508

    
3509

    
3510
--
3511
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3512
--
3513

    
3514
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3515

    
3516

    
3517
--
3518
-- PostgreSQL database dump complete
3519
--
3520

    
(19-19/29)