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: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
256
--
257

    
258
CREATE FUNCTION _map(map hstore, value text) RETURNS text
259
    LANGUAGE plpgsql IMMUTABLE STRICT
260
    AS $$
261
DECLARE
262
    match text := map -> value;
263
BEGIN
264
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
265
        match := map -> '*'; -- use default entry
266
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
267
        END IF;
268
    END IF;
269
    
270
    -- Interpret result
271
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
272
    ELSIF match = '*' THEN RETURN value;
273
    ELSE RETURN match;
274
    END IF;
275
END;
276
$$;
277

    
278

    
279
--
280
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
281
--
282

    
283
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
284
    LANGUAGE sql IMMUTABLE
285
    AS $_$
286
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
287
$_$;
288

    
289

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

    
294
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
295
    LANGUAGE sql IMMUTABLE
296
    AS $_$
297
SELECT util.join_strs(value, '; ')
298
FROM
299
(
300
    SELECT *
301
    FROM
302
    (
303
        SELECT
304
        DISTINCT ON (value)
305
        *
306
        FROM
307
        (VALUES
308
              (1, $1)
309
            , (2, $2)
310
            , (3, $3)
311
            , (4, $4)
312
            , (5, $5)
313
            , (6, $6)
314
            , (7, $7)
315
            , (8, $8)
316
            , (9, $9)
317
            , (10, $10)
318
        )
319
        AS v (sort_order, value)
320
        WHERE value IS NOT NULL
321
    )
322
    AS v
323
    ORDER BY sort_order
324
)
325
AS v
326
$_$;
327

    
328

    
329
--
330
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
331
--
332

    
333
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
334
    LANGUAGE sql IMMUTABLE
335
    AS $_$
336
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
337
$_$;
338

    
339

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

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

    
378

    
379
--
380
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
381
--
382

    
383
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
384
    LANGUAGE sql IMMUTABLE
385
    AS $_$
386
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
387
$_$;
388

    
389

    
390
--
391
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
392
--
393

    
394
CREATE FUNCTION _not(value boolean) RETURNS boolean
395
    LANGUAGE sql IMMUTABLE STRICT
396
    AS $_$
397
SELECT NOT $1
398
$_$;
399

    
400

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

    
405
CREATE FUNCTION _now() RETURNS timestamp with time zone
406
    LANGUAGE sql STABLE
407
    AS $$
408
SELECT now()
409
$$;
410

    
411

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

    
416
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
417
    LANGUAGE plpgsql IMMUTABLE
418
    AS $$
419
DECLARE
420
    type util.datatype NOT NULL := type; -- add NOT NULL
421
BEGIN
422
    IF type = 'str' THEN RETURN nullif(value::text, "null");
423
    -- Invalid value is ignored, but invalid null value generates error
424
    ELSIF type = 'float' THEN
425
        DECLARE
426
            -- Outside the try block so that invalid null value generates error
427
            "null" double precision := "null"::double precision;
428
        BEGIN
429
            RETURN nullif(value::double precision, "null");
430
        EXCEPTION
431
            WHEN data_exception THEN RETURN value; -- ignore invalid value
432
        END;
433
    END IF;
434
END;
435
$$;
436

    
437

    
438
--
439
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
440
--
441

    
442
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
443
    LANGUAGE sql IMMUTABLE
444
    AS $_$
445
SELECT util."_nullIf"($1, $2, $3::util.datatype)
446
$_$;
447

    
448

    
449
--
450
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
451
--
452

    
453
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
454
    LANGUAGE sql IMMUTABLE
455
    AS $_$
456
SELECT bool_or(value)
457
FROM
458
(VALUES
459
      ($1)
460
    , ($2)
461
    , ($3)
462
    , ($4)
463
    , ($5)
464
)
465
AS v (value)
466
$_$;
467

    
468

    
469
--
470
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
471
--
472

    
473
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.';
474

    
475

    
476
--
477
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
478
--
479

    
480
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
481
    LANGUAGE sql IMMUTABLE
482
    AS $_$
