Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

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

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

    
104

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

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

    
113

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

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

    
133

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

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

    
152

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

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

    
170

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

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

    
181

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

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

    
192

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

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

    
205

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

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

    
216

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

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

    
227

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

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

    
238

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

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

    
249

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

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

    
260

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

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

    
271

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

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

    
286

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

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

    
311

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

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

    
322

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

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

    
361

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

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

    
372

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

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

    
411

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

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

    
422

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

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

    
433

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

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

    
444

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

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

    
455

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

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

    
481

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

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

    
501

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

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

    
510

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

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

    
521

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

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

    
532

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

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

    
550

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

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

    
559

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

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

    
570

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

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

    
587

    
588
--
589
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
590
--
591

    
592
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
593
    LANGUAGE sql IMMUTABLE
594
    AS $_$
595
SELECT pg_catalog.array_fill($1, ARRAY[$2])
596
$_$;
597

    
598

    
599
--
600
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
604
    LANGUAGE sql IMMUTABLE
605
    AS $_$
606
SELECT util.array_length($1, 1)
607
$_$;
608

    
609

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

    
614
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
618
$_$;
619

    
620

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

    
625
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
626
returns 0 instead of NULL for empty arrays
627
';
628

    
629

    
630
--
631
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
635
    LANGUAGE sql STABLE STRICT
636
    AS $_$
637
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
638
$_$;
639

    
640

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

    
645
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
646
    LANGUAGE plpgsql STRICT
647
    AS $_$
648
BEGIN
649
    -- not yet clustered (ARRAY[] compares NULLs literally)
650
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
651
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
652
    END IF;
653
END;
654
$_$;
655

    
656

    
657
--
658
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
659
--
660

    
661
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
662
idempotent
663
';
664

    
665

    
666
--
667
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
668
--
669

    
670
CREATE FUNCTION col__min(col col_ref) RETURNS integer
671
    LANGUAGE sql STABLE
672
    AS $_$
673
SELECT util.eval2val($$
674
SELECT $$||quote_ident($1.name)||$$
675
FROM $$||$1.table_||$$
676
ORDER BY $$||quote_ident($1.name)||$$ ASC
677
LIMIT 1
678
$$, NULL::integer)
679
$_$;
680

    
681

    
682
--
683
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
684
--
685

    
686
CREATE FUNCTION col_comment(col col_ref) RETURNS text
687
    LANGUAGE plpgsql STABLE STRICT
688
    AS $$
689
DECLARE
690
	comment text;
691
BEGIN
692
	SELECT description
693
	FROM pg_attribute
694
	LEFT JOIN pg_description ON objoid = attrelid
695
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
696
	WHERE attrelid = col.table_ AND attname = col.name
697
	INTO STRICT comment
698
	;
699
	RETURN comment;
700
EXCEPTION
701
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
702
END;
703
$$;
704

    
705

    
706
--
707
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
708
--
709

    
710
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
711
    LANGUAGE plpgsql STABLE STRICT
712
    AS $$
713
DECLARE
714
	default_sql text;
715
BEGIN
716
	SELECT adsrc
717
	FROM pg_attribute
718
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
719
	WHERE attrelid = col.table_ AND attname = col.name
720
	INTO STRICT default_sql
721
	;
722
	RETURN default_sql;
723
EXCEPTION
724
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
725
END;
726
$$;
727

    
728

    
729
--
730
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
731
--
732

    
733
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
734
    LANGUAGE sql STABLE
735
    AS $_$
736
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
737
$_$;
738

    
739

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

    
744
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
745
ret_type_null: NULL::ret_type
746
';
747

    
748

    
749
--
750
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
751
--
752

    
753
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
754
    LANGUAGE plpgsql STRICT
755
    AS $$
756
BEGIN
757
    PERFORM util.col_type(col);
758
    RETURN true;
759
EXCEPTION
760
    WHEN undefined_column THEN RETURN false;
761
END;
762
$$;
763

    
764

    
765
--
766
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
767
--
768

    
769
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
770
    LANGUAGE plpgsql STABLE STRICT
771
    AS $$
772
DECLARE
773
    prefix text := util.name(type)||'.';
774
BEGIN
775
    RETURN QUERY
776
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
777
        FROM util.col_names(type) f (name_);
778
END;
779
$$;
780

    
781

    
782
--
783
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
784
--
785

    
786
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
787
    LANGUAGE sql STABLE STRICT
788
    AS $_$
789
SELECT attname::text
790
FROM pg_attribute
791
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
792
ORDER BY attnum
793
$_$;
794

    
795

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

    
800
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
801
    LANGUAGE plpgsql STABLE STRICT
802
    AS $_$
803
BEGIN
804
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
805
END;
806
$_$;
807

    
808

    
809
--
810
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
811
--
812

    
813
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
814
    LANGUAGE plpgsql STABLE STRICT
815
    AS $$
816
DECLARE
817
    type regtype;
818
BEGIN
819
    SELECT atttypid FROM pg_attribute
820
    WHERE attrelid = col.table_ AND attname = col.name
821
    INTO STRICT type
822
    ;
823
    RETURN type;
824
EXCEPTION
825
    WHEN no_data_found THEN
826
        RAISE undefined_column USING MESSAGE =
827
            concat('undefined column: ', col.name);
828
END;
829
$$;
830

    
831

    
832
--
833
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
834
--
835

    
836
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
837
    LANGUAGE sql IMMUTABLE
838
    AS $_$
839
SELECT util.esc_name__append($2, $1)
840
$_$;
841

    
842

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

    
847
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
848
    LANGUAGE sql IMMUTABLE
849
    AS $_$
850
SELECT position($1 in $2) > 0 /*1-based offset*/
851
$_$;
852

    
853

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

    
858
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
859
    LANGUAGE sql
860
    AS $_$
861
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
862
$_$;
863

    
864

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

    
869
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
870
    LANGUAGE plpgsql STRICT
871
    AS $$
872
BEGIN
873
    PERFORM util.eval(sql);
874
EXCEPTION
875
    WHEN duplicate_table  THEN NULL;
876
    WHEN duplicate_object THEN NULL; -- e.g. constraint
877
    WHEN duplicate_column THEN NULL;
878
    WHEN invalid_table_definition THEN
879
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
880
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
881
        END IF;
