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: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
856
--
857

    
858
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
859
    LANGUAGE plpgsql STRICT
860
    AS $$
861
BEGIN
862
    PERFORM util.eval(sql);
863
EXCEPTION
864
    WHEN duplicate_table  THEN NULL;
865
    WHEN duplicate_object THEN NULL; -- e.g. constraint
866
    WHEN duplicate_column THEN NULL;
867
    WHEN invalid_table_definition THEN
868
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
869
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
870
        END IF;
871
END;
872
$$;
873

    
874

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

    
879
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
880
idempotent
881
';
882

    
883

    
884
--
885
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
886
--
887

    
888
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
889
    LANGUAGE sql IMMUTABLE
890
    AS $_$
891
/* newline before so the query starts at the beginning of the line.
892
newline after to visually separate queries from one another. */
893
SELECT util.raise_notice($$
894
$$||$1||$$
895
$$)
896
$_$;
897

    
898

    
899
--
900
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
901
--
902

    
903
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
904
    LANGUAGE sql STABLE STRICT
905
    AS $_$
906
SELECT util.eval2set($$
907
SELECT col
908
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
909
LEFT JOIN $$||$2||$$ ON "to" = col
910
WHERE "from" IS NULL
911
$$, NULL::text)
912
$_$;
913

    
914

    
915
--
916
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
917
--
918

    
919
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
920
gets table_''s derived columns (all the columns not in the names table)
921
';
922

    
923

    
924
--
925
-- Name: diff_any(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
926
--
927

    
928
CREATE FUNCTION diff_any(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
929
    LANGUAGE sql STABLE
930
    AS $_$
931
SELECT * FROM
932
util.eval2col_pair($$
933
SELECT left_, right_
934
FROM      $$||$1||$$ left_
935
FULL JOIN $$||$2||$$ right_
936
ON left_ = right_
937
WHERE left_ IS DISTINCT FROM right_
938
ORDER BY left_, right_
939
$$, $3)
940
$_$;
941

    
942

    
943
--
944
-- Name: FUNCTION diff_any(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
945
--
946

    
947
COMMENT ON FUNCTION diff_any(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
948
col_type_null (*required*): NULL::col_type
949

    
950
to run EXPLAIN on the FULL JOIN query:
951
# run this function
952
# look for a NOTICE containing the expanded query that it ran
953
# run EXPLAIN on this expanded query
954
';
955

    
956

    
957
--
958
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
959
--
960

    
961
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
962
    LANGUAGE sql STABLE
963
    AS $_$
964
SELECT * FROM util.diff_any($1::text, $2::text, $3)
965
$_$;
966

    
967

    
968
--
969
-- Name: FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
970
--
971

    
972
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
973
col_type_null (*required*): NULL::col_type
974
usage:
975
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
976
';
977

    
978

    
979
--
980
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
981
--
982

    
983
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
984
    LANGUAGE sql STRICT
985
    AS $_$
986
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
987
$_$;
988

    
989

    
990
--
991
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
992
--
993

    
994
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
995
idempotent
996
';
997

    
998

    
999
--
1000
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1001
--
1002

    
1003
CREATE FUNCTION drop_column(col col_ref) RETURNS void
1004
    LANGUAGE sql STRICT
1005
    AS $_$
1006
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1007
quote_ident($1.name))
1008
$_$;
1009

    
1010

    
1011
--
1012
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
1013
--
1014

    
1015
COMMENT ON FUNCTION drop_column(col col_ref) IS '
1016
idempotent
1017
';
1018

    
1019

    
1020
--
1021
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
1022
--
1023

    
1024
CREATE FUNCTION drop_table(table_ text) RETURNS void
1025
    LANGUAGE sql STRICT
1026
    AS $_$
1027
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
1028
$_$;
1029

    
1030

    
1031
--
1032
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
1033
--
1034

    
1035
COMMENT ON FUNCTION drop_table(table_ text) IS '
1036
idempotent
1037
';
1038

    
1039

    
1040
--
1041
-- Name: drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1042
--
1043

    
1044
CREATE FUNCTION drop_view(view_ text) RETURNS void
1045
    LANGUAGE sql STRICT
1046
    AS $_$
1047
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1)
1048
$_$;
1049

    
1050

    
1051
--
1052
-- Name: FUNCTION drop_view(view_ text); Type: COMMENT; Schema: util; Owner: -
1053
--
1054

    
1055
COMMENT ON FUNCTION drop_view(view_ text) IS '
1056
idempotent
1057
';
1058

    
1059

    
1060
--
1061
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1062
--
1063

    
1064
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1065
    LANGUAGE sql IMMUTABLE
1066
    AS $_$
1067
SELECT util.array_fill($1, 0)
1068
$_$;
1069

    
1070

    
1071
--
1072
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1073
--
1074

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

    
1079

    
1080
--
1081
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1082
--
1083

    
1084
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1085
    LANGUAGE sql IMMUTABLE
1086
    AS $_$
1087
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1088
$_$;
1089

    
1090

    
1091
--
1092
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1093
--
1094

    
1095
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1096
    LANGUAGE sql IMMUTABLE
1097
    AS $_$
1098
SELECT regexp_replace($2, '("?)$', $1||'\1')
1099
$_$;
1100

    
1101

    
1102
--
1103
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1104
--
1105

    
1106
CREATE FUNCTION eval(sql text) RETURNS void
1107
    LANGUAGE plpgsql STRICT
1108
    AS $$
1109
BEGIN
1110
	PERFORM util.debug_print_sql(sql);
1111
	EXECUTE sql;
1112
END;
1113
$$;
1114

    
1115

    
1116
--
1117
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1118
--
1119

    
1120
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1121
    LANGUAGE plpgsql
1122
    AS $$
1123
BEGIN
1124
	PERFORM util.debug_print_sql(sql);
1125
	RETURN QUERY EXECUTE sql;
1126
END;
1127
$$;
1128

    
1129

    
1130
--
1131
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1132
--
1133

    
1134
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1135
col_type_null (*required*): NULL::col_type
1136
';
1137

    
1138

    
1139
--
1140
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1141
--
1142

    
1143
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1144
    LANGUAGE plpgsql
1145
    AS $$
1146
BEGIN
1147
	PERFORM util.debug_print_sql(sql);
1148
	RETURN QUERY EXECUTE sql;
1149
END;
1150
$$;
1151

    
1152

    
1153
--
1154
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1155
--
1156

    
1157
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1158
ret_type_null: NULL::ret_type
1159
';
1160

    
1161

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

    
1166
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1167
    LANGUAGE plpgsql
1168
    AS $$
1169
DECLARE
1170
	ret_val ret_type_null%TYPE;
1171
BEGIN
1172
	PERFORM util.debug_print_sql(sql);
1173
	EXECUTE sql INTO STRICT ret_val;
1174
	RETURN ret_val;
1175
END;
1176
$$;
1177

    
1178

    
1179
--
1180
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1181
--
1182

    
1183
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1184
ret_type_null: NULL::ret_type
1185
';
1186

    
1187

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

    
1192
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1193
    LANGUAGE sql
1194
    AS $_$
1195
SELECT util.eval2val($$SELECT $$||$1, $2)
1196
$_$;
1197

    
1198

    
1199
--
1200
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1201
--
1202

    
1203
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1204
ret_type_null: NULL::ret_type
1205
';
1206

    
1207

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

    
1212
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1213
    LANGUAGE sql
1214
    AS $_$
1215
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1216
$_$;
1217

    
1218

    
1219
--
1220
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1221
--
1222

    
1223
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1224
sql: can be NULL, which will be passed through
1225
ret_type_null: NULL::ret_type
1226
';
1227

    
1228

    
1229
--
1230
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1231
--
1232

    
1233
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1234
    LANGUAGE sql STABLE STRICT
1235
    AS $_$
1236
SELECT col_name
1237
FROM unnest($2) s (col_name)
1238
WHERE util.col_exists(($1, col_name))
1239
$_$;
1240

    
1241

    
1242
--
1243
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1244
--
1245

    
1246
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1247
    LANGUAGE sql
1248
    AS $_$
1249
SELECT util.eval2set($$EXPLAIN $$||$1)
1250
$_$;
1251

    
1252

    
1253
--
1254
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1255
--
1256

    
1257
CREATE FUNCTION explain2notice(sql text) RETURNS void
1258
    LANGUAGE plpgsql
1259
    AS $_$
1260
BEGIN
1261
	RAISE NOTICE '%', $$EXPLAIN:
1262
$$||util.explain2str(sql);
1263
END;
1264
$_$;
1265

    
1266

    
1267
--
1268
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1269
--
1270

    
1271
CREATE FUNCTION explain2str(sql text) RETURNS text
1272
    LANGUAGE sql
1273
    AS $_$
1274
SELECT util.join_strs(explain, $$
1275
$$) FROM util.explain($1)
1276
$_$;
1277

    
1278

    
1279
SET default_tablespace = '';
1280

    
1281
SET default_with_oids = false;
1282

    
1283
--
1284
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1285
--
1286

    
1287
CREATE TABLE explain (
1288
    line text NOT NULL
1289
);
1290

    
1291

    
1292
--
1293
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1294
--
1295

    
1296
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1297
    LANGUAGE sql
1298
    AS $_$
1299
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1300
$$||quote_nullable($1)||$$
1301
)$$)
1302
$_$;
1303

    
1304

    
1305
--
1306
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1307
--
1308

    
1309
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1310
usage:
1311
PERFORM util.explain2table($$
1312
query
1313
$$);
1314
';
1315

    
1316

    
1317
--
1318
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1319
--
1320

    
1321
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1322
    LANGUAGE sql IMMUTABLE