483
SELECT $2 - $1
484
$_$;
485

    
486

    
487
--
488
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
489
--
490

    
491
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
492
    LANGUAGE sql IMMUTABLE STRICT
493
    AS $_$
494
SELECT regexp_split_to_table($1, $2)
495
$_$;
496

    
497

    
498
--
499
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
500
--
501

    
502
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
503
    LANGUAGE sql STABLE STRICT
504
    AS $_$
505
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
506
$_$;
507

    
508

    
509
--
510
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
511
--
512

    
513
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
514
    LANGUAGE plpgsql STRICT
515
    AS $_$
516
BEGIN
517
    -- not yet clustered (ARRAY[] compares NULLs literally)
518
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
519
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
520
    END IF;
521
END;
522
$_$;
523

    
524

    
525
--
526
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
527
--
528

    
529
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
530

    
531

    
532
--
533
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
534
--
535

    
536
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
537
    LANGUAGE plpgsql STRICT
538
    AS $$
539
BEGIN
540
    PERFORM util.col_type(col);
541
    RETURN true;
542
EXCEPTION
543
    WHEN undefined_column THEN RETURN false;
544
END;
545
$$;
546

    
547

    
548
--
549
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
550
--
551

    
552
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
553
    LANGUAGE plpgsql STABLE STRICT
554
    AS $$
555
DECLARE
556
    prefix text := util.name(type)||'.';
557
BEGIN
558
    RETURN QUERY
559
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
560
        FROM util.col_names(type) f (name_);
561
END;
562
$$;
563

    
564

    
565
--
566
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
567
--
568

    
569
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
570
    LANGUAGE plpgsql STABLE STRICT
571
    AS $_$
572
BEGIN
573
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
574
END;
575
$_$;
576

    
577

    
578
--
579
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
580
--
581

    
582
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
583
    LANGUAGE sql STABLE STRICT
584
    AS $_$
585
SELECT attname::text
586
FROM pg_attribute
587
WHERE attrelid = $1 AND attnum >= 1
588
ORDER BY attnum
589
$_$;
590

    
591

    
592
--
593
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
594
--
595

    
596
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
597
    LANGUAGE plpgsql STABLE STRICT
598
    AS $$
599
DECLARE
600
    type regtype;
601
BEGIN
602
    SELECT atttypid FROM pg_attribute
603
    WHERE attrelid = col.table_ AND attname = col.name
604
    INTO STRICT type
605
    ;
606
    RETURN type;
607
EXCEPTION
608
    WHEN no_data_found THEN
609
        RAISE undefined_column USING MESSAGE =
610
            concat('undefined column: ', col.name);
611
END;
612
$$;
613

    
614

    
615
--
616
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
617
--
618

    
619
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
620
    LANGUAGE sql IMMUTABLE STRICT
621
    AS $_$
622
SELECT position($1 in $2) > 0 /*1-based offset*/
623
$_$;
624

    
625

    
626
--
627
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
628
--
629

    
630
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
631
    LANGUAGE plpgsql STRICT
632
    AS $$
633
BEGIN
634
    EXECUTE sql;
635
EXCEPTION
636
    WHEN duplicate_table  THEN NULL;
637
    WHEN duplicate_column THEN NULL;
638
END;
639
$$;
640

    
641

    
642
--
643
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
644
--
645

    
646
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
647

    
648

    
649
--
650
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
651
--
652

    
653
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
654
    LANGUAGE sql IMMUTABLE STRICT
655
    AS $_$
656
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
657
$_$;
658

    
659

    
660
--
661
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
662
--
663

    
664
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
665
    LANGUAGE sql STABLE STRICT
666
    AS $_$
667
SELECT col_name
668
FROM unnest($2) s (col_name)
669
WHERE util.col_exists(($1, col_name))
670
$_$;
671

    
672

    
673
--
674
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
675
--
676

    
677
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
678
    LANGUAGE sql IMMUTABLE STRICT
679
    AS $_$
680
SELECT substring($2 for length($1)) = $1
681
$_$;
682

    
683

    
684
--
685
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
686
--
687

    
688
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
689
    LANGUAGE sql IMMUTABLE STRICT
