Project

General

Profile

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

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

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

    
15
CREATE SCHEMA util;
16

    
17

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

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

    
24

    
25
SET search_path = util, pg_catalog;
26

    
27
--
28
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
29
--
30

    
31
CREATE TYPE col_cast AS (
32
	col_name text,
33
	type regtype
34
);
35

    
36

    
37
--
38
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
39
--
40

    
41
CREATE TYPE col_ref AS (
42
	table_ regclass,
43
	name text
44
);
45

    
46

    
47
--
48
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
49
--
50

    
51
CREATE TYPE compass_dir AS ENUM (
52
    'N',
53
    'E',
54
    'S',
55
    'W'
56
);
57

    
58

    
59
--
60
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
61
--
62

    
63
CREATE TYPE datatype AS ENUM (
64
    'str',
65
    'float'
66
);
67

    
68

    
69
--
70
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
71
--
72

    
73
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
74
    LANGUAGE sql IMMUTABLE
75
    AS $_$
76
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
77
$_$;
78

    
79

    
80
--
81
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
82
--
83

    
84
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
85
    LANGUAGE sql IMMUTABLE
86
    AS $_$
87
SELECT bool_and(value)
88
FROM
89
(VALUES
90
      ($1)
91
    , ($2)
92
    , ($3)
93
    , ($4)
94
    , ($5)
95
)
96
AS v (value)
97
$_$;
98

    
99

    
100
--
101
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
102
--
103

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

    
106

    
107
--
108
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
109
--
110

    
111
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
112
    LANGUAGE sql IMMUTABLE
113
    AS $_$
114
SELECT avg(value)
115
FROM
116
(VALUES
117
      ($1)
118
    , ($2)
119
    , ($3)
120
    , ($4)
121
    , ($5)
122
)
123
AS v (value)
124
$_$;
125

    
126

    
127
--
128
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
129
--
130

    
131
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
132
    LANGUAGE sql IMMUTABLE STRICT
133
    AS $_$
134
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)
135
FROM 
136
(
137
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
138
    UNION ALL
139
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
140
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
141
)
142
matches (g)
143
$_$;
144

    
145

    
146
--
147
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
148
--
149

    
150
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
151
    LANGUAGE sql IMMUTABLE
152
    AS $_$
153
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
154
FROM
155
(VALUES
156
      ($1)
157
    , ($2/60)
158
    , ($3/60/60)
159
)
160
AS v (value)
161
$_$;
162

    
163

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

    
168
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
169
    LANGUAGE sql IMMUTABLE
170
    AS $_$
171
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
172
$_$;
173

    
174

    
175
--
176
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
177
--
178

    
179
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
180
    LANGUAGE sql IMMUTABLE
181
    AS $_$
182
SELECT $1 = $2
183
$_$;
184

    
185

    
186
--
187
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
188
--
189

    
190
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
191
    LANGUAGE sql IMMUTABLE
192
    AS $_$
193
-- Fix dates after threshold date
194
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
195
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
196
$_$;
197

    
198

    
199
--
200
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
201
--
202

    
203
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
204
    LANGUAGE sql IMMUTABLE
205
    AS $_$