882
END;
883
$$;
884

    
885

    
886
--
887
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
888
--
889

    
890
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
891
idempotent
892
';
893

    
894

    
895
--
896
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
897
--
898

    
899
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
900
    LANGUAGE sql IMMUTABLE
901
    AS $_$
902
/* newline before so the query starts at the beginning of the line.
903
newline after to visually separate queries from one another. */
904
SELECT util.raise_notice($$
905
$$||$1||$$
906
$$)
907
$_$;
908

    
909

    
910
--
911
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
912
--
913

    
914
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
915
    LANGUAGE sql STABLE STRICT
916
    AS $_$
917
SELECT util.eval2set($$
918
SELECT col
919
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
920
LEFT JOIN $$||$2||$$ ON "to" = col
921
WHERE "from" IS NULL
922
$$, NULL::text)
923
$_$;
924

    
925

    
926
--
927
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
928
--
929

    
930
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
931
gets table_''s derived columns (all the columns not in the names table)
932
';
933

    
934

    
935
--
936
-- Name: diff(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
937
--
938

    
939
CREATE FUNCTION diff(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
940
    LANGUAGE sql STABLE
941
    AS $_$
942
SELECT * FROM
943
util.eval2col_pair($$
944
/* need to explicitly cast each side to the return type because this does not
945
happen automatically even when an implicit cast is available */
946
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
947
FROM      $$||$1||$$ left_
948
FULL JOIN $$||$2||$$ right_
949
ON left_ = right_
950
WHERE left_ IS DISTINCT FROM right_
951
ORDER BY left_, right_
952
$$, $3)
953
$_$;
954

    
955

    
956
--
957
-- Name: FUNCTION diff(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
958
--
959

    
960
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
961
col_type_null (*required*): NULL::col_type
962

    
963
to run EXPLAIN on the FULL JOIN query:
964
# run this function
965
# look for a NOTICE containing the expanded query that it ran
966
# run EXPLAIN on this expanded query
967
';
968

    
969

    
970
--
971
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
972
--
973

    
974
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
975
    LANGUAGE sql STABLE
976
    AS $_$
977
SELECT * FROM util.diff($1::text, $2::text, $3)
978
$_$;
979

    
980

    
981
--
982
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
983
--
984

    
985
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
986
col_type_null (*required*): NULL::shared_base_type
987
usage:
988
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
989
';
990

    
991

    
992
--
993
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
994
--
995

    
996
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
997
    LANGUAGE sql STRICT
998
    AS $_$
999
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1000
$_$;
1001

    
1002

    
1003
--
1004
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1005
--
1006

    
1007
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1008
idempotent
1009
';
1010

    
1011

    
1012
--
1013
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1014
--
1015

    
1016
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1017
    LANGUAGE sql STRICT
1018
    AS $_$
1019
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1020
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1021
$_$;
1022

    
1023

    
1024
--
1025
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1026
--
1027

    
1028
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1029
idempotent
1030
';
1031

    
1032

    
1033
--
1034
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1035
--
1036

    
1037
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1038
    LANGUAGE sql STRICT
1039
    AS $_$
1040
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1
1041
||util._if($2, $$ CASCADE$$, ''::text))
1042
$_$;
1043

    
1044

    
1045
--
1046
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1047
--
1048

    
1049
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1050
idempotent
1051
';
1052

    
1053

    
1054
--
1055
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1056
--
1057

    
1058
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1059
    LANGUAGE sql STRICT
1060
    AS $_$
1061
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1
1062
||util._if($2, $$ CASCADE$$, ''::text))
1063
$_$;
1064

    
1065

    
1066
--
1067
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1068
--
1069

    
1070
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1071
idempotent
1072
';
1073

    
1074

    
1075
--
1076
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1077
--
1078

    
1079
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1080
    LANGUAGE sql IMMUTABLE
1081
    AS $_$
1082
SELECT util.array_fill($1, 0)
1083
$_$;
1084

    
1085

    
1086
--
1087
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1088
--
1089

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

    
1094

    
1095
--
1096
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1097
--
1098

    
1099
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1100
    LANGUAGE sql IMMUTABLE
1101
    AS $_$
1102
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1103
$_$;
1104

    
1105

    
1106
--
1107
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1108
--
1109

    
1110
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1111
    LANGUAGE sql IMMUTABLE
1112
    AS $_$
1113
SELECT regexp_replace($2, '("?)$', $1||'\1')
1114
$_$;
1115

    
1116

    
1117
--
1118
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1119
--
1120

    
1121
CREATE FUNCTION eval(sql text) RETURNS void
1122
    LANGUAGE plpgsql STRICT
1123
    AS $$
1124
BEGIN
1125
	PERFORM util.debug_print_sql(sql);
1126
	EXECUTE sql;
1127
END;
1128
$$;
1129

    
1130

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

    
1135
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1136
    LANGUAGE plpgsql
1137
    AS $$
1138
BEGIN
1139
	PERFORM util.debug_print_sql(sql);
1140
	RETURN QUERY EXECUTE sql;
1141
END;
1142
$$;
1143

    
1144

    
1145
--
1146
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1147
--
1148

    
1149
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1150
col_type_null (*required*): NULL::col_type
1151
';
1152

    
1153

    
1154
--
1155
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1156
--
1157

    
1158
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1159
    LANGUAGE plpgsql
1160
    AS $$
1161
BEGIN
1162
	PERFORM util.debug_print_sql(sql);
1163
	RETURN QUERY EXECUTE sql;
1164
END;
1165
$$;
1166

    
1167

    
1168
--
1169
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1170
--
1171

    
1172
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1173
ret_type_null: NULL::ret_type
1174
';
1175

    
1176

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

    
1181
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1182
    LANGUAGE plpgsql
1183
    AS $$
1184
DECLARE
1185
	ret_val ret_type_null%TYPE;
1186
BEGIN
1187
	PERFORM util.debug_print_sql(sql);
1188
	EXECUTE sql INTO STRICT ret_val;
1189
	RETURN ret_val;
1190
END;
1191
$$;
1192

    
1193

    
1194
--
1195
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1196
--
1197

    
1198
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1199
ret_type_null: NULL::ret_type
1200
';
1201

    
1202

    
1203
--
1204
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1205
--
1206

    
1207
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1208
    LANGUAGE sql
1209
    AS $_$
1210
SELECT util.eval2val($$SELECT $$||$1, $2)
1211
$_$;
1212

    
1213

    
1214
--
1215
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1216
--
1217

    
1218
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1219
ret_type_null: NULL::ret_type
1220
';
1221

    
1222

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

    
1227
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1228
    LANGUAGE sql
1229
    AS $_$
1230
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1231
$_$;
1232

    
1233

    
1234
--
1235
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1236
--
1237

    
1238
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1239
sql: can be NULL, which will be passed through
1240
ret_type_null: NULL::ret_type
1241
';
1242

    
1243

    
1244
--
1245
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1246
--
1247

    
1248
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1249
    LANGUAGE sql STABLE STRICT
1250
    AS $_$
1251
SELECT col_name
1252
FROM unnest($2) s (col_name)
1253
WHERE util.col_exists(($1, col_name))
1254
$_$;
1255

    
1256

    
1257
--
1258
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1259
--
1260

    
1261
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1262
    LANGUAGE sql
1263
    AS $_$
1264
SELECT util.eval2set($$EXPLAIN $$||$1)
1265
$_$;
1266

    
1267

    
1268
--
1269
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1270
--
1271

    
1272
CREATE FUNCTION explain2notice(sql text) RETURNS void
1273
    LANGUAGE plpgsql
1274
    AS $_$
1275
BEGIN
1276
	RAISE NOTICE '%', $$EXPLAIN:
1277
$$||util.explain2str(sql);
1278
END;
1279
$_$;
1280

    
1281

    
1282
--
1283
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1284
--
1285

    
1286
CREATE FUNCTION explain2str(sql text) RETURNS text
1287
    LANGUAGE sql
1288
    AS $_$
1289
SELECT util.join_strs(explain, $$
1290
$$) FROM util.explain($1)
1291
$_$;
1292

    
1293

    
1294
SET default_tablespace = '';
1295

    
1296
SET default_with_oids = false;
1297

    
1298
--
1299
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1300
--
1301

    
1302
CREATE TABLE explain (
1303
    line text NOT NULL
1304
);
1305

    
1306

    
1307
--
1308
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1309
--
1310

    
1311
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1312
    LANGUAGE sql
1313
    AS $_$
1314
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1315
$$||quote_nullable($1)||$$
1316
)$$)
1317
$_$;
1318

    
1319

    
1320
--
1321
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1322
--
1323

    
1324
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1325
usage:
1326
PERFORM util.explain2table($$
1327
query
1328
$$);
1329
';
1330

    
1331

    
1332
--
1333
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1334
--
1335

    
1336
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1337
    LANGUAGE sql IMMUTABLE