690
    AS $_$
691
SELECT $1 || $3 || $2
692
$_$;
693

    
694

    
695
--
696
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
697
--
698

    
699
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
700
    LANGUAGE plpgsql STABLE STRICT
701
    AS $_$
702
DECLARE
703
    value text;
704
BEGIN
705
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
706
        INTO value USING key;
707
    RETURN value;
708
END;
709
$_$;
710

    
711

    
712
--
713
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
714
--
715

    
716
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
717
    LANGUAGE plpgsql STABLE STRICT
718
    AS $_$
719
BEGIN
720
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
721
END;
722
$_$;
723

    
724

    
725
--
726
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
727
--
728

    
729
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
730
    LANGUAGE sql STRICT
731
    AS $_$
732
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
733
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
734
||quote_literal($2))
735
$_$;
736

    
737

    
738
--
739
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
740
--
741

    
742
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
743

    
744

    
745
--
746
-- Name: mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
747
--
748

    
749
CREATE FUNCTION mk_derived_col(col col_ref, expr text) RETURNS void
750
    LANGUAGE plpgsql STRICT
751
    AS $_$
752
DECLARE
753
    type regtype = util.typeof(expr, col.table_::text::regtype);
754
    col_name_sql text = quote_ident(col.name);
755
BEGIN
756
    PERFORM util.create_if_not_exists($$
757
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;
758
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
759
$$||expr||$$;
760
$$);
761
END;
762
$_$;
763

    
764

    
765
--
766
-- Name: FUNCTION mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
767
--
768

    
769
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text) IS 'idempotent';
770

    
771

    
772
--
773
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
774
--
775

    
776
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
777
    LANGUAGE sql STRICT
778
    AS $_$
779
SELECT util.create_if_not_exists($$
780
CREATE TABLE $$||$1||$$
781
(
782
    LIKE util.map INCLUDING ALL
783
)
784
$$)
785
$_$;
786

    
787

    
788
--
789
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
790
--
791

    
792
CREATE FUNCTION name(type regtype) RETURNS text
793
    LANGUAGE sql STABLE STRICT
794
    AS $_$
795
SELECT typname::text FROM pg_type WHERE oid = $1
796
$_$;
797

    
798

    
799
--
800
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
801
--
802

    
803
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
804
    LANGUAGE sql STRICT
805
    AS $_$