1323
    AS $_$
1324
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1325
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1326
) END
1327
$_$;
1328

    
1329

    
1330
--
1331
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1332
--
1333

    
1334
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1335
ensures that an array will always have proper non-NULL dimensions
1336
';
1337

    
1338

    
1339
--
1340
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1341
--
1342

    
1343
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1344
    LANGUAGE plpgsql
1345
    AS $_$
1346
DECLARE
1347
	PG_EXCEPTION_DETAIL text;
1348
	recreate_users_cmd text = util.save_drop_views(users);
1349
BEGIN
1350
	PERFORM util.eval(cmd);
1351
	PERFORM util.eval(recreate_users_cmd);
1352
EXCEPTION
1353
WHEN dependent_objects_still_exist THEN
1354
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1355
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1356
	users = array(SELECT * FROM util.regexp_matches_group(
1357
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1358
	IF util.is_empty(users) THEN RAISE; END IF;
1359
	PERFORM util.force_recreate(cmd, users);
1360
END;
1361
$_$;
1362

    
1363

    
1364
--
1365
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1366
--
1367

    
1368
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1369
idempotent
1370

    
1371
users: not necessary to provide this because it will be autopopulated
1372
';
1373

    
1374

    
1375
--
1376
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1377
--
1378

    
1379
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1380
    LANGUAGE plpgsql STRICT
1381
    AS $_$
1382
DECLARE
1383
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1384
$$||query;
1385
BEGIN
1386
	EXECUTE mk_view;
1387
EXCEPTION
1388
WHEN invalid_table_definition THEN
1389
	IF SQLERRM = 'cannot drop columns from view'
1390
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1391
	THEN
1392
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1393
		EXECUTE mk_view;
1394
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1395
	END IF;
1396
END;
1397
$_$;
1398

    
1399

    
1400
--
1401
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1402
--
1403

    
1404
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1405
idempotent
1406
';
1407

    
1408

    
1409
--
1410
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1411
--
1412

    
1413
CREATE FUNCTION grants_users() RETURNS SETOF text
1414
    LANGUAGE sql IMMUTABLE
1415
    AS $$
1416
VALUES ('bien_read'), ('public_')
1417
$$;
1418

    
1419

    
1420
--
1421
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1422
--
1423

    
1424
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1425
    LANGUAGE sql IMMUTABLE
1426
    AS $_$
1427
SELECT substring($2 for length($1)) = $1
1428
$_$;
1429

    
1430

    
1431
--
1432
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1433
--
1434

    
1435
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1436
    LANGUAGE sql IMMUTABLE
1437
    AS $_$
1438
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1439
$_$;
1440

    
1441

    
1442
--
1443
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1444
--
1445

    
1446
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1447
avoids repeating the same value for each key
1448
';
1449

    
1450

    
1451
--
1452
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1453
--
1454

    
1455
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1456
    LANGUAGE sql IMMUTABLE
1457
    AS $_$
1458
SELECT COALESCE($1, $2)
1459
$_$;
1460

    
1461

    
1462
--
1463
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1464
--
1465

    
1466
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1467
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1468
';
1469

    
1470

    
1471
--
1472
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1473
--
1474

    
1475
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1476
    LANGUAGE sql STABLE STRICT
1477
    AS $_$
1478
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1479
$_$;
1480

    
1481

    
1482
--
1483
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1484
--
1485

    
1486
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1487
    LANGUAGE sql IMMUTABLE
1488
    AS $_$
1489
SELECT util.array_length($1) = 0
1490
$_$;
1491

    
1492

    
1493
--
1494
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1495
--
1496

    
1497
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1498
    LANGUAGE sql IMMUTABLE
1499
    AS $_$
1500
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1501
$_$;
1502

    
1503

    
1504
--
1505
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1506
--
1507

    
1508
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1509
    LANGUAGE sql IMMUTABLE
1510
    AS $_$
1511
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1512
$_$;
1513

    
1514

    
1515
--
1516
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1517
--
1518

    
1519
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1520
    LANGUAGE sql IMMUTABLE STRICT
1521
    AS $_$
1522
SELECT $1 || $3 || $2
1523
$_$;
1524

    
1525

    
1526
--
1527
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1528
--
1529

    
1530
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1531
    LANGUAGE sql IMMUTABLE
1532
    AS $_$
1533
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1534
$_$;
1535

    
1536

    
1537
--
1538
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1539
--
1540

    
1541
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1542
    LANGUAGE sql IMMUTABLE
1543
    AS $_$
1544
SELECT ltrim($1, $$
1545
$$)
1546
$_$;
1547

    
1548

    
1549
--
1550
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1551
--
1552

    
1553
CREATE FUNCTION map_filter_insert() RETURNS trigger
1554
    LANGUAGE plpgsql
1555
    AS $$
1556
BEGIN
1557
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1558
	RETURN new;
1559
END;
1560
$$;
1561

    
1562

    
1563
--
1564
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1565
--
1566

    
1567
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1568
    LANGUAGE plpgsql STABLE STRICT
1569
    AS $_$
1570
DECLARE
1571
    value text;
1572
BEGIN
1573
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1574
        INTO value USING key;
1575
    RETURN value;
1576
END;
1577
$_$;
1578

    
1579

    
1580
--
1581
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1582
--
1583

    
1584
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1585
    LANGUAGE sql IMMUTABLE
1586
    AS $_$
1587
SELECT util._map(util.nulls_map($1), $2)
1588
$_$;
1589

    
1590

    
1591
--
1592
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1593
--
1594

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

    
1598
[1] inlining of function calls, which is different from constant folding
1599
[2] _map()''s profiling query
1600
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1601
and map_nulls()''s profiling query
1602
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1603
both take ~920 ms.
1604
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.
1605
';
1606

    
1607

    
1608
--
1609
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1610
--
1611

    
1612
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1613
    LANGUAGE plpgsql STABLE STRICT
1614
    AS $_$
1615
BEGIN
1616
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1617
END;
1618
$_$;
1619

    
1620

    
1621
--
1622
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1623
--
1624

    
1625
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1626
    LANGUAGE sql
1627
    AS $_$
1628
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1629
$$||util.ltrim_nl($2))
1630
$_$;
1631

    
1632

    
1633
--
1634
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1635
--
1636

    
1637
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1638
idempotent
1639
';
1640

    
1641

    
1642
--
1643
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1644
--
1645

    
1646
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1647
    LANGUAGE sql
1648
    AS $_$
1649
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1650
$_$;
1651

    
1652

    
1653
--
1654
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1655
--
1656

    
1657
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1658
idempotent
1659
';
1660

    
1661

    
1662
--
1663
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1664
--
1665

    
1666
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1667
    LANGUAGE sql STRICT
1668
    AS $_$
1669
SELECT util.create_if_not_exists($$
1670
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1671
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1672
||quote_literal($2)||$$;
1673
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1674
constant
1675
';
1676
$$)
1677
$_$;
1678

    
1679

    
1680
--
1681
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1682
--
1683

    
1684
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1685
idempotent
1686
';
1687

    
1688

    
1689
--
1690
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1691
--
1692

    
1693
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1694
    LANGUAGE plpgsql STRICT
1695
    AS $_$
1696
DECLARE
1697
    type regtype = util.typeof(expr, col.table_::text::regtype);
1698
    col_name_sql text = quote_ident(col.name);
1699
BEGIN
1700
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1701
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1702
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1703
$$||expr||$$;
1704
$$);
1705
END;
1706
$_$;
1707

    
1708

    
1709
--
1710
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1711
--
1712

    
1713
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1714
idempotent
1715
';
1716

    
1717

    
1718
--
1719
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1720
--
1721

    
1722
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1723
    LANGUAGE sql STRICT