1338
    AS $_$
1339
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1340
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1341
) END
1342
$_$;
1343

    
1344

    
1345
--
1346
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1347
--
1348

    
1349
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1350
ensures that an array will always have proper non-NULL dimensions
1351
';
1352

    
1353

    
1354
--
1355
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1356
--
1357

    
1358
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1359
    LANGUAGE plpgsql
1360
    AS $_$
1361
DECLARE
1362
	PG_EXCEPTION_DETAIL text;
1363
	recreate_users_cmd text = util.save_drop_views(users);
1364
BEGIN
1365
	PERFORM util.eval(cmd);
1366
	PERFORM util.eval(recreate_users_cmd);
1367
EXCEPTION
1368
WHEN dependent_objects_still_exist THEN
1369
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1370
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1371
	users = array(SELECT * FROM util.regexp_matches_group(
1372
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1373
	IF util.is_empty(users) THEN RAISE; END IF;
1374
	PERFORM util.force_recreate(cmd, users);
1375
END;
1376
$_$;
1377

    
1378

    
1379
--
1380
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1381
--
1382

    
1383
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1384
idempotent
1385

    
1386
users: not necessary to provide this because it will be autopopulated
1387
';
1388

    
1389

    
1390
--
1391
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1392
--
1393

    
1394
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1395
    LANGUAGE plpgsql STRICT
1396
    AS $_$
1397
DECLARE
1398
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1399
$$||query;
1400
BEGIN
1401
	EXECUTE mk_view;
1402
EXCEPTION
1403
WHEN invalid_table_definition THEN
1404
	IF SQLERRM = 'cannot drop columns from view'
1405
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1406
	THEN
1407
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1408
		EXECUTE mk_view;
1409
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1410
	END IF;
1411
END;
1412
$_$;
1413

    
1414

    
1415
--
1416
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1417
--
1418

    
1419
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1420
idempotent
1421
';
1422

    
1423

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

    
1428
CREATE FUNCTION grants_users() RETURNS SETOF text
1429
    LANGUAGE sql IMMUTABLE
1430
    AS $$
1431
VALUES ('bien_read'), ('public_')
1432
$$;
1433

    
1434

    
1435
--
1436
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1437
--
1438

    
1439
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1440
    LANGUAGE sql IMMUTABLE
1441
    AS $_$
1442
SELECT substring($2 for length($1)) = $1
1443
$_$;
1444

    
1445

    
1446
--
1447
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1448
--
1449

    
1450
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1451
    LANGUAGE sql STABLE
1452
    AS $_$
1453
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1454
$_$;
1455

    
1456

    
1457
--
1458
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1459
--
1460

    
1461
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1462
    LANGUAGE sql IMMUTABLE
1463
    AS $_$
1464
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1465
$_$;
1466

    
1467

    
1468
--
1469
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1470
--
1471

    
1472
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1473
avoids repeating the same value for each key
1474
';
1475

    
1476

    
1477
--
1478
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1479
--
1480

    
1481
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1482
    LANGUAGE sql IMMUTABLE
1483
    AS $_$
1484
SELECT COALESCE($1, $2)
1485
$_$;
1486

    
1487

    
1488
--
1489
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1490
--
1491

    
1492
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1493
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1494
';
1495

    
1496

    
1497
--
1498
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1499
--
1500

    
1501
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1502
    LANGUAGE sql
1503
    AS $_$
1504
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1505
$_$;
1506

    
1507

    
1508
--
1509
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1510
--
1511

    
1512
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1513
    LANGUAGE sql STABLE STRICT
1514
    AS $_$
1515
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1516
$_$;
1517

    
1518

    
1519
--
1520
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522

    
1523
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1524
    LANGUAGE sql IMMUTABLE
1525
    AS $_$
1526
SELECT util.array_length($1) = 0
1527
$_$;
1528

    
1529

    
1530
--
1531
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1532
--
1533

    
1534
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1535
    LANGUAGE sql IMMUTABLE
1536
    AS $_$
1537
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1538
$_$;
1539

    
1540

    
1541
--
1542
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1543
--
1544

    
1545
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1546
    LANGUAGE sql IMMUTABLE
1547
    AS $_$
1548
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1549
$_$;
1550

    
1551

    
1552
--
1553
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1554
--
1555

    
1556
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1557
    LANGUAGE sql IMMUTABLE STRICT
1558
    AS $_$
1559
SELECT $1 || $3 || $2
1560
$_$;
1561

    
1562

    
1563
--
1564
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1565
--
1566

    
1567
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1568
    LANGUAGE sql IMMUTABLE
1569
    AS $_$
1570
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1571
$_$;
1572

    
1573

    
1574
--
1575
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1576
--
1577

    
1578
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1579
    LANGUAGE sql IMMUTABLE
1580
    AS $_$
1581
SELECT ltrim($1, $$
1582
$$)
1583
$_$;
1584

    
1585

    
1586
--
1587
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1588
--
1589

    
1590
CREATE FUNCTION map_filter_insert() RETURNS trigger
1591
    LANGUAGE plpgsql
1592
    AS $$
1593
BEGIN
1594
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1595
	RETURN new;
1596
END;
1597
$$;
1598

    
1599

    
1600
--
1601
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1602
--
1603

    
1604
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1605
    LANGUAGE plpgsql STABLE STRICT
1606
    AS $_$
1607
DECLARE
1608
    value text;
1609
BEGIN
1610
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1611
        INTO value USING key;
1612
    RETURN value;
1613
END;
1614
$_$;
1615

    
1616

    
1617
--
1618
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1619
--
1620

    
1621
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1622
    LANGUAGE sql IMMUTABLE
1623
    AS $_$
1624
SELECT util._map(util.nulls_map($1), $2)
1625
$_$;
1626

    
1627

    
1628
--
1629
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1630
--
1631

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

    
1635
[1] inlining of function calls, which is different from constant folding
1636
[2] _map()''s profiling query
1637
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1638
and map_nulls()''s profiling query
1639
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1640
both take ~920 ms.
1641
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.
1642
';
1643

    
1644

    
1645
--
1646
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1647
--
1648

    
1649
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1650
    LANGUAGE plpgsql STABLE STRICT
1651
    AS $_$
1652
BEGIN
1653
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1654
END;
1655
$_$;
1656

    
1657

    
1658
--
1659
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1660
--
1661

    
1662
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1663
    LANGUAGE sql
1664
    AS $_$
1665
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1666
$$||util.ltrim_nl($2))
1667
$_$;
1668

    
1669

    
1670
--
1671
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1672
--
1673

    
1674
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1675
idempotent
1676
';
1677

    
1678

    
1679
--
1680
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1681
--
1682

    
1683
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1684
    LANGUAGE sql
1685
    AS $_$
1686
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1687
$_$;
1688

    
1689

    
1690
--
1691
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1692
--
1693

    
1694
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1695
idempotent
1696
';
1697

    
1698

    
1699
--
1700
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1701
--
1702

    
1703
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1704
    LANGUAGE sql STRICT
1705
    AS $_$
1706
SELECT util.create_if_not_exists($$
1707
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1708
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1709
||quote_literal($2)||$$;
1710
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1711
constant
1712
';
1713
$$)
1714
$_$;
1715

    
1716

    
1717
--
1718
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1719
--
1720

    
1721
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1722
idempotent
1723
';
1724

    
1725

    
1726
--
1727
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1728
--
1729

    
1730
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1731
    LANGUAGE plpgsql STRICT
1732
    AS $_$
1733
DECLARE
1734
    type regtype = util.typeof(expr, col.table_::text::regtype);
1735
    col_name_sql text = quote_ident(col.name);
1736
BEGIN
1737
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1738
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1739
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1740
$$||expr||$$;
1741
$$);
1742
END;
1743
$_$;
1744

    
1745

    
1746
--
1747
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1748
--
1749

    
1750
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1751
idempotent
1752
';
1753

    
1754

    
1755
--
1756
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1757
--
1758

    
1759
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1760
    LANGUAGE sql STRICT