206
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
207
$_$;
208

    
209

    
210
--
211
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
212
--
213

    
214
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217
SELECT util._if($1 != '', $2, $3)
218
$_$;
219

    
220

    
221
--
222
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
223
--
224

    
225
CREATE FUNCTION _join("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
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
229
$_$;
230

    
231

    
232
--
233
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
234
--
235

    
236
CREATE FUNCTION _join_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
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
240
$_$;
241

    
242

    
243
--
244
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
245
--
246

    
247
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
248
    LANGUAGE sql IMMUTABLE
249
    AS $_$
250
SELECT coalesce($1 || ': ', '') || $2
251
$_$;
252

    
253

    
254
--
255
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
256
--
257

    
258
CREATE FUNCTION _lowercase(value text) RETURNS text
259
    LANGUAGE sql IMMUTABLE STRICT
260
    AS $_$
261
SELECT lower($1)
262
$_$;
263

    
264

    
265
--
266
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
267
--
268

    
269
CREATE FUNCTION _map(map hstore, value text) RETURNS text
270
    LANGUAGE plpgsql IMMUTABLE STRICT
271
    AS $$
272
DECLARE
273
    match text := map -> value;
274
BEGIN
275
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
276
        match := map -> '*'; -- use default entry
277
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
278
        END IF;
279
    END IF;
280
    
281
    -- Interpret result
282
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
283
    ELSIF match = '*' THEN RETURN value;
284
    ELSE RETURN match;
285
    END IF;
286
END;
287
$$;
288

    
289

    
290
--
291
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
292
--
293

    
294
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
295
    LANGUAGE sql IMMUTABLE
296
    AS $_$
297
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
298
$_$;
299

    
300

    
301
--
302
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
303
--
304

    
305
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
306
    LANGUAGE sql IMMUTABLE
307
    AS $_$
308
SELECT util.join_strs(value, '; ')
309
FROM
310
(
311
    SELECT *
312
    FROM
313
    (
314
        SELECT
315
        DISTINCT ON (value)
316
        *
317
        FROM
318
        (VALUES
319
              (1, $1)
320
            , (2, $2)
321
            , (3, $3)
322
            , (4, $4)
323
            , (5, $5)
324
            , (6, $6)
325
            , (7, $7)
326
            , (8, $8)
327
            , (9, $9)
328
            , (10, $10)
329
        )
330
        AS v (sort_order, value)
331
        WHERE value IS NOT NULL
332
    )
333
    AS v
334
    ORDER BY sort_order
335
)
336
AS v
337
$_$;
338

    
339

    
340
--
341
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
342
--
343

    
344
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
345
    LANGUAGE sql IMMUTABLE
346
    AS $_$
347
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
348
$_$;
349

    
350

    
351
--
352
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
353
--
354

    
355
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
356
    LANGUAGE sql IMMUTABLE
357
    AS $_$
358
SELECT util.join_strs(value, ' ')
359
FROM
360
(
361
    SELECT *
362
    FROM
363
    (
364
        SELECT
365
        DISTINCT ON (value)
366
        *
367
        FROM
368
        (VALUES
369
              (1, $1)
370
            , (2, $2)
371
            , (3, $3)
372
            , (4, $4)
373
            , (5, $5)
374
            , (6, $6)
375
            , (7, $7)
376
            , (8, $8)
377
            , (9, $9)
378
            , (10, $10)
379
        )
380
        AS v (sort_order, value)
381
        WHERE value IS NOT NULL
382
    )
383
    AS v
384
    ORDER BY sort_order
385
)
386
AS v
387
$_$;
388

    
389

    
390
--
391
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
392
--
393

    
394
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
395
    LANGUAGE sql IMMUTABLE
396
    AS $_$
397
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
398
$_$;
399

    
400

    
401
--
402
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
403
--
404

    
405
CREATE FUNCTION _not(value boolean) RETURNS boolean
406
    LANGUAGE sql IMMUTABLE STRICT
407
    AS $_$
408
SELECT NOT $1
409
$_$;
410

    
411

    
412
--
413
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
CREATE FUNCTION _now() RETURNS timestamp with time zone
417
    LANGUAGE sql STABLE
418
    AS $$
419
SELECT now()
420
$$;
421

    
422

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

    
427
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
428
    LANGUAGE plpgsql IMMUTABLE
429
    AS $$
430
DECLARE
431
    type util.datatype NOT NULL := type; -- add NOT NULL
432
BEGIN
433
    IF type = 'str' THEN RETURN nullif(value::text, "null");
434
    -- Invalid value is ignored, but invalid null value generates error
435
    ELSIF type = 'float' THEN
436
        DECLARE
437
            -- Outside the try block so that invalid null value generates error
438
            "null" double precision := "null"::double precision;
439
        BEGIN
440
            RETURN nullif(value::double precision, "null");
441
        EXCEPTION
442
            WHEN data_exception THEN RETURN value; -- ignore invalid value
443
        END;
444
    END IF;
445
END;
446
$$;
447

    
448

    
449
--
450
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
451
--
452

    
453
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
454
    LANGUAGE sql IMMUTABLE
455
    AS $_$
456
SELECT util."_nullIf"($1, $2, $3::util.datatype)
457
$_$;
458

    
459

    
460
--
461
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
462
--
463

    
464
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
465
    LANGUAGE sql IMMUTABLE
466
    AS $_$
467
SELECT bool_or(value)
468
FROM
469
(VALUES
470
      ($1)
471
    , ($2)
472
    , ($3)
473
    , ($4)
474
    , ($5)
475
)
476
AS v (value)
477
$_$;
478

    
479

    
480
--
481
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
482
--
483

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

    
486

    
487
--
488
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
489
--
490

    
491
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
492
    LANGUAGE sql IMMUTABLE
493
    AS $_$
494
SELECT $2 - $1
495
$_$;
496

    
497

    
498
--
499
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
500
--
501

    
502
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
503
    LANGUAGE sql IMMUTABLE STRICT
504
    AS $_$
505
SELECT regexp_split_to_table($1, $2)
506
$_$;
507

    
508

    
509
--
510
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
511
--
512

    
513
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
514
    LANGUAGE sql IMMUTABLE
515
    AS $_$
516
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
517
$_$;
518

    
519

    
520
--
521
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
522
--
523

    
524
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
525
    LANGUAGE plpgsql IMMUTABLE
526
    AS $$
527
DECLARE
528
	value_cmp         state%TYPE = ARRAY[value];
529
	state             state%TYPE = COALESCE(state, value_cmp);
530
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
531
BEGIN
532
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
533
END;
534
$$;
535

    
536

    
537
--
538
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
539
--
540

    
541
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
542
    LANGUAGE sql IMMUTABLE
543
    AS $_$
544
SELECT pg_catalog.array_fill($1, ARRAY[$2])
545
$_$;
546

    
547

    
548
--
549
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
550
--
551

    
552
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
553
    LANGUAGE sql IMMUTABLE STRICT
554
    AS $_$
555
SELECT array_length($1, 1)
556
$_$;
557

    
558

    
559
--
560
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
561
--
562

    
563
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
564
    LANGUAGE sql IMMUTABLE STRICT
565
    AS $_$
566
SELECT COALESCE(pg_catalog.array_length($1, $2), 0)
567
$_$;
568

    
569

    
570
--
571
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
572
--
573

    
574
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS 'returns 0 instead of NULL for empty arrays';
575

    
576

    
577
--
578
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
579
--
580

    
581
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
582
    LANGUAGE sql STABLE STRICT
583
    AS $_$
584
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
585
$_$;
586

    
587

    
588
--
589
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
590
--
591

    
592
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
593
    LANGUAGE plpgsql STRICT
594
    AS $_$
595
BEGIN
596
    -- not yet clustered (ARRAY[] compares NULLs literally)
597
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
598
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
599
    END IF;
600
END;
601
$_$;
602

    
603

    
604
--
605
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
606
--
607

    
608
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
609

    
610

    
611
--
612
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
613
--
614

    
615
CREATE FUNCTION col_comment(col col_ref) RETURNS text
616
    LANGUAGE plpgsql STABLE STRICT
617
    AS $$
618
DECLARE
619
	comment text;
620
BEGIN
621
	SELECT description
622
	FROM pg_attribute
623
	LEFT JOIN pg_description ON objoid = attrelid
624
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
625
	WHERE attrelid = col.table_ AND attname = col.name
626
	INTO STRICT comment
627
	;
628
	RETURN comment;
629
EXCEPTION
630
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
631
END;
632
$$;
633

    
634

    
635
--
636
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
637
--
638

    
639
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
640
    LANGUAGE plpgsql STABLE STRICT
641
    AS $$
642
DECLARE
643
	default_sql text;
644
BEGIN
645
	SELECT adsrc
646
	FROM pg_attribute
647
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
648
	WHERE attrelid = col.table_ AND attname = col.name
649
	INTO STRICT default_sql
650
	;
651
	RETURN default_sql;
652
EXCEPTION
653
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
654
END;
655
$$;
656

    
657

    
658
--
659
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
660
--
661

    
662
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
663
    LANGUAGE sql STABLE
664
    AS $_$
665
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
666
$_$;
667

    
668

    
669
--
670
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
671
--
672

    
673
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
674

    
675

    
676
--
677
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
678
--
679

    
680
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
681
    LANGUAGE plpgsql STRICT
682
    AS $$
683
BEGIN
684
    PERFORM util.col_type(col);
685
    RETURN true;
686
EXCEPTION
687
    WHEN undefined_column THEN RETURN false;
688
END;
689
$$;
690

    
691

    
692
--
693
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
694
--
695

    
696
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
697
    LANGUAGE plpgsql STABLE STRICT
698
    AS $$
699
DECLARE
700
    prefix text := util.name(type)||'.';
701
BEGIN
702
    RETURN QUERY
703
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
704
        FROM util.col_names(type) f (name_);
705
END;
706
$$;
707

    
708

    
709
--
710
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
711
--
712

    
713
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
714
    LANGUAGE plpgsql STABLE STRICT
715
    AS $_$
716
BEGIN
717
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
718
END;
719
$_$;
720

    
721

    
722
--
723
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
724
--
725

    
726
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
727
    LANGUAGE sql STABLE STRICT
728
    AS $_$
729
SELECT attname::text
730
FROM pg_attribute
731
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
732
ORDER BY attnum
733
$_$;
734

    
735

    
736
--
737
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
738
--
739

    
740
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
741
    LANGUAGE plpgsql STABLE STRICT
742
    AS $$
743
DECLARE
744
    type regtype;
745
BEGIN
746
    SELECT atttypid FROM pg_attribute
747
    WHERE attrelid = col.table_ AND attname = col.name
748
    INTO STRICT type
749
    ;
750
    RETURN type;
751
EXCEPTION
752
    WHEN no_data_found THEN
753
        RAISE undefined_column USING MESSAGE =
754
            concat('undefined column: ', col.name);
755
END;
756
$$;
757

    
758

    
759
--
760
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
761
--
762

    
763
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
764
    LANGUAGE sql IMMUTABLE STRICT
765
    AS $_$
766
SELECT position($1 in $2) > 0 /*1-based offset*/
767
$_$;
768

    
769

    
770
--
771
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
772
--
773

    
774
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
775
    LANGUAGE plpgsql STRICT
776
    AS $$
777
BEGIN
778
    PERFORM util.eval(sql);
779
EXCEPTION
780
    WHEN duplicate_table  THEN NULL;
781
    WHEN duplicate_object THEN NULL; -- e.g. constraint
782
    WHEN duplicate_column THEN NULL;
783
    WHEN invalid_table_definition THEN
784
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
785
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
786
        END IF;
787
END;
788
$$;
789

    
790

    
791
--
792
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
793
--
794

    
795
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
796

    
797

    
798
--
799
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
800
--
801

    
802
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
803
    LANGUAGE sql STRICT
804
    AS $_$
805
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
806
$_$;
807

    
808

    
809
--
810
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
811
--
812

    
813
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
814

    
815

    
816
--
817
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
818
--
819

    
820
CREATE FUNCTION drop_table(table_ text) RETURNS void
821
    LANGUAGE sql STRICT
822
    AS $_$
823
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
824
$_$;
825

    
826

    
827
--
828
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
829
--
830

    
831
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
832

    
833

    
834
--
835
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
836
--
837

    
838
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
839
    LANGUAGE sql IMMUTABLE STRICT
840
    AS $_$
841
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
842
$_$;
843

    
844

    
845
--
846
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
847
--
848

    
849
CREATE FUNCTION eval(sql text) RETURNS void
850
    LANGUAGE plpgsql STRICT
851
    AS $$
852
BEGIN
853
    RAISE NOTICE '%', sql;
854
    EXECUTE sql;
855
END;
856
$$;
857

    
858

    
859
--
860
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
861
--
862

    
863
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
864
    LANGUAGE plpgsql
865
    AS $$
866
DECLARE
867
	ret_val ret_type_null%TYPE;
868
BEGIN
869
	RAISE NOTICE '%', sql;
870
	EXECUTE sql INTO STRICT ret_val;
871
	RETURN ret_val;
872
END;
873
$$;
874

    
875

    
876
--
877
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
878
--
879

    
880
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
881

    
882

    
883
--
884
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
885
--
886

    
887
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
888
    LANGUAGE sql
889
    AS $_$
890
SELECT util.eval2val($$SELECT $$||$1, $2)
891
$_$;
892

    
893

    
894
--
895
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
896
--
897

    
898
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
899

    
900

    
901
--
902
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
903
--
904

    
905
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
906
    LANGUAGE sql
907
    AS $_$
908
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
909
$_$;
910

    
911

    
912
--
913
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
914
--
915

    
916
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
917
ret_type_null: NULL::ret_type';
918

    
919

    
920
--
921
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
922
--
923

    
924
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
925
    LANGUAGE sql STABLE STRICT
926
    AS $_$
927
SELECT col_name
928
FROM unnest($2) s (col_name)
929
WHERE util.col_exists(($1, col_name))
930
$_$;
931

    
932

    
933
--
934
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
935
--
936

    
937
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
938
    LANGUAGE plpgsql STRICT
939
    AS $_$
940
DECLARE
941
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
942
$$||query;
943
BEGIN
944
	EXECUTE mk_view;
945
EXCEPTION
946
WHEN invalid_table_definition THEN
947
	IF SQLERRM = 'cannot drop columns from view'
948
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
949
	THEN
950
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
951
		EXECUTE mk_view;
952
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
953
	END IF;
954
END;
955
$_$;
956

    
957

    
958
--
959
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
960
--
961

    
962
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
963

    
964

    
965
--
966
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
967
--
968

    
969
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
970
    LANGUAGE sql IMMUTABLE STRICT
971
    AS $_$
972
SELECT substring($2 for length($1)) = $1
973
$_$;
974

    
975

    
976
--
977
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
978
--
979

    
980
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
981
    LANGUAGE sql STABLE STRICT
982
    AS $_$
983
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
984
$_$;
985

    
986

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

    
991
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
992
    LANGUAGE sql IMMUTABLE STRICT
993
    AS $_$
994
SELECT $1 || $3 || $2
995
$_$;
996

    
997

    
998
--
999
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1000
--
1001

    
1002
CREATE FUNCTION map_filter_insert() RETURNS trigger
1003
    LANGUAGE plpgsql
1004
    AS $$
1005
BEGIN
1006
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1007
	RETURN new;
1008
END;
1009
$$;
1010

    
1011

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

    
1016
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1017
    LANGUAGE plpgsql STABLE STRICT
1018
    AS $_$
1019
DECLARE
1020
    value text;
1021
BEGIN
1022
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1023
        INTO value USING key;
1024
    RETURN value;
1025
END;
1026
$_$;
1027

    
1028

    
1029
--
1030
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1031
--
1032

    
1033
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1034
    LANGUAGE plpgsql STABLE STRICT
1035
    AS $_$
1036
BEGIN
1037
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1038
END;
1039
$_$;
1040

    
1041

    
1042
--
1043
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1044
--
1045

    
1046
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1047
    LANGUAGE sql STRICT
1048
    AS $_$
1049
SELECT util.create_if_not_exists($$
1050
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1051
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1052
||quote_literal($2)||$$;
1053
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1054
$$)
1055
$_$;
1056

    
1057

    
1058
--
1059
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1060
--
1061

    
1062
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1063

    
1064

    
1065
--
1066
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1067
--
1068

    
1069
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1070
    LANGUAGE plpgsql STRICT
1071
    AS $_$
1072
DECLARE
1073
    type regtype = util.typeof(expr, col.table_::text::regtype);
1074
    col_name_sql text = quote_ident(col.name);
1075
BEGIN
1076
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1077
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1078
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1079
$$||expr||$$;
1080
$$);
1081
END;
1082
$_$;
1083

    
1084

    
1085
--
1086
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1087
--
1088

    
1089
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS 'idempotent';
1090

    
1091

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

    
1096
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1097
    LANGUAGE sql STRICT