1724
    AS $_$
1725
SELECT util.create_if_not_exists($$
1726
CREATE TABLE $$||$1||$$
1727
(
1728
    LIKE util.map INCLUDING ALL
1729
);
1730

    
1731
CREATE TRIGGER map_filter_insert
1732
  BEFORE INSERT
1733
  ON $$||$1||$$
1734
  FOR EACH ROW
1735
  EXECUTE PROCEDURE util.map_filter_insert();
1736
$$)
1737
$_$;
1738

    
1739

    
1740
--
1741
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1742
--
1743

    
1744
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1745
    LANGUAGE sql IMMUTABLE
1746
    AS $_$
1747
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1748
$_$;
1749

    
1750

    
1751
--
1752
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1753
--
1754

    
1755
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1756
    LANGUAGE sql IMMUTABLE
1757
    AS $_$
1758
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1764
--
1765

    
1766
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1767
usage:
1768
for *1* schema arg:
1769
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1770
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1771
';
1772

    
1773

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

    
1778
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1779
    LANGUAGE sql IMMUTABLE
1780
    AS $_$
1781
SELECT $$SET LOCAL search_path TO $$||$1
1782
$_$;
1783

    
1784

    
1785
--
1786
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1787
--
1788

    
1789
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1790
    LANGUAGE sql STRICT