1761
    AS $_$
1762
SELECT util.create_if_not_exists($$
1763
CREATE TABLE $$||$1||$$
1764
(
1765
    LIKE util.map INCLUDING ALL
1766
);
1767

    
1768
CREATE TRIGGER map_filter_insert
1769
  BEFORE INSERT
1770
  ON $$||$1||$$
1771
  FOR EACH ROW
1772
  EXECUTE PROCEDURE util.map_filter_insert();
1773
$$)
1774
$_$;
1775

    
1776

    
1777
--
1778
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1779
--
1780

    
1781
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1782
    LANGUAGE sql IMMUTABLE
1783
    AS $_$
1784
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1785
$_$;
1786

    
1787

    
1788
--
1789
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1790
--
1791

    
1792
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1793
    LANGUAGE sql IMMUTABLE
1794
    AS $_$
1795
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1796
$_$;
1797

    
1798

    
1799
--
1800
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1801
--
1802

    
1803
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1804
usage:
1805
for *1* schema arg:
1806
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1807
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1808
';
1809

    
1810

    
1811
--
1812
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1813
--
1814

    
1815
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1816
    LANGUAGE sql IMMUTABLE
1817
    AS $_$
1818
SELECT $$SET LOCAL search_path TO $$||$1
1819
$_$;
1820

    
1821

    
1822
--
1823
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1824
--
1825

    
1826
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1827
    LANGUAGE sql STRICT
1828
    AS $_$
1829
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1830
$_$;
1831

    
1832

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

    
1837
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1838
idempotent
1839
';
1840

    
1841

    
1842
--
1843
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1844
--
1845

    
1846
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1847
    LANGUAGE plpgsql STRICT
1848
    AS $_$
1849
DECLARE
1850
	view_qual_name text = util.qual_name(view_);
1851
BEGIN
1852
	EXECUTE $$