1098
    AS $_$
1099
SELECT util.create_if_not_exists($$
1100
CREATE TABLE $$||$1||$$
1101
(
1102
    LIKE util.map INCLUDING ALL
1103
);
1104

    
1105
CREATE TRIGGER map_filter_insert
1106
  BEFORE INSERT
1107
  ON $$||$1||$$
1108
  FOR EACH ROW
1109
  EXECUTE PROCEDURE util.map_filter_insert();
1110
$$)
1111
$_$;
1112

    
1113

    
1114
--
1115
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117

    
1118
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1119
    LANGUAGE sql STRICT
1120
    AS $_$
1121
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1122
$_$;
1123

    
1124

    
1125
--
1126
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1127
--
1128

    
1129
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1130

    
1131

    
1132
--
1133
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1134
--
1135

    
1136
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1137
    LANGUAGE plpgsql STRICT
1138
    AS $_$
1139
BEGIN
1140
	EXECUTE $$
1141
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1142
  RETURNS SETOF $$||view_||$$ AS
1143
$BODY1$
1144
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1145
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
1146
$BODY1$
1147
  LANGUAGE sql STABLE
1148
  COST 100
1149
  ROWS 1000
1150
$$;
1151
-- Also create subset function which turns off enable_sort
1152
	EXECUTE $$