1791
    AS $_$
1792
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1793
$_$;
1794

    
1795

    
1796
--
1797
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1798
--
1799

    
1800
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1801
idempotent
1802
';
1803

    
1804

    
1805
--
1806
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1807
--
1808

    
1809
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1810
    LANGUAGE plpgsql STRICT
1811
    AS $_$
1812
DECLARE
1813
	view_qual_name text = util.qual_name(view_);
1814
BEGIN
1815
	EXECUTE $$
1816
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1817
  RETURNS SETOF $$||view_||$$ AS
1818
$BODY1$
1819
SELECT * FROM $$||view_qual_name||$$
1820
ORDER BY sort_col
1821
LIMIT $1 OFFSET $2
1822
$BODY1$
1823
  LANGUAGE sql STABLE
1824
  COST 100
1825
  ROWS 1000
1826
$$;
1827
	
1828
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1829
END;
1830
$_$;
1831

    
1832

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

    
1837
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1838
    LANGUAGE plpgsql STRICT
1839
    AS $_$
1840
DECLARE
1841
	view_qual_name text = util.qual_name(view_);
1842
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1843
BEGIN
1844
	EXECUTE $$
1845
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1846
  RETURNS integer AS
1847
$BODY1$
1848
SELECT $$||quote_ident(row_num_col)||$$
1849
FROM $$||view_qual_name||$$
1850
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1851
LIMIT 1
1852
$BODY1$
1853
  LANGUAGE sql STABLE
1854
  COST 100;
1855
$$;
1856
	
1857
	EXECUTE $$
1858
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1859
  RETURNS SETOF $$||view_||$$ AS
1860
$BODY1$
1861
SELECT * FROM $$||view_qual_name||$$
1862
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1863
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1864
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1865
ORDER BY $$||quote_ident(row_num_col)||$$
1866
$BODY1$
1867
  LANGUAGE sql STABLE
1868
  COST 100
1869
  ROWS 1000
1870
$$;
1871
	
1872
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1873
END;
1874
$_$;
1875

    
1876

    
1877
--
1878
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1879
--
1880

    
1881
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1882
    LANGUAGE plpgsql STRICT
1883
    AS $_$
1884
DECLARE
1885
	view_qual_name text = util.qual_name(view_);
1886
BEGIN
1887
	EXECUTE $$
1888
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1889
  RETURNS SETOF $$||view_||$$
1890
  SET enable_sort TO 'off'
1891
  AS
1892
$BODY1$
1893
SELECT * FROM $$||view_qual_name||$$($2, $3)
1894
$BODY1$
1895
  LANGUAGE sql STABLE
1896
  COST 100
1897
  ROWS 1000