806
SELECT util.rename_if_exists($$ALTER TABLE $$||$1||$$ RENAME $$
807
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
808
FROM util.col_names($1::text::regtype) f (name)
809
$_$;
810

    
811

    
812
--
813
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
814
--
815

    
816
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
817

    
818

    
819
--
820
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
821
--
822

    
823
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
824
    LANGUAGE sql STRICT
825
    AS $_$
826
SELECT util.mk_map_table($1);
827
SELECT util.truncate($1);
828
$_$;
829

    
830

    
831
--
832
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
833
--
834

    
835
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
836
    LANGUAGE plpgsql STRICT
837
    AS $_$
838
DECLARE
839
    old text[] = ARRAY(SELECT util.col_names(table_));
840
    new text[] = ARRAY(SELECT util.map_values(names));
841
BEGIN
842
    old = old[1:array_length(new, 1)]; -- truncate to same length
843
    PERFORM util.rename_if_exists($$ALTER TABLE $$||$1||$$ RENAME $$
844
        ||quote_ident(key)||$$ TO $$||quote_ident(value))
845
    FROM each(hstore(old, new));
846
END;
847
$_$;
848

    
849

    
850
--
851
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
852
--
853

    
854
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
855

    
856

    
857
--
858
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
859
--
860

    
861
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
862
    LANGUAGE plpgsql STRICT
863
    AS $_$
864
DECLARE
865
    sql text = $$ALTER TABLE $$||table_||$$
866
$$||NULLIF(array_to_string(ARRAY(
867
    SELECT
868
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
869
    ||$$ USING $$||col_name_sql||$$::$$||target_type
870
    FROM
871
    (
872
        SELECT
873
          quote_ident(col_name) AS col_name_sql
874
        , util.col_type((table_, col_name)) AS curr_type
875
        , type AS target_type
876
        FROM unnest(col_casts)
877
    ) s
878
    WHERE curr_type != target_type
879
), '
880
, '), '');
881
BEGIN
882
    RAISE NOTICE '%', sql;
883
    EXECUTE COALESCE(sql, '');
884
END;
885
$_$;
886

    
887

    
888
--
889
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
890
--
891

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

    
894

    
895
--
896
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
897
--
898

    
899
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
900
    LANGUAGE plpgsql STABLE STRICT
901
    AS $_$
902
DECLARE
903
    hstore hstore;
904
BEGIN
905
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
906
        table_||$$))$$ INTO STRICT hstore;
907
    RETURN hstore;
908
END;
909
$_$;
910

    
911

    
912
--
913
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
914
--
915

    
916
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
917
    LANGUAGE plpgsql STRICT
918
    AS $_$
919
DECLARE
920
    row record;
921
BEGIN
922
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
923
    LOOP
924
        IF row.global_name != row.name THEN
925
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
926
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
927
        END IF;
928
    END LOOP;
929
END;
930
$_$;
931

    
932

    
933
--
934
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
935
--
936

    
937
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
938

    
939

    
940
--
941
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
942
--
943

    
944
CREATE FUNCTION truncate(table_ regclass) RETURNS void
945
    LANGUAGE plpgsql STRICT
946
    AS $_$
947
BEGIN
948
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
949
END;
950
$_$;
951

    
952

    
953
--
954
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
955
--
956

    
957
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
958

    
959

    
960
--
961
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
962
--
963

    
964
CREATE FUNCTION try_create(sql text) RETURNS void
965
    LANGUAGE plpgsql STRICT
966
    AS $$
967
BEGIN
968
    EXECUTE sql;
969
EXCEPTION
970
    WHEN undefined_column THEN NULL;
971
    WHEN duplicate_column THEN NULL;
972
END;
973
$$;
974

    
975

    
976
--
977
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
978
--
979

    
980
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
981

    
982

    
983
--
984
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
985
--
986

    
987
CREATE FUNCTION type_qual(value anyelement) RETURNS text
988
    LANGUAGE sql IMMUTABLE
989
    AS $_$
990
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
991
$_$;
992

    
993

    
994
--
995
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
996
--
997

    
998
CREATE FUNCTION typeof(expr text, table_ regtype) RETURNS regtype
999
    LANGUAGE plpgsql STABLE STRICT
1000
    AS $_$
1001
DECLARE
1002
    type regtype;
1003
BEGIN
1004
    EXECUTE $$SELECT pg_typeof($$||expr||$$) FROM (SELECT (NULL::$$||table_||
1005
    $$).*) _s$$ INTO STRICT type;
1006
    RETURN type;
1007
END;
1008
$_$;
1009

    
1010

    
1011
--
1012
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1013
--
1014

    
1015
CREATE AGGREGATE join_strs(text, text) (
1016
    SFUNC = join_strs_transform,
1017
    STYPE = text
1018
);
1019

    
1020

    
1021
--
1022
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1023
--
1024

    
1025
CREATE OPERATOR -> (
1026
    PROCEDURE = map_get,
1027
    LEFTARG = regclass,
1028
    RIGHTARG = text
1029
);
1030

    
1031

    
1032
SET default_tablespace = '';
1033

    
1034
SET default_with_oids = false;
1035

    
1036
--
1037
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1038
--
1039

    
1040
CREATE TABLE map (
1041
    "from" text NOT NULL,
1042
    "to" text,
1043
    filter text,
1044
    notes text
1045
);
1046

    
1047

    
1048
--
1049
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1050
--
1051

    
1052

    
1053

    
1054
--
1055
-- Name: map_pkey; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
1056
--
1057

    
1058
ALTER TABLE ONLY map
1059
    ADD CONSTRAINT map_pkey PRIMARY KEY ("from");
1060

    
1061

    
1062
--
1063
-- PostgreSQL database dump complete
1064
--
1065

    
(14-14/24)