1153
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1154
  RETURNS SETOF $$||view_||$$
1155
  SET enable_sort TO 'off'
1156
  AS
1157
$BODY1$
1158
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1159
$BODY1$
1160
  LANGUAGE sql STABLE
1161
  COST 100
1162
  ROWS 1000
1163
;
1164
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1165
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1166
If you want to run EXPLAIN and get expanded output, use the regular subset
1167
function instead. (When a config param is set on a function, EXPLAIN produces
1168
just a function scan.)
1169
';
1170
$$;
1171
END;
1172
$_$;
1173

    
1174

    
1175
--
1176
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1177
--
1178

    
1179
CREATE FUNCTION name(type regtype) RETURNS text
1180
    LANGUAGE sql STABLE STRICT
1181
    AS $_$
1182
SELECT typname::text FROM pg_type WHERE oid = $1
1183
$_$;
1184

    
1185

    
1186
--
1187
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1188
--
1189

    
1190
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1191
    LANGUAGE sql IMMUTABLE
1192
    AS $_$
1193
SELECT $1 IS NOT NULL AND array_length($1, 1)/*ARRAY[]->NULL*/ IS NOT NULL
1194
$_$;
1195

    
1196

    
1197
--
1198
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1199
--
1200

    
1201
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1202
    LANGUAGE sql IMMUTABLE