1898
;
1899
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1900
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1901
If you want to run EXPLAIN and get expanded output, use the regular subset
1902
function instead. (When a config param is set on a function, EXPLAIN produces
1903
just a function scan.)
1904
';
1905
$$;
1906
END;
1907
$_$;
1908

    
1909

    
1910
--
1911
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1912
--
1913

    
1914
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
1915
creates subset function which turns off enable_sort
1916
';
1917

    
1918

    
1919
--
1920
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1921
--
1922

    
1923
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
1924
    LANGUAGE sql IMMUTABLE
1925
    AS $_$
1926
SELECT util.mk_set_search_path(util.schema_esc($1))
1927
$_$;
1928

    
1929

    
1930
--
1931
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
1932
--
1933

    
1934
CREATE FUNCTION name(table_ regclass) RETURNS text
1935
    LANGUAGE sql STABLE
1936
    AS $_$
1937
SELECT relname::text FROM pg_class WHERE oid = $1
1938
$_$;
1939

    
1940

    
1941
--
1942
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1943
--
1944

    
1945
CREATE FUNCTION name(type regtype) RETURNS text
1946
    LANGUAGE sql STABLE STRICT
1947
    AS $_$
1948
SELECT typname::text FROM pg_type WHERE oid = $1
1949
$_$;
1950

    
1951

    
1952
--
1953
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1954
--
1955

    
1956
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1957
    LANGUAGE sql IMMUTABLE
1958
    AS $_$
1959
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1960
$_$;
1961

    
1962

    
1963
--
1964
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1965
--
1966

    
1967
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1968
    LANGUAGE sql IMMUTABLE
1969
    AS $_$
1970
SELECT $1 IS NOT NULL
1971
$_$;
1972

    
1973

    
1974
--
1975
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1976
--
1977

    
1978
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1979
    LANGUAGE sql IMMUTABLE
1980
    AS $_$
1981
SELECT util.hstore($1, NULL) || '*=>*'
1982
$_$;
1983

    
1984

    
1985
--
1986
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1987
--
1988

    
1989
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
1990
for use with _map()
1991
';
1992

    
1993

    
1994
--
1995
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1996
--
1997

    
1998
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1999
    LANGUAGE sql IMMUTABLE
2000
    AS $_$
2001
SELECT $2 + COALESCE($1, 0)
2002
$_$;
2003

    
2004

    
2005
--
2006
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2007
--
2008

    
2009
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2010
    LANGUAGE sql IMMUTABLE
2011
    AS $_$
2012
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2013
$_$;
2014

    
2015

    
2016
--
2017
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2018
--
2019

    
2020
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2021
    LANGUAGE sql STABLE STRICT
2022
    SET search_path TO pg_temp
2023
    AS $_$
2024
SELECT $1::text
2025
$_$;
2026

    
2027

    
2028
--
2029
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2030
--
2031

    
2032
CREATE FUNCTION qual_name(type regtype) RETURNS text
2033
    LANGUAGE sql STABLE STRICT
2034
    SET search_path TO pg_temp
2035
    AS $_$
2036
SELECT $1::text
2037
$_$;
2038

    
2039

    
2040
--
2041
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2042
--
2043

    
2044
COMMENT ON FUNCTION qual_name(type regtype) IS '
2045
a type''s schema-qualified name
2046
';
2047

    
2048

    
2049
--
2050
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2051
--
2052

    
2053
CREATE FUNCTION qual_name(type unknown) RETURNS text
2054
    LANGUAGE sql STABLE STRICT
2055
    AS $_$
2056
SELECT util.qual_name($1::text::regtype)
2057
$_$;
2058

    
2059

    
2060
--
2061
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2062
--
2063

    
2064
CREATE FUNCTION raise_notice(msg text) RETURNS void
2065
    LANGUAGE plpgsql IMMUTABLE STRICT
2066
    AS $$
2067
BEGIN
2068
	RAISE NOTICE '%', msg;
2069
END;
2070
$$;
2071

    
2072

    
2073
--
2074
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2075
--
2076

    
2077
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2078
    LANGUAGE plpgsql IMMUTABLE STRICT
2079
    AS $$
2080
BEGIN
2081
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2082
END;
2083
$$;
2084

    
2085

    
2086
--
2087
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089

    
2090
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2091
    LANGUAGE sql IMMUTABLE
2092
    AS $_$
2093
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2094
$_$;
2095

    
2096

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

    
2101
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2102
    LANGUAGE sql
2103
    AS $_$
2104
SELECT util.drop_table($1);
2105
SELECT util.materialize_query($1, $2);
2106
$_$;
2107

    
2108

    
2109
--
2110
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2111
--
2112

    
2113
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2114
idempotent, but repeats action each time
2115
';
2116

    
2117

    
2118
--
2119
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2120
--
2121

    
2122
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2123
    LANGUAGE sql
2124
    AS $_$
2125
SELECT util.drop_table($1);
2126
SELECT util.materialize_view($1, $2);
2127
$_$;
2128

    
2129

    
2130
--
2131
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2132
--
2133

    
2134
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2135
idempotent, but repeats action each time
2136
';
2137

    
2138

    
2139
--
2140
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2141
--
2142

    
2143
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2144
    LANGUAGE sql STRICT
2145
    AS $_$
2146
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2147
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2148
FROM util.col_names($1::text::regtype) f (name);
2149
SELECT NULL::void; -- don't fold away functions called in previous query
2150
$_$;
2151

    
2152

    
2153
--
2154
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2155
--
2156

    
2157
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2158
idempotent
2159
';
2160

    
2161

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

    
2166
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2167
    LANGUAGE sql STRICT