1853
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1854
  RETURNS SETOF $$||view_||$$ AS
1855
$BODY1$
1856
SELECT * FROM $$||view_qual_name||$$
1857
ORDER BY sort_col
1858
LIMIT $1 OFFSET $2
1859
$BODY1$
1860
  LANGUAGE sql STABLE
1861
  COST 100
1862
  ROWS 1000
1863
$$;
1864
	
1865
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1866
END;
1867
$_$;
1868

    
1869

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

    
1874
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1875
    LANGUAGE plpgsql STRICT
1876
    AS $_$
1877
DECLARE
1878
	view_qual_name text = util.qual_name(view_);
1879
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1880
BEGIN
1881
	EXECUTE $$
1882
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1883
  RETURNS integer AS
1884
$BODY1$
1885
SELECT $$||quote_ident(row_num_col)||$$
1886
FROM $$||view_qual_name||$$
1887
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1888
LIMIT 1
1889
$BODY1$
1890
  LANGUAGE sql STABLE
1891
  COST 100;
1892
$$;
1893
	
1894
	EXECUTE $$
1895
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1896
  RETURNS SETOF $$||view_||$$ AS
1897
$BODY1$
1898
SELECT * FROM $$||view_qual_name||$$
1899
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1900
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1901
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1902
ORDER BY $$||quote_ident(row_num_col)||$$
1903
$BODY1$
1904
  LANGUAGE sql STABLE
1905
  COST 100
1906
  ROWS 1000
1907
$$;
1908
	
1909
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1910
END;
1911
$_$;
1912

    
1913

    
1914
--
1915
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1916
--
1917

    
1918
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1919
    LANGUAGE plpgsql STRICT
1920
    AS $_$
1921
DECLARE
1922
	view_qual_name text = util.qual_name(view_);
1923
BEGIN
1924
	EXECUTE $$
1925
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1926
  RETURNS SETOF $$||view_||$$
1927
  SET enable_sort TO 'off'
1928
  AS
1929
$BODY1$
1930
SELECT * FROM $$||view_qual_name||$$($2, $3)
1931
$BODY1$
1932
  LANGUAGE sql STABLE
1933
  COST 100
1934
  ROWS 1000
1935
;
1936
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1937
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1938
If you want to run EXPLAIN and get expanded output, use the regular subset
1939
function instead. (When a config param is set on a function, EXPLAIN produces
1940
just a function scan.)
1941
';
1942
$$;
1943
END;
1944
$_$;
1945

    
1946

    
1947
--
1948
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1949
--
1950

    
1951
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
1952
creates subset function which turns off enable_sort
1953
';
1954

    
1955

    
1956
--
1957
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1958
--
1959

    
1960
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
1961
    LANGUAGE sql IMMUTABLE
1962
    AS $_$
1963
SELECT util.mk_set_search_path(util.schema_esc($1))
1964
$_$;
1965

    
1966

    
1967
--
1968
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
1969
--
1970

    
1971
CREATE FUNCTION name(table_ regclass) RETURNS text
1972
    LANGUAGE sql STABLE
1973
    AS $_$
1974
SELECT relname::text FROM pg_class WHERE oid = $1
1975
$_$;
1976

    
1977

    
1978
--
1979
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1980
--
1981

    
1982
CREATE FUNCTION name(type regtype) RETURNS text
1983
    LANGUAGE sql STABLE STRICT
1984
    AS $_$
1985
SELECT typname::text FROM pg_type WHERE oid = $1
1986
$_$;
1987

    
1988

    
1989
--
1990
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1991
--
1992

    
1993
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1994
    LANGUAGE sql IMMUTABLE
1995
    AS $_$
1996
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1997
$_$;
1998

    
1999

    
2000
--
2001
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2002
--
2003

    
2004
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2005
    LANGUAGE sql IMMUTABLE
2006
    AS $_$
2007
SELECT $1 IS NOT NULL
2008
$_$;
2009

    
2010

    
2011
--
2012
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2013
--
2014

    
2015
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2016
    LANGUAGE sql IMMUTABLE
2017
    AS $_$
2018
SELECT util.hstore($1, NULL) || '*=>*'
2019
$_$;
2020

    
2021

    
2022
--
2023
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2024
--
2025

    
2026
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2027
for use with _map()
2028
';
2029

    
2030

    
2031
--
2032
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2033
--
2034

    
2035
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2036
    LANGUAGE sql IMMUTABLE
2037
    AS $_$
2038
SELECT $2 + COALESCE($1, 0)
2039
$_$;
2040

    
2041

    
2042
--
2043
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2044
--
2045

    
2046
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2047
    LANGUAGE sql IMMUTABLE
2048
    AS $_$
2049
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2050
$_$;
2051

    
2052

    
2053
--
2054
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2055
--
2056

    
2057
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2058
    LANGUAGE sql STABLE STRICT
2059
    SET search_path TO pg_temp
2060
    AS $_$
2061
SELECT $1::text
2062
$_$;
2063

    
2064

    
2065
--
2066
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2067
--
2068

    
2069
CREATE FUNCTION qual_name(type regtype) RETURNS text
2070
    LANGUAGE sql STABLE STRICT
2071
    SET search_path TO pg_temp
2072
    AS $_$
2073
SELECT $1::text
2074
$_$;
2075

    
2076

    
2077
--
2078
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2079
--
2080

    
2081
COMMENT ON FUNCTION qual_name(type regtype) IS '
2082
a type''s schema-qualified name
2083
';
2084

    
2085

    
2086
--
2087
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089

    
2090
CREATE FUNCTION qual_name(type unknown) RETURNS text
2091
    LANGUAGE sql STABLE STRICT
2092
    AS $_$
2093
SELECT util.qual_name($1::text::regtype)
2094
$_$;
2095

    
2096

    
2097
--
2098
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2099
--
2100

    
2101
CREATE FUNCTION raise_notice(msg text) RETURNS void
2102
    LANGUAGE plpgsql IMMUTABLE STRICT
2103
    AS $$
2104
BEGIN
2105
	RAISE NOTICE '%', msg;
2106
END;
2107
$$;
2108

    
2109

    
2110
--
2111
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2112
--
2113

    
2114
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2115
    LANGUAGE plpgsql IMMUTABLE STRICT