1203
    AS $_$
1204
SELECT $1 IS NOT NULL
1205
$_$;
1206

    
1207

    
1208
--
1209
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1210
--
1211

    
1212
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1213
    LANGUAGE plpgsql IMMUTABLE STRICT
1214
    AS $$
1215
BEGIN
1216
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1217
END;
1218
$$;
1219

    
1220

    
1221
--
1222
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1223
--
1224

    
1225
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1226
    LANGUAGE sql STRICT
1227
    AS $_$
1228
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1229
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1230
FROM util.col_names($1::text::regtype) f (name)
1231
$_$;
1232

    
1233

    
1234
--
1235
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1236
--
1237

    
1238
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1239

    
1240

    
1241
--
1242
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1243
--
1244

    
1245
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1246
    LANGUAGE sql STRICT
1247
    AS $_$
1248
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1249
SELECT util.set_col_names($1, $2);
1250
$_$;
1251

    
1252

    
1253
--
1254
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1255
--
1256

    
1257
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS 'idempotent.
1258
alters the names table, so it will need to be repopulated after running this function.';
1259

    
1260

    
1261
--
1262
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1263
--
1264

    
1265
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1266
    LANGUAGE sql STRICT
1267
    AS $_$
1268
SELECT util.drop_table($1);
1269
SELECT util.mk_map_table($1);
1270
$_$;
1271

    
1272

    
1273
--
1274
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1275
--
1276

    
1277
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1278
    LANGUAGE sql STRICT