2168
    AS $_$
2169
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2170
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2171
SELECT util.set_col_names($1, $2);
2172
$_$;
2173

    
2174

    
2175
--
2176
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2177
--
2178

    
2179
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2180
idempotent.
2181
alters the names table, so it will need to be repopulated after running this function.
2182
';
2183

    
2184

    
2185
--
2186
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2187
--
2188

    
2189
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2190
    LANGUAGE sql STRICT
2191
    AS $_$
2192
SELECT util.drop_table($1);
2193
SELECT util.mk_map_table($1);
2194
$_$;
2195

    
2196

    
2197
--
2198
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2199
--
2200

    
2201
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2202
    LANGUAGE plpgsql STRICT
2203
    AS $_$
2204
DECLARE
2205
	result text = NULL;
2206
BEGIN
2207
	BEGIN
2208
		result = util.show_create_view(view_);
2209
		PERFORM util.eval($$DROP VIEW $$||view_);
2210
	EXCEPTION
2211
		WHEN undefined_table THEN NULL;
2212
	END;
2213
	RETURN result;
2214
END;
2215
$_$;
2216

    
2217

    
2218
--
2219
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2220
--
2221

    
2222
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2223
    LANGUAGE sql
2224
    AS $_$
2225
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2226
$_$;
2227

    
2228

    
2229
--
2230
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2231
--
2232

    
2233
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2234
    LANGUAGE sql STABLE
2235
    AS $_$
2236
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2237
$_$;
2238

    
2239

    
2240
--
2241
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2242
--
2243

    
2244
CREATE FUNCTION schema(table_ regclass) RETURNS text
2245
    LANGUAGE sql STABLE
2246
    AS $_$
2247
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2248
$_$;
2249

    
2250

    
2251
--
2252
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2253
--
2254

    
2255
CREATE FUNCTION schema(type regtype) RETURNS text
2256
    LANGUAGE sql STABLE
2257
    AS $_$
2258
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2259
$_$;
2260

    
2261

    
2262
--
2263
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2264
--
2265

    
2266
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2267
    LANGUAGE sql STABLE
2268
    AS $_$
2269
SELECT util.schema(pg_typeof($1))
2270
$_$;
2271

    
2272

    
2273
--
2274
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2278
    LANGUAGE sql STABLE
2279
    AS $_$
2280
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2281
$_$;
2282

    
2283

    
2284
--
2285
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2286
--
2287

    
2288
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2289
a schema bundle is a group of schemas with a common prefix
2290
';
2291

    
2292

    
2293
--
2294
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2295
--
2296

    
2297
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2298
    LANGUAGE sql
2299
    AS $_$