2116
    AS $$
2117
BEGIN
2118
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2119
END;
2120
$$;
2121

    
2122

    
2123
--
2124
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2125
--
2126

    
2127
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2128
    LANGUAGE sql IMMUTABLE
2129
    AS $_$
2130
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2131
$_$;
2132

    
2133

    
2134
--
2135
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2136
--
2137

    
2138
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2139
    LANGUAGE sql
2140
    AS $_$
2141
/* can't have in_table/out_table inherit from *each other*, because inheritance
2142
also causes the rows of the parent table to be included in the child table.
2143
instead, they need to inherit from a common, empty table. */
2144
SELECT util.drop_table($4, force := true);
2145
SELECT util.copy_struct($2, $4);
2146
SELECT util.inherit($2, $4);
2147
SELECT util.inherit($3, $4);
2148

    
2149
SELECT util.rematerialize_query($1, $$
2150
SELECT * FROM util.diff(
2151
  $$||quote_nullable($2)||$$::regclass
2152
, $$||quote_nullable($3)||$$::regclass
2153
, NULL::$$||$4||$$)
2154
$$);
2155
$_$;
2156

    
2157

    
2158
--
2159
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2160
--
2161

    
2162
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2163
type_table (*required*): table to create as the shared base type
2164
';
2165

    
2166

    
2167
--
2168
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2169
--
2170

    
2171
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2172
    LANGUAGE sql
2173
    AS $_$
2174
SELECT util.drop_table($1);
2175
SELECT util.materialize_query($1, $2);
2176
$_$;
2177

    
2178

    
2179
--
2180
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2181
--
2182

    
2183
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2184
idempotent, but repeats action each time
2185
';
2186

    
2187

    
2188
--
2189
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2190
--
2191

    
2192
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2193
    LANGUAGE sql
2194
    AS $_$
2195
SELECT util.drop_table($1);
2196
SELECT util.materialize_view($1, $2);
2197
$_$;
2198

    
2199

    
2200
--
2201
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2202
--
2203

    
2204
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2205
idempotent, but repeats action each time
2206
';
2207

    
2208

    
2209
--
2210
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2211
--
2212

    
2213
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2214
    LANGUAGE sql STRICT
2215
    AS $_$
2216
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2217
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2218
FROM util.col_names($1::text::regtype) f (name);
2219
SELECT NULL::void; -- don't fold away functions called in previous query
2220
$_$;
2221

    
2222

    
2223
--
2224
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2225
--
2226

    
2227
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2228
idempotent
2229
';
2230

    
2231

    
2232
--
2233
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2234
--
2235

    
2236
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2237
    LANGUAGE sql STRICT
2238
    AS $_$
2239
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2240
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2241
SELECT util.set_col_names($1, $2);
2242
$_$;
2243

    
2244

    
2245
--
2246
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2247
--
2248

    
2249
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2250
idempotent.
2251
alters the names table, so it will need to be repopulated after running this function.
2252
';
2253

    
2254

    
2255
--
2256
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2257
--
2258

    
2259
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2260
    LANGUAGE sql STRICT
2261
    AS $_$
2262
SELECT util.drop_table($1);
2263
SELECT util.mk_map_table($1);
2264
$_$;
2265

    
2266

    
2267
--
2268
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2269
--
2270

    
2271
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2272
    LANGUAGE plpgsql STRICT
2273
    AS $_$
2274
DECLARE
2275
	result text = NULL;
2276
BEGIN
2277
	BEGIN
2278
		result = util.show_create_view(view_);
2279
		PERFORM util.eval($$DROP VIEW $$||view_);
2280
	EXCEPTION
2281
		WHEN undefined_table THEN NULL;
2282
	END;
2283
	RETURN result;
2284
END;
2285
$_$;
2286

    
2287

    
2288
--
2289
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2290
--
2291

    
2292
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2293
    LANGUAGE sql
2294
    AS $_$
2295
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2296
$_$;
2297

    
2298

    
2299
--
2300
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2301
--
2302

    
2303
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2304
    LANGUAGE sql STABLE
2305
    AS $_$
2306
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2307
$_$;
2308

    
2309

    
2310
--
2311
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2312
--
2313

    
2314
CREATE FUNCTION schema(table_ regclass) RETURNS text
2315
    LANGUAGE sql STABLE
2316
    AS $_$
2317
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2318
$_$;
2319

    
2320

    
2321
--
2322
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2323
--
2324

    
2325
CREATE FUNCTION schema(type regtype) RETURNS text
2326
    LANGUAGE sql STABLE
2327
    AS $_$
2328
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2329
$_$;
2330

    
2331

    
2332
--
2333
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2334
--
2335

    
2336
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2337
    LANGUAGE sql STABLE
2338
    AS $_$
2339
SELECT util.schema(pg_typeof($1))
2340
$_$;
2341

    
2342

    
2343
--
2344
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2345
--
2346

    
2347
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2348
    LANGUAGE sql STABLE
2349
    AS $_$
2350
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2351
$_$;
2352

    
2353

    
2354
--
2355
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2356
--
2357

    
2358
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2359
a schema bundle is a group of schemas with a common prefix
2360
';
2361

    
2362

    
2363
--
2364
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2365
--
2366

    
2367
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2368
    LANGUAGE sql
2369
    AS $_$