1279
    AS $_$
1280
SELECT util.eval(
1281
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1282
$_$;
1283

    
1284

    
1285
--
1286
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1287
--
1288

    
1289
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1290
    LANGUAGE plpgsql STRICT
1291
    AS $_$
1292
DECLARE
1293
    old text[] = ARRAY(SELECT util.col_names(table_));
1294
    new text[] = ARRAY(SELECT util.map_values(names));
1295
BEGIN
1296
    old = old[1:array_length(new, 1)]; -- truncate to same length
1297
    PERFORM util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1298
        ||quote_ident(key)||$$ TO $$||quote_ident(value))
1299
    FROM each(hstore(old, new))
1300
    WHERE value != key -- not same name
1301
    ;
1302
END;
1303
$_$;
1304

    
1305

    
1306
--
1307
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1308
--
1309

    
1310
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1311

    
1312

    
1313
--
1314
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1315
--
1316

    
1317
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1318
    LANGUAGE plpgsql STRICT
1319
    AS $_$
1320
DECLARE
1321
	row_ util.map;
1322
BEGIN
1323
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1324
	LOOP
1325
		PERFORM util.mk_const_col((table_, row_."to"),
1326
			substring(row_."from" from 2));
1327
	END LOOP;
1328
	
1329
	PERFORM util.set_col_names(table_, names);