2300
SELECT util.schema_rename(old_schema,
2301
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2302
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2303
SELECT NULL::void; -- don't fold away functions called in previous query
2304
$_$;
2305

    
2306

    
2307
--
2308
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2309
--
2310

    
2311
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2312
    LANGUAGE plpgsql
2313
    AS $$
2314
BEGIN
2315
	-- don't schema_bundle_rm() the schema_bundle to keep!
2316
	IF replace = with_ THEN RETURN; END IF;
2317
	
2318
	PERFORM util.schema_bundle_rm(replace);
2319
	PERFORM util.schema_bundle_rename(with_, replace);
2320
END;
2321
$$;
2322

    
2323

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

    
2328
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2329
    LANGUAGE sql
2330
    AS $_$
2331
SELECT util.schema_rm(schema)
2332
FROM util.schema_bundle_get_schemas($1) f (schema);
2333
SELECT NULL::void; -- don't fold away functions called in previous query
2334
$_$;
2335

    
2336

    
2337
--
2338
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2339
--
2340

    
2341
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2342
    LANGUAGE sql STABLE
2343
    AS $_$
2344
SELECT quote_ident(util.schema($1))
2345
$_$;
2346

    
2347

    
2348
--
2349
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2350
--
2351

    
2352
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2353
    LANGUAGE sql
2354
    AS $_$
2355
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2356
$_$;
2357

    
2358

    
2359
--
2360
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2361
--
2362

    
2363
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2364
    LANGUAGE plpgsql
2365
    AS $$
2366
BEGIN
2367
	-- don't schema_rm() the schema to keep!
2368
	IF replace = with_ THEN RETURN; END IF;
2369
	
2370
	PERFORM util.schema_rm(replace);
2371
	PERFORM util.schema_rename(with_, replace);
2372
END;
2373
$$;
2374

    
2375

    
2376
--
2377
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2378
--
2379

    
2380
CREATE FUNCTION schema_rm(schema text) RETURNS void
2381
    LANGUAGE sql
2382
    AS $_$
2383
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2384
$_$;
2385

    
2386

    
2387
--
2388
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2389
--
2390

    
2391
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2392
    LANGUAGE sql STRICT
2393
    AS $_$
2394
SELECT util.eval(
2395
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2396
$_$;
2397

    
2398

    
2399
--
2400
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2401
--
2402

    
2403
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2404
    LANGUAGE plpgsql STRICT
2405
    AS $_$
2406
DECLARE
2407
    old text[] = ARRAY(SELECT util.col_names(table_));
2408
    new text[] = ARRAY(SELECT util.map_values(names));
2409
BEGIN
2410
    old = old[1:array_length(new, 1)]; -- truncate to same length
2411
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2412
||$$ TO $$||quote_ident(value))
2413
    FROM each(hstore(old, new))
2414
    WHERE value != key -- not same name
2415
    ;
2416
END;
2417
$_$;
2418

    
2419

    
2420
--
2421
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2422
--
2423

    
2424
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2425
idempotent
2426
';
2427

    
2428

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

    
2433
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2434
    LANGUAGE plpgsql STRICT
2435
    AS $_$
2436
DECLARE
2437
	row_ util.map;
2438
BEGIN
2439
	-- rename any metadata cols rather than re-adding them with new names
2440
	BEGIN
2441
		PERFORM util.set_col_names(table_, names);
2442
	EXCEPTION
2443
		WHEN array_subscript_error THEN -- selective suppress
2444
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2445
				-- metadata cols not yet added
2446
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2447
			END IF;
2448
	END;
2449
	
2450
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2451
	LOOP
2452
		PERFORM util.mk_const_col((table_, row_."to"),
2453
			substring(row_."from" from 2));
2454
	END LOOP;
2455
	
2456
	PERFORM util.set_col_names(table_, names);
2457
END;
2458
$_$;
2459

    
2460

    
2461
--
2462
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2463
--
2464

    
2465
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2466
idempotent.
2467
the metadata mappings must be *last* in the names table.
2468
';
2469

    
2470

    
2471
--
2472
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2473
--
2474

    
2475
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2476
    LANGUAGE plpgsql STRICT
2477
    AS $_$
2478
DECLARE
2479
    sql text = $$ALTER TABLE $$||table_||$$
2480
$$||NULLIF(array_to_string(ARRAY(
2481
    SELECT
2482
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2483
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2484
    FROM
2485
    (
2486
        SELECT
2487
          quote_ident(col_name) AS col_name_sql
2488
        , util.col_type((table_, col_name)) AS curr_type
2489
        , type AS target_type
2490
        FROM unnest(col_casts)
2491
    ) s
2492
    WHERE curr_type != target_type
2493
), '
2494
, '), '');
2495
BEGIN
2496
    PERFORM util.debug_print_sql(sql);
2497
    EXECUTE COALESCE(sql, '');
2498
END;
2499
$_$;
2500

    
2501

    
2502
--
2503
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2504
--
2505

    
2506
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2507
idempotent
2508
';
2509

    
2510

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

    
2515
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2516
    LANGUAGE sql STABLE
2517
    AS $_$
2518
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2519
$$||util.show_grants_for($1)
2520
$_$;
2521

    
2522

    
2523
--
2524
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2525
--
2526

    
2527
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2528
    LANGUAGE sql STABLE
2529
    AS $_$
2530
SELECT string_agg(cmd, '')
2531
FROM
2532
(
2533
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2534
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2535
$$ ELSE '' END) AS cmd
2536
	FROM util.grants_users() f (user_)
2537
) s
2538
$_$;
2539

    
2540

    
2541
--
2542
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2543
--
2544

    
2545
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2546
    LANGUAGE plpgsql STABLE STRICT
2547
    AS $_$
2548
DECLARE
2549
    hstore hstore;
2550
BEGIN
2551
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2552
        table_||$$))$$ INTO STRICT hstore;
2553
    RETURN hstore;
2554
END;
2555
$_$;
2556

    
2557

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

    
2562
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2563
    LANGUAGE sql STABLE STRICT
2564
    AS $_$
2565
SELECT COUNT(*) > 0 FROM pg_constraint
2566
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2567
$_$;
2568

    
2569

    
2570
--
2571
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2572
--
2573

    
2574
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2575
gets whether a status flag is set by the presence of a table constraint
2576
';
2577

    
2578

    
2579
--
2580
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2581
--
2582

    
2583
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2584
    LANGUAGE sql STRICT
2585
    AS $_$
2586
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2587
||quote_ident($2)||$$ CHECK (true)$$)
2588
$_$;
2589

    
2590

    
2591
--
2592
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2593
--
2594

    
2595
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2596
stores a status flag by the presence of a table constraint.
2597
idempotent.
2598
';
2599

    
2600

    
2601
--
2602
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2603
--
2604

    
2605
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2606
    LANGUAGE sql STABLE STRICT
2607
    AS $_$
2608
SELECT util.table_flag__get($1, 'nulls_mapped')
2609
$_$;
2610

    
2611

    
2612
--
2613
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2614
--
2615

    
2616
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2617
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2618
';
2619

    
2620

    
2621
--
2622
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2623
--
2624

    
2625
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2626
    LANGUAGE sql STRICT
2627
    AS $_$
2628
SELECT util.table_flag__set($1, 'nulls_mapped')
2629
$_$;
2630

    
2631

    
2632
--
2633
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2634
--
2635

    
2636
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2637
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2638
idempotent.
2639
';
2640

    
2641

    
2642
--
2643
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2644
--
2645

    
2646
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2647
    LANGUAGE plpgsql STRICT
2648
    AS $_$
2649
DECLARE
2650
    row record;
2651
BEGIN
2652
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2653
    LOOP
2654
        IF row.global_name != row.name THEN
2655
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2656
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2657
        END IF;
2658
    END LOOP;
2659
END;
2660
$_$;
2661

    
2662

    
2663
--
2664
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2665
--
2666

    
2667
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2668
idempotent
2669
';
2670

    
2671

    
2672
--
2673
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2674
--
2675

    
2676
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2677
    LANGUAGE sql STRICT
2678
    AS $_$