2370
SELECT util.schema_rename(old_schema,
2371
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2372
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2373
SELECT NULL::void; -- don't fold away functions called in previous query
2374
$_$;
2375

    
2376

    
2377
--
2378
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2379
--
2380

    
2381
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2382
    LANGUAGE plpgsql
2383
    AS $$
2384
BEGIN
2385
	-- don't schema_bundle_rm() the schema_bundle to keep!
2386
	IF replace = with_ THEN RETURN; END IF;
2387
	
2388
	PERFORM util.schema_bundle_rm(replace);
2389
	PERFORM util.schema_bundle_rename(with_, replace);
2390
END;
2391
$$;
2392

    
2393

    
2394
--
2395
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2396
--
2397

    
2398
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2399
    LANGUAGE sql
2400
    AS $_$
2401
SELECT util.schema_rm(schema)
2402
FROM util.schema_bundle_get_schemas($1) f (schema);
2403
SELECT NULL::void; -- don't fold away functions called in previous query
2404
$_$;
2405

    
2406

    
2407
--
2408
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2409
--
2410

    
2411
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2412
    LANGUAGE sql STABLE
2413
    AS $_$
2414
SELECT quote_ident(util.schema($1))
2415
$_$;
2416

    
2417

    
2418
--
2419
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2420
--
2421

    
2422
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2423
    LANGUAGE sql
2424
    AS $_$
2425
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2426
$_$;
2427

    
2428

    
2429
--
2430
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2431
--
2432

    
2433
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2434
    LANGUAGE plpgsql
2435
    AS $$
2436
BEGIN
2437
	-- don't schema_rm() the schema to keep!
2438
	IF replace = with_ THEN RETURN; END IF;
2439
	
2440
	PERFORM util.schema_rm(replace);
2441
	PERFORM util.schema_rename(with_, replace);
2442
END;
2443
$$;
2444

    
2445

    
2446
--
2447
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2448
--
2449

    
2450
CREATE FUNCTION schema_rm(schema text) RETURNS void
2451
    LANGUAGE sql
2452
    AS $_$
2453
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2454
$_$;
2455

    
2456

    
2457
--
2458
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2459
--
2460

    
2461
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2462
    LANGUAGE sql STRICT
2463
    AS $_$
2464
SELECT util.eval(
2465
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2466
$_$;
2467

    
2468

    
2469
--
2470
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2471
--
2472

    
2473
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2474
    LANGUAGE plpgsql STRICT
2475
    AS $_$
2476
DECLARE
2477
    old text[] = ARRAY(SELECT util.col_names(table_));
2478
    new text[] = ARRAY(SELECT util.map_values(names));
2479
BEGIN
2480
    old = old[1:array_length(new, 1)]; -- truncate to same length
2481
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2482
||$$ TO $$||quote_ident(value))
2483
    FROM each(hstore(old, new))
2484
    WHERE value != key -- not same name
2485
    ;
2486
END;
2487
$_$;
2488

    
2489

    
2490
--
2491
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2492
--
2493

    
2494
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2495
idempotent
2496
';
2497

    
2498

    
2499
--
2500
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2501
--
2502

    
2503
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2504
    LANGUAGE plpgsql STRICT
2505
    AS $_$
2506
DECLARE
2507
	row_ util.map;
2508
BEGIN
2509
	-- rename any metadata cols rather than re-adding them with new names
2510
	BEGIN
2511
		PERFORM util.set_col_names(table_, names);
2512
	EXCEPTION
2513
		WHEN array_subscript_error THEN -- selective suppress
2514
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2515
				-- metadata cols not yet added
2516
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2517
			END IF;
2518
	END;
2519
	
2520
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2521
	LOOP
2522
		PERFORM util.mk_const_col((table_, row_."to"),
2523
			substring(row_."from" from 2));
2524
	END LOOP;
2525
	
2526
	PERFORM util.set_col_names(table_, names);
2527
END;
2528
$_$;
2529

    
2530

    
2531
--
2532
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2533
--
2534

    
2535
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2536
idempotent.
2537
the metadata mappings must be *last* in the names table.
2538
';
2539

    
2540

    
2541
--
2542
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2543
--
2544

    
2545
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2546
    LANGUAGE plpgsql STRICT
2547
    AS $_$
2548
DECLARE
2549
    sql text = $$ALTER TABLE $$||table_||$$
2550
$$||NULLIF(array_to_string(ARRAY(
2551
    SELECT
2552
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2553
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2554
    FROM
2555
    (
2556
        SELECT
2557
          quote_ident(col_name) AS col_name_sql
2558
        , util.col_type((table_, col_name)) AS curr_type
2559
        , type AS target_type
2560
        FROM unnest(col_casts)
2561
    ) s
2562
    WHERE curr_type != target_type
2563
), '
2564
, '), '');
2565
BEGIN
2566
    PERFORM util.debug_print_sql(sql);
2567
    EXECUTE COALESCE(sql, '');
2568
END;
2569
$_$;
2570

    
2571

    
2572
--
2573
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2574
--
2575

    
2576
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2577
idempotent
2578
';
2579

    
2580

    
2581
--
2582
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2583
--
2584

    
2585
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2586
    LANGUAGE sql STABLE
2587
    AS $_$
2588
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2589
$$||util.show_grants_for($1)
2590
$_$;
2591

    
2592

    
2593
--
2594
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2595
--
2596

    
2597
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2598
    LANGUAGE sql STABLE
2599
    AS $_$
2600
SELECT string_agg(cmd, '')
2601
FROM
2602
(
2603
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2604
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2605
$$ ELSE '' END) AS cmd
2606
	FROM util.grants_users() f (user_)
2607
) s
2608
$_$;
2609

    
2610

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

    
2615
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2616
    LANGUAGE plpgsql STABLE STRICT
2617
    AS $_$
2618
DECLARE
2619
    hstore hstore;
2620
BEGIN
2621
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2622
        table_||$$))$$ INTO STRICT hstore;
2623
    RETURN hstore;
2624
END;
2625
$_$;
2626

    
2627

    
2628
--
2629
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2630
--
2631

    
2632
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2633
    LANGUAGE sql STABLE STRICT
2634
    AS $_$
2635
SELECT COUNT(*) > 0 FROM pg_constraint
2636
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2637
$_$;
2638

    
2639

    
2640
--
2641
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2642
--
2643

    
2644
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2645
gets whether a status flag is set by the presence of a table constraint
2646
';
2647

    
2648

    
2649
--
2650
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2651
--
2652

    
2653
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2654
    LANGUAGE sql STRICT
2655
    AS $_$
2656
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2657
||quote_ident($2)||$$ CHECK (true)$$)
2658
$_$;
2659

    
2660

    
2661
--
2662
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2663
--
2664

    
2665
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2666
stores a status flag by the presence of a table constraint.
2667
idempotent.
2668
';
2669

    
2670

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

    
2675
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2676
    LANGUAGE sql STABLE STRICT
2677
    AS $_$
2678
SELECT util.table_flag__get($1, 'nulls_mapped')
2679
$_$;
2680

    
2681

    
2682
--
2683
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2684
--
2685

    
2686
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2687
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2688
';
2689

    
2690

    
2691
--
2692
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2693
--
2694

    
2695
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2696
    LANGUAGE sql STRICT