1330
END;
1331
$_$;
1332

    
1333

    
1334
--
1335
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1336
--
1337

    
1338
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS 'idempotent.
1339
the metadata mappings must be *last* in the names table.';
1340

    
1341

    
1342
--
1343
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1344
--
1345

    
1346
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1347
    LANGUAGE plpgsql STRICT
1348
    AS $_$
1349
DECLARE
1350
    sql text = $$ALTER TABLE $$||table_||$$
1351
$$||NULLIF(array_to_string(ARRAY(
1352
    SELECT
1353
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1354
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1355
    FROM
1356
    (
1357
        SELECT
1358
          quote_ident(col_name) AS col_name_sql
1359
        , util.col_type((table_, col_name)) AS curr_type
1360
        , type AS target_type
1361
        FROM unnest(col_casts)
1362
    ) s
1363
    WHERE curr_type != target_type
1364
), '
1365
, '), '');
1366
BEGIN
1367
    RAISE NOTICE '%', sql;
1368
    EXECUTE COALESCE(sql, '');
1369
END;
1370
$_$;
1371

    
1372

    
1373
--
1374
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1375
--
1376

    
1377
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS 'idempotent';
1378

    
1379

    
1380
--
1381
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1382
--
1383

    
1384
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1385
    LANGUAGE plpgsql STABLE STRICT
1386
    AS $_$
1387
DECLARE
1388
    hstore hstore;
1389
BEGIN
1390
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1391
        table_||$$))$$ INTO STRICT hstore;
1392
    RETURN hstore;
1393
END;
1394
$_$;
1395

    
1396

    
1397
--
1398
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1399
--
1400

    
1401
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1402
    LANGUAGE sql STABLE STRICT
1403
    AS $_$
1404
SELECT COUNT(*) > 0 FROM pg_constraint
1405
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1406
$_$;
1407

    
1408

    
1409
--
1410
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1411
--
1412

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

    
1415

    
1416
--
1417
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1418
--
1419

    
1420
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1421
    LANGUAGE sql STRICT
1422
    AS $_$
1423
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1424
||quote_ident($2)||$$ CHECK (true)$$)
1425
$_$;
1426

    
1427

    
1428
--
1429
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1430
--
1431

    
1432
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS 'stores a status flag by the presence of a table constraint.
1433
idempotent.';
1434

    
1435

    
1436
--
1437
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1438
--
1439

    
1440
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1441
    LANGUAGE sql STABLE STRICT
1442
    AS $_$
1443
SELECT util.table_flag__get($1, 'nulls_mapped')
1444
$_$;
1445

    
1446

    
1447
--
1448
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1449
--
1450

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

    
1453

    
1454
--
1455
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1456
--
1457

    
1458
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1459
    LANGUAGE sql STRICT
1460
    AS $_$
1461
SELECT util.table_flag__set($1, 'nulls_mapped')
1462
$_$;
1463

    
1464

    
1465
--
1466
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1467
--
1468

    
1469
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS 'sets that a table''s NULL-equivalent strings have been replaced with NULL.
1470
idempotent.';
1471

    
1472

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

    
1477
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1478
    LANGUAGE sql STABLE STRICT
1479
    AS $_$
1480
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1481
$_$;
1482

    
1483

    
1484
--
1485
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1486
--
1487

    
1488
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1489
    LANGUAGE plpgsql STRICT
1490
    AS $_$