2679
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2680
SELECT NULL::void; -- don't fold away functions called in previous query
2681
$_$;
2682

    
2683

    
2684
--
2685
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2686
--
2687

    
2688
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2689
trims table_ to include only columns in the original data.
2690
idempotent.
2691
';
2692

    
2693

    
2694
--
2695
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2696
--
2697

    
2698
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2699
    LANGUAGE plpgsql STRICT
2700
    AS $_$
2701
BEGIN
2702
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2703
END;
2704
$_$;
2705

    
2706

    
2707
--
2708
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2709
--
2710

    
2711
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2712
idempotent
2713
';
2714

    
2715

    
2716
--
2717
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2718
--
2719

    
2720
CREATE FUNCTION try_create(sql text) RETURNS void
2721
    LANGUAGE plpgsql STRICT
2722
    AS $$
2723
BEGIN
2724
    PERFORM util.eval(sql);
2725
EXCEPTION
2726
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2727
    WHEN undefined_column THEN NULL;
2728
    WHEN duplicate_column THEN NULL;
2729
END;
2730
$$;
2731

    
2732

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

    
2737
COMMENT ON FUNCTION try_create(sql text) IS '
2738
idempotent
2739
';
2740

    
2741

    
2742
--
2743
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2744
--
2745

    
2746
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2747
    LANGUAGE sql STRICT
2748
    AS $_$
2749
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2750
$_$;
2751

    
2752

    
2753
--
2754
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2755
--
2756

    
2757
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
2758
idempotent
2759
';
2760

    
2761

    
2762
--
2763
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2764
--
2765

    
2766
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2767
    LANGUAGE sql IMMUTABLE
2768
    AS $_$
2769
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2770
$_$;
2771

    
2772

    
2773
--
2774
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2775
--
2776

    
2777
COMMENT ON FUNCTION type_qual(value anyelement) IS '
2778
a type''s NOT NULL qualifier
2779
';
2780

    
2781

    
2782
--
2783
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2784
--
2785

    
2786
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2787
    LANGUAGE plpgsql STABLE
2788
    AS $_$
2789
DECLARE
2790
    type regtype;
2791
BEGIN
2792
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2793
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2794
    RETURN type;
2795
END;
2796
$_$;
2797

    
2798

    
2799
--
2800
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2801
--
2802

    
2803
CREATE AGGREGATE all_same(anyelement) (
2804
    SFUNC = all_same_transform,
2805
    STYPE = anyarray,
2806
    FINALFUNC = all_same_final
2807
);
2808

    
2809

    
2810
--
2811
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2812
--
2813

    
2814
COMMENT ON AGGREGATE all_same(anyelement) IS '
2815
includes NULLs in comparison
2816
';
2817

    
2818

    
2819
--
2820
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2821
--
2822

    
2823
CREATE AGGREGATE join_strs(text, text) (
2824
    SFUNC = join_strs_transform,
2825
    STYPE = text
2826
);
2827

    
2828

    
2829
--
2830
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2831
--
2832

    
2833
CREATE OPERATOR -> (
2834
    PROCEDURE = map_get,
2835
    LEFTARG = regclass,
2836
    RIGHTARG = text
2837
);
2838

    
2839

    
2840
--
2841
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2842
--
2843

    
2844
CREATE OPERATOR => (
2845
    PROCEDURE = hstore,
2846
    LEFTARG = text[],
2847
    RIGHTARG = text
2848
);
2849

    
2850

    
2851
--
2852
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2853
--
2854

    
2855
COMMENT ON OPERATOR => (text[], text) IS '
2856
usage: array[''key1'', ...]::text[] => ''value''
2857
';
2858

    
2859

    
2860
--
2861
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2862
--
2863

    
2864
CREATE OPERATOR ?*>= (
2865
    PROCEDURE = is_populated_more_often_than,
2866
    LEFTARG = anyelement,
2867
    RIGHTARG = anyelement
2868
);
2869

    
2870

    
2871
--
2872
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2873
--
2874

    
2875
CREATE OPERATOR ?>= (
2876
    PROCEDURE = is_more_complete_than,
2877
    LEFTARG = anyelement,
2878
    RIGHTARG = anyelement
2879
);
2880

    
2881

    
2882
--
2883
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2884
--
2885

    
2886
CREATE OPERATOR ||% (
2887
    PROCEDURE = concat_esc,
2888
    LEFTARG = text,
2889
    RIGHTARG = text
2890
);
2891

    
2892

    
2893
--
2894
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2895
--
2896

    
2897
COMMENT ON OPERATOR ||% (text, text) IS '
2898
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
2899
';
2900

    
2901

    
2902
--
2903
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2904
--
2905

    
2906
CREATE TABLE map (
2907
    "from" text NOT NULL,
2908
    "to" text,
2909
    filter text,
2910
    notes text
2911
);
2912

    
2913

    
2914
--
2915
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2916
--
2917

    
2918

    
2919

    
2920
--
2921
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2922
--
2923

    
2924

    
2925

    
2926
--
2927
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2928
--
2929

    
2930
ALTER TABLE ONLY map
2931
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2932

    
2933

    
2934
--
2935
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2936
--
2937

    
2938
ALTER TABLE ONLY map
2939
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2940

    
2941

    
2942
--
2943
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2944
--
2945

    
2946
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2947

    
2948

    
2949
--
2950
-- PostgreSQL database dump complete
2951
--
2952

    
(19-19/29)