2697
    AS $_$
2698
SELECT util.table_flag__set($1, 'nulls_mapped')
2699
$_$;
2700

    
2701

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

    
2706
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2707
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2708
idempotent.
2709
';
2710

    
2711

    
2712
--
2713
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2714
--
2715

    
2716
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2717
    LANGUAGE plpgsql STRICT
2718
    AS $_$
2719
DECLARE
2720
    row record;
2721
BEGIN
2722
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2723
    LOOP
2724
        IF row.global_name != row.name THEN
2725
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2726
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2727
        END IF;
2728
    END LOOP;
2729
END;
2730
$_$;
2731

    
2732

    
2733
--
2734
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2735
--
2736

    
2737
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2738
idempotent
2739
';
2740

    
2741

    
2742
--
2743
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2744
--
2745

    
2746
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2747
    LANGUAGE sql STRICT
2748
    AS $_$
2749
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2750
SELECT NULL::void; -- don't fold away functions called in previous query
2751
$_$;
2752

    
2753

    
2754
--
2755
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2756
--
2757

    
2758
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2759
trims table_ to include only columns in the original data.
2760
idempotent.
2761
';
2762

    
2763

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

    
2768
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2769
    LANGUAGE plpgsql STRICT
2770
    AS $_$
2771
BEGIN
2772
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2773
END;
2774
$_$;
2775

    
2776

    
2777
--
2778
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2779
--
2780

    
2781
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2782
idempotent
2783
';
2784

    
2785

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

    
2790
CREATE FUNCTION try_create(sql text) RETURNS void
2791
    LANGUAGE plpgsql STRICT
2792
    AS $$
2793
BEGIN
2794
    PERFORM util.eval(sql);
2795
EXCEPTION
2796
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2797
    WHEN undefined_column THEN NULL;
2798
    WHEN duplicate_column THEN NULL;
2799
END;
2800
$$;
2801

    
2802

    
2803
--
2804
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2805
--
2806

    
2807
COMMENT ON FUNCTION try_create(sql text) IS '
2808
idempotent
2809
';
2810

    
2811

    
2812
--
2813
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2814
--
2815

    
2816
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2817
    LANGUAGE sql STRICT
2818
    AS $_$
2819
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2820
$_$;
2821

    
2822

    
2823
--
2824
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2825
--
2826

    
2827
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
2828
idempotent
2829
';
2830

    
2831

    
2832
--
2833
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2834
--
2835

    
2836
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2837
    LANGUAGE sql IMMUTABLE
2838
    AS $_$
2839
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2840
$_$;
2841

    
2842

    
2843
--
2844
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2845
--
2846

    
2847
COMMENT ON FUNCTION type_qual(value anyelement) IS '
2848
a type''s NOT NULL qualifier
2849
';
2850

    
2851

    
2852
--
2853
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2854
--
2855

    
2856
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2857
    LANGUAGE plpgsql STABLE
2858
    AS $_$
2859
DECLARE
2860
    type regtype;
2861
BEGIN
2862
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2863
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2864
    RETURN type;
2865
END;
2866
$_$;
2867

    
2868

    
2869
--
2870
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2871
--
2872

    
2873
CREATE AGGREGATE all_same(anyelement) (
2874
    SFUNC = all_same_transform,
2875
    STYPE = anyarray,
2876
    FINALFUNC = all_same_final
2877
);
2878

    
2879

    
2880
--
2881
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2882
--
2883

    
2884
COMMENT ON AGGREGATE all_same(anyelement) IS '
2885
includes NULLs in comparison
2886
';
2887

    
2888

    
2889
--
2890
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2891
--
2892

    
2893
CREATE AGGREGATE join_strs(text, text) (
2894
    SFUNC = join_strs_transform,
2895
    STYPE = text
2896
);
2897

    
2898

    
2899
--
2900
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2901
--
2902

    
2903
CREATE OPERATOR -> (
2904
    PROCEDURE = map_get,
2905
    LEFTARG = regclass,
2906
    RIGHTARG = text
2907
);
2908

    
2909

    
2910
--
2911
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2912
--
2913

    
2914
CREATE OPERATOR => (
2915
    PROCEDURE = hstore,
2916
    LEFTARG = text[],
2917
    RIGHTARG = text
2918
);
2919

    
2920

    
2921
--
2922
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2923
--
2924

    
2925
COMMENT ON OPERATOR => (text[], text) IS '
2926
usage: array[''key1'', ...]::text[] => ''value''
2927
';
2928

    
2929

    
2930
--
2931
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2932
--
2933

    
2934
CREATE OPERATOR ?*>= (
2935
    PROCEDURE = is_populated_more_often_than,
2936
    LEFTARG = anyelement,
2937
    RIGHTARG = anyelement
2938
);
2939

    
2940

    
2941
--
2942
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2943
--
2944

    
2945
CREATE OPERATOR ?>= (
2946
    PROCEDURE = is_more_complete_than,
2947
    LEFTARG = anyelement,
2948
    RIGHTARG = anyelement
2949
);
2950

    
2951

    
2952
--
2953
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2954
--
2955

    
2956
CREATE OPERATOR ||% (
2957
    PROCEDURE = concat_esc,
2958
    LEFTARG = text,
2959
    RIGHTARG = text
2960
);
2961

    
2962

    
2963
--
2964
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2965
--
2966

    
2967
COMMENT ON OPERATOR ||% (text, text) IS '
2968
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
2969
';
2970

    
2971

    
2972
--
2973
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2974
--
2975

    
2976
CREATE TABLE map (
2977
    "from" text NOT NULL,
2978
    "to" text,
2979
    filter text,
2980
    notes text
2981
);
2982

    
2983

    
2984
--
2985
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2986
--
2987

    
2988

    
2989

    
2990
--
2991
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2992
--
2993

    
2994

    
2995

    
2996
--
2997
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2998
--
2999

    
3000
ALTER TABLE ONLY map
3001
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3002

    
3003

    
3004
--
3005
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3006
--
3007

    
3008
ALTER TABLE ONLY map
3009
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3010

    
3011

    
3012
--
3013
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3014
--
3015

    
3016
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3017

    
3018

    
3019
--
3020
-- PostgreSQL database dump complete
3021
--
3022

    
(19-19/29)