1491
DECLARE
1492
    row record;
1493
BEGIN
1494
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1495
    LOOP
1496
        IF row.global_name != row.name THEN
1497
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1498
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1499
        END IF;
1500
    END LOOP;
1501
END;
1502
$_$;
1503

    
1504

    
1505
--
1506
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1507
--
1508

    
1509
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1510

    
1511

    
1512
--
1513
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1514
--
1515

    
1516
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1517
    LANGUAGE plpgsql STRICT
1518
    AS $_$
1519
BEGIN
1520
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1521
END;
1522
$_$;
1523

    
1524

    
1525
--
1526
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1527
--
1528

    
1529
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1530

    
1531

    
1532
--
1533
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1534
--
1535

    
1536
CREATE FUNCTION try_create(sql text) RETURNS void
1537
    LANGUAGE plpgsql STRICT
1538
    AS $$
1539
BEGIN
1540
    PERFORM util.eval(sql);
1541
EXCEPTION
1542
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1543
    WHEN undefined_column THEN NULL;
1544
    WHEN duplicate_column THEN NULL;
1545
END;
1546
$$;
1547

    
1548

    
1549
--
1550
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1551
--
1552

    
1553
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1554

    
1555

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

    
1560
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1561
    LANGUAGE sql STRICT
1562
    AS $_$
1563
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1564
$_$;
1565

    
1566

    
1567
--
1568
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1569
--
1570

    
1571
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1572

    
1573

    
1574
--
1575
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1576
--
1577

    
1578
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1579
    LANGUAGE sql IMMUTABLE
1580
    AS $_$
1581
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1582
$_$;
1583

    
1584

    
1585
--
1586
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
1587
--
1588

    
1589
COMMENT ON FUNCTION type_qual(value anyelement) IS 'a type''s NOT NULL qualifier';
1590

    
1591

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

    
1596
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1597
    LANGUAGE sql STABLE STRICT
1598
    SET search_path TO pg_temp
1599
    AS $_$
1600
SELECT $1::text
1601
$_$;
1602

    
1603

    
1604
--
1605
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
1606
--
1607

    
1608
COMMENT ON FUNCTION type_qual_name(type regtype) IS 'a type''s schema-qualified name';
1609

    
1610

    
1611
--
1612
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
1613
--
1614

    
1615
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
1616
    LANGUAGE plpgsql STABLE
1617
    AS $_$
1618
DECLARE
1619
    type regtype;
1620
BEGIN
1621
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
1622
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
1623
    RETURN type;
1624
END;
1625
$_$;
1626

    
1627

    
1628
--
1629
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1630
--
1631

    
1632
CREATE AGGREGATE all_same(anyelement) (
1633
    SFUNC = all_same_transform,
1634
    STYPE = anyarray,
1635
    FINALFUNC = all_same_final
1636
);
1637

    
1638

    
1639
--
1640
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1641
--
1642

    
1643
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1644

    
1645

    
1646
--
1647
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1648
--
1649

    
1650
CREATE AGGREGATE join_strs(text, text) (
1651
    SFUNC = join_strs_transform,
1652
    STYPE = text
1653
);
1654

    
1655

    
1656
--
1657
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1658
--
1659

    
1660
CREATE OPERATOR -> (
1661
    PROCEDURE = map_get,
1662
    LEFTARG = regclass,
1663
    RIGHTARG = text
1664
);
1665

    
1666

    
1667
SET default_tablespace = '';
1668

    
1669
SET default_with_oids = false;
1670

    
1671
--
1672
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1673
--
1674

    
1675
CREATE TABLE map (
1676
    "from" text NOT NULL,
1677
    "to" text,
1678
    filter text,
1679
    notes text
1680
);
1681

    
1682

    
1683
--
1684
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1685
--
1686

    
1687

    
1688

    
1689
--
1690
-- Name: map_pkey; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
1691
--
1692

    
1693
ALTER TABLE ONLY map
1694
    ADD CONSTRAINT map_pkey PRIMARY KEY ("from");
1695

    
1696

    
1697
--
1698
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1699
--
1700

    
1701
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1702

    
1703

    
1704
--
1705
-- PostgreSQL database dump complete
1706
--
1707

    
(17-17/27)