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); Type: FUNCTION; Schema: util; Owner: -
961
--
962

    
963
CREATE FUNCTION debug_print_return_value(value anyelement) RETURNS anyelement
964
    LANGUAGE sql IMMUTABLE
965
    AS $_$
966
SELECT util.raise_notice('returns: '||util.quote_typed($1));
967
SELECT $1;
968
$_$;
969

    
970

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

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

    
985

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

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

    
1001

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

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

    
1010

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

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

    
1022

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

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

    
1033

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

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

    
1069

    
1070
--
1071
-- 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: -
1072
--
1073

    
1074
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 '
1075
col_type_null (*required*): NULL::col_type
1076
single_row: whether the tables consist of a single row, which should be
1077
	displayed side-by-side
1078

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

    
1085

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

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

    
1096

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

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

    
1105

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

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

    
1117

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

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

    
1126

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

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

    
1139

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

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

    
1151

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

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

    
1160

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

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

    
1172

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

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

    
1186

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

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

    
1197

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

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

    
1206

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

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

    
1217

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

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

    
1226

    
1227
--
1228
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1229
--
1230

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

    
1237

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

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

    
1246

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

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

    
1257

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

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

    
1268

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

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

    
1282

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

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

    
1296

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

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

    
1305

    
1306
--
1307
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1308
--
1309

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

    
1319

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

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

    
1333

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

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

    
1342

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

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

    
1359

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

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

    
1368

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

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

    
1379

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

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

    
1388

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

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

    
1399

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

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

    
1409

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

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

    
1422

    
1423
--
1424
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1425
--
1426

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

    
1433

    
1434
--
1435
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1436
--
1437

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

    
1447

    
1448
--
1449
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1450
--
1451

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

    
1459

    
1460
SET default_tablespace = '';
1461

    
1462
SET default_with_oids = false;
1463

    
1464
--
1465
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1466
--
1467

    
1468
CREATE TABLE explain (
1469
    line text NOT NULL
1470
);
1471

    
1472

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

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

    
1485

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

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

    
1497

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

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

    
1510

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

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

    
1519

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

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

    
1544

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

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

    
1552
users: not necessary to provide this because it will be autopopulated
1553
';
1554

    
1555

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

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

    
1580

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

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

    
1589

    
1590
--
1591
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1592
--
1593

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

    
1600

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

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

    
1611

    
1612
--
1613
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1614
--
1615

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

    
1622

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

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

    
1633

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

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

    
1642

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

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

    
1653

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

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

    
1662

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

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

    
1673

    
1674
--
1675
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1676
--
1677

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

    
1684

    
1685
--
1686
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1687
--
1688

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

    
1695

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

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

    
1706

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

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

    
1717

    
1718
--
1719
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1720
--
1721

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

    
1728

    
1729
--
1730
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1731
--
1732

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

    
1739

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

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

    
1750

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

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

    
1761

    
1762
--
1763
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1764
--
1765

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

    
1773

    
1774
--
1775
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1776
--
1777

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

    
1787

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

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

    
1804

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

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

    
1815

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

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

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

    
1832

    
1833
--
1834
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1835
--
1836

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

    
1845

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

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

    
1859

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

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

    
1868

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

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

    
1879

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

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

    
1888

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

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

    
1906

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

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

    
1915

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

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

    
1935

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

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

    
1944

    
1945
--
1946
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1947
--
1948

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

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

    
1966

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

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

    
1977

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

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

    
1988

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

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

    
2000

    
2001
--
2002
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
2003
--
2004

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

    
2014

    
2015
--
2016
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2017
--
2018

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

    
2025

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

    
2030
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2031
idempotent
2032
';
2033

    
2034

    
2035
--
2036
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2037
--
2038

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

    
2062

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

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

    
2106

    
2107
--
2108
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2109
--
2110

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

    
2139

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

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

    
2148

    
2149
--
2150
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2151
--
2152

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

    
2159

    
2160
--
2161
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2162
--
2163

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

    
2170

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

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

    
2181

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

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

    
2192

    
2193
--
2194
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2195
--
2196

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

    
2203

    
2204
--
2205
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207

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

    
2214

    
2215
--
2216
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2217
--
2218

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

    
2225

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

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

    
2236

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

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

    
2245

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

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

    
2256

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

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

    
2267

    
2268
--
2269
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2270
--
2271

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

    
2279

    
2280
--
2281
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2282
--
2283

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

    
2291

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

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

    
2300

    
2301
--
2302
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2303
--
2304

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

    
2311

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

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

    
2322

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

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

    
2333

    
2334
--
2335
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2336
--
2337

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

    
2344

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

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

    
2355

    
2356
--
2357
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2358
--
2359

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

    
2368

    
2369
--
2370
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2371
--
2372

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

    
2381

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

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

    
2392

    
2393
--
2394
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2395
--
2396

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

    
2403

    
2404
--
2405
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2406
--
2407

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

    
2415

    
2416
--
2417
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2418
--
2419

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

    
2426

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

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

    
2437

    
2438
--
2439
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2440
--
2441

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

    
2448

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

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

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

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

    
2480

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

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

    
2489

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

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

    
2501

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

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

    
2510

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

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

    
2522

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

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

    
2531

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

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

    
2545

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

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

    
2554

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

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

    
2567

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

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

    
2581

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

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

    
2590

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

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

    
2601

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

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

    
2610

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

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

    
2623

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

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

    
2633

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

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

    
2645

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

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

    
2656

    
2657
--
2658
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2659
--
2660

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

    
2677

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

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

    
2688

    
2689
--
2690
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2691
--
2692

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

    
2699

    
2700
--
2701
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2702
--
2703

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

    
2710

    
2711
--
2712
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2713
--
2714

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

    
2721

    
2722
--
2723
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2724
--
2725

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

    
2732

    
2733
--
2734
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2735
--
2736

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

    
2743

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

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

    
2752

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

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

    
2766

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

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

    
2783

    
2784
--
2785
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2786
--
2787

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

    
2796

    
2797
--
2798
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2799
--
2800

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

    
2807

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

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

    
2818

    
2819
--
2820
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2821
--
2822

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

    
2829

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

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

    
2840

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

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

    
2857

    
2858
--
2859
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2860
--
2861

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

    
2868

    
2869
--
2870
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2871
--
2872

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

    
2880

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

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

    
2901

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

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

    
2910

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

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

    
2942

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

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

    
2952

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

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

    
2983

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

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

    
2992

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

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

    
3003

    
3004
--
3005
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3006
--
3007

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

    
3015

    
3016
--
3017
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3018
--
3019

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

    
3033

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

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

    
3047

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

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

    
3058

    
3059
--
3060
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3061
--
3062

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

    
3069

    
3070
--
3071
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3072
--
3073

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

    
3086

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

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

    
3098

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

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

    
3107

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

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

    
3119

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

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

    
3129

    
3130
--
3131
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3132
--
3133

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

    
3140

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

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

    
3149

    
3150
--
3151
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3152
--
3153

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

    
3160

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

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

    
3170

    
3171
--
3172
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3173
--
3174

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

    
3191

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

    
3196
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3197
idempotent
3198
';
3199

    
3200

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

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

    
3212

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

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

    
3222

    
3223
--
3224
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3225
--
3226

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

    
3235

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

    
3240
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3241
idempotent
3242
';
3243

    
3244

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

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

    
3256

    
3257
--
3258
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3259
--
3260

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

    
3273

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

    
3278
COMMENT ON FUNCTION try_create(sql text) IS '
3279
idempotent
3280
';
3281

    
3282

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

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

    
3293

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

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

    
3302

    
3303
--
3304
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3305
--
3306

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

    
3313

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

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

    
3322

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

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

    
3339

    
3340
--
3341
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3342
--
3343

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

    
3350

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

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

    
3359

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

    
3364
CREATE AGGREGATE join_strs(text, text) (
3365
    SFUNC = join_strs_transform,
3366
    STYPE = text
3367
);
3368

    
3369

    
3370
--
3371
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3372
--
3373

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

    
3380

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

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

    
3389
should be overridden for types that store both keys and values
3390

    
3391
used in a FULL JOIN to select which columns to join on
3392
';
3393

    
3394

    
3395
--
3396
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3397
--
3398

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

    
3405

    
3406
--
3407
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3408
--
3409

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

    
3416

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

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

    
3425

    
3426
--
3427
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3428
--
3429

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

    
3436

    
3437
--
3438
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3439
--
3440

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

    
3447

    
3448
--
3449
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3450
--
3451

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

    
3458

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

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

    
3467

    
3468
--
3469
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3470
--
3471

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

    
3479

    
3480
--
3481
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3482
--
3483

    
3484

    
3485

    
3486
--
3487
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3488
--
3489

    
3490

    
3491

    
3492
--
3493
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3494
--
3495

    
3496
ALTER TABLE ONLY map
3497
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3498

    
3499

    
3500
--
3501
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3502
--
3503

    
3504
ALTER TABLE ONLY map
3505
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3506

    
3507

    
3508
--
3509
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3510
--
3511

    
3512
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3513

    
3514

    
3515
--
3516
-- PostgreSQL database dump complete
3517
--
3518

    
(19-19/29)