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: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
539
--
540

    
541
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
542
    LANGUAGE sql STABLE STRICT
543
    AS $_$
544
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
545
$_$;
546

    
547

    
548
--
549
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
550
--
551

    
552
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
553
    LANGUAGE plpgsql STRICT
554
    AS $_$
555
BEGIN
556
    -- not yet clustered (ARRAY[] compares NULLs literally)
557
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
558
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
559
    END IF;
560
END;
561
$_$;
562

    
563

    
564
--
565
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
566
--
567

    
568
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
569

    
570

    
571
--
572
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
573
--
574

    
575
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
576
    LANGUAGE plpgsql STABLE STRICT
577
    AS $$
578
DECLARE
579
	default_sql text;
580
BEGIN
581
	SELECT adsrc
582
	FROM pg_attribute
583
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
584
	WHERE attrelid = col.table_ AND attname = col.name
585
	INTO STRICT default_sql
586
	;
587
	RETURN default_sql;
588
EXCEPTION
589
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
590
END;
591
$$;
592

    
593

    
594
--
595
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
596
--
597

    
598
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
599
    LANGUAGE sql STABLE
600
    AS $_$
601
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
602
$_$;
603

    
604

    
605
--
606
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
607
--
608

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

    
611

    
612
--
613
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
614
--
615

    
616
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
617
    LANGUAGE plpgsql STRICT
618
    AS $$
619
BEGIN
620
    PERFORM util.col_type(col);
621
    RETURN true;
622
EXCEPTION
623
    WHEN undefined_column THEN RETURN false;
624
END;
625
$$;
626

    
627

    
628
--
629
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
630
--
631

    
632
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
633
    LANGUAGE plpgsql STABLE STRICT
634
    AS $$
635
DECLARE
636
    prefix text := util.name(type)||'.';
637
BEGIN
638
    RETURN QUERY
639
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
640
        FROM util.col_names(type) f (name_);
641
END;
642
$$;
643

    
644

    
645
--
646
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
647
--
648

    
649
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
650
    LANGUAGE plpgsql STABLE STRICT
651
    AS $_$
652
BEGIN
653
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
654
END;
655
$_$;
656

    
657

    
658
--
659
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
660
--
661

    
662
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
663
    LANGUAGE sql STABLE STRICT
664
    AS $_$
665
SELECT attname::text
666
FROM pg_attribute
667
WHERE attrelid = $1 AND attnum >= 1
668
ORDER BY attnum
669
$_$;
670

    
671

    
672
--
673
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
674
--
675

    
676
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
677
    LANGUAGE plpgsql STABLE STRICT
678
    AS $$
679
DECLARE
680
    type regtype;
681
BEGIN
682
    SELECT atttypid FROM pg_attribute
683
    WHERE attrelid = col.table_ AND attname = col.name
684
    INTO STRICT type
685
    ;
686
    RETURN type;
687
EXCEPTION
688
    WHEN no_data_found THEN
689
        RAISE undefined_column USING MESSAGE =
690
            concat('undefined column: ', col.name);
691
END;
692
$$;
693

    
694

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

    
699
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
700
    LANGUAGE sql IMMUTABLE STRICT
701
    AS $_$
702
SELECT position($1 in $2) > 0 /*1-based offset*/
703
$_$;
704

    
705

    
706
--
707
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
708
--
709

    
710
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
711
    LANGUAGE plpgsql STRICT
712
    AS $$
713
BEGIN
714
    EXECUTE sql;
715
EXCEPTION
716
    WHEN duplicate_table  THEN NULL;
717
    WHEN duplicate_column THEN NULL;
718
END;
719
$$;
720

    
721

    
722
--
723
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
724
--
725

    
726
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
727

    
728

    
729
--
730
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
731
--
732

    
733
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
734
    LANGUAGE sql STRICT
735
    AS $_$
736
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
737
$_$;
738

    
739

    
740
--
741
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
742
--
743

    
744
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
745

    
746

    
747
--
748
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
749
--
750

    
751
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
752
    LANGUAGE sql IMMUTABLE STRICT
753
    AS $_$
754
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
755
$_$;
756

    
757

    
758
--
759
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
760
--
761

    
762
CREATE FUNCTION eval(sql text) RETURNS void
763
    LANGUAGE plpgsql STRICT
764
    AS $$
765
BEGIN
766
    RAISE NOTICE '%', sql;
767
    EXECUTE sql;
768
END;
769
$$;
770

    
771

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

    
776
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
777
    LANGUAGE plpgsql
778
    AS $$
779
DECLARE
780
	ret_val ret_type_null%TYPE;
781
BEGIN
782
	RAISE NOTICE '%', sql;
783
	EXECUTE sql INTO STRICT ret_val;
784
	RETURN ret_val;
785
END;
786
$$;
787

    
788

    
789
--
790
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
791
--
792

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

    
795

    
796
--
797
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
798
--
799

    
800
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
801
    LANGUAGE sql
802
    AS $_$
803
SELECT util.eval2val($$SELECT $$||$1, $2)
804
$_$;
805

    
806

    
807
--
808
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
809
--
810

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

    
813

    
814
--
815
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
816
--
817

    
818
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
819
    LANGUAGE sql
820
    AS $_$
821
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
822
$_$;
823

    
824

    
825
--
826
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
827
--
828

    
829
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
830
ret_type_null: NULL::ret_type';
831

    
832

    
833
--
834
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
835
--
836

    
837
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
838
    LANGUAGE sql STABLE STRICT
839
    AS $_$
840
SELECT col_name
841
FROM unnest($2) s (col_name)
842
WHERE util.col_exists(($1, col_name))
843
$_$;
844

    
845

    
846
--
847
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
848
--
849

    
850
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
851
    LANGUAGE plpgsql STRICT
852
    AS $_$
853
DECLARE
854
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
855
$$||query;
856
BEGIN
857
	EXECUTE mk_view;
858
EXCEPTION
859
WHEN invalid_table_definition THEN
860
	IF SQLERRM = 'cannot drop columns from view'
861
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
862
	THEN
863
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
864
		EXECUTE mk_view;
865
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
866
	END IF;
867
END;
868
$_$;
869

    
870

    
871
--
872
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
873
--
874

    
875
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
876

    
877

    
878
--
879
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
880
--
881

    
882
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
883
    LANGUAGE sql IMMUTABLE STRICT
884
    AS $_$
885
SELECT substring($2 for length($1)) = $1
886
$_$;
887

    
888

    
889
--
890
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
891
--
892

    
893
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
894
    LANGUAGE sql IMMUTABLE STRICT
895
    AS $_$
896
SELECT $1 || $3 || $2
897
$_$;
898

    
899

    
900
--
901
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
902
--
903

    
904
CREATE FUNCTION map_filter_insert() RETURNS trigger
905
    LANGUAGE plpgsql
906
    AS $$
907
BEGIN
908
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
909
	RETURN new;
910
END;
911
$$;
912

    
913

    
914
--
915
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
916
--
917

    
918
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
919
    LANGUAGE plpgsql STABLE STRICT
920
    AS $_$
921
DECLARE
922
    value text;
923
BEGIN
924
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
925
        INTO value USING key;
926
    RETURN value;
927
END;
928
$_$;
929

    
930

    
931
--
932
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
933
--
934

    
935
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
936
    LANGUAGE plpgsql STABLE STRICT
937
    AS $_$
938
BEGIN
939
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
940
END;
941
$_$;
942

    
943

    
944
--
945
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
946
--
947

    
948
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
949
    LANGUAGE sql STRICT
950
    AS $_$
951
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
952
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
953
||quote_literal($2))
954
$_$;
955

    
956

    
957
--
958
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
959
--
960

    
961
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
962

    
963

    
964
--
965
-- Name: mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
966
--
967

    
968
CREATE FUNCTION mk_derived_col(col col_ref, expr text) RETURNS void
969
    LANGUAGE plpgsql STRICT
970
    AS $_$
971
DECLARE
972
    type regtype = util.typeof(expr, col.table_::text::regtype);
973
    col_name_sql text = quote_ident(col.name);
974
BEGIN
975
    PERFORM util.create_if_not_exists($$
976
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;
977
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
978
$$||expr||$$;
979
$$);
980
END;
981
$_$;
982

    
983

    
984
--
985
-- Name: FUNCTION mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
986
--
987

    
988
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text) IS 'idempotent';
989

    
990

    
991
--
992
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
993
--
994

    
995
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
996
    LANGUAGE sql STRICT
997
    AS $_$
998
SELECT util.create_if_not_exists($$
999
CREATE TABLE $$||$1||$$
1000
(
1001
    LIKE util.map INCLUDING ALL
1002
);
1003

    
1004
CREATE TRIGGER map_filter_insert
1005
  BEFORE INSERT
1006
  ON $$||$1||$$
1007
  FOR EACH ROW
1008
  EXECUTE PROCEDURE util.map_filter_insert();
1009
$$)
1010
$_$;
1011

    
1012

    
1013
--
1014
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1015
--
1016

    
1017
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1018
    LANGUAGE sql STRICT
1019
    AS $_$
1020
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1021
$_$;
1022

    
1023

    
1024
--
1025
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1026
--
1027

    
1028
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1029

    
1030

    
1031
--
1032
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1033
--
1034

    
1035
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1036
    LANGUAGE plpgsql STRICT
1037
    AS $_$
1038
BEGIN
1039
	EXECUTE $$
1040
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1041
  RETURNS SETOF $$||view_||$$ AS
1042
$BODY1$
1043
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1044
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
1045
$BODY1$
1046
  LANGUAGE sql STABLE
1047
  COST 100
1048
  ROWS 1000
1049
$$;
1050
-- Also create subset function which turns off enable_sort
1051
	EXECUTE $$
1052
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1053
  RETURNS SETOF $$||view_||$$
1054
  SET enable_sort TO 'off'
1055
  AS
1056
$BODY1$
1057
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1058
$BODY1$
1059
  LANGUAGE sql STABLE
1060
  COST 100
1061
  ROWS 1000
1062
;
1063
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1064
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1065
If you want to run EXPLAIN and get expanded output, use the regular subset
1066
function instead. (When a config param is set on a function, EXPLAIN produces
1067
just a function scan.)
1068
';
1069
$$;
1070
END;
1071
$_$;
1072

    
1073

    
1074
--
1075
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1076
--
1077

    
1078
CREATE FUNCTION name(type regtype) RETURNS text
1079
    LANGUAGE sql STABLE STRICT
1080
    AS $_$
1081
SELECT typname::text FROM pg_type WHERE oid = $1
1082
$_$;
1083

    
1084

    
1085
--
1086
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1087
--
1088

    
1089
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1090
    LANGUAGE sql IMMUTABLE
1091
    AS $_$
1092
SELECT $1 IS NOT NULL AND array_length($1, 1)/*ARRAY[]->NULL*/ IS NOT NULL
1093
$_$;
1094

    
1095

    
1096
--
1097
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1098
--
1099

    
1100
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1101
    LANGUAGE sql IMMUTABLE
1102
    AS $_$
1103
SELECT $1 IS NOT NULL
1104
$_$;
1105

    
1106

    
1107
--
1108
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1109
--
1110

    
1111
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1112
    LANGUAGE plpgsql IMMUTABLE STRICT
1113
    AS $$
1114
BEGIN
1115
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1116
END;
1117
$$;
1118

    
1119

    
1120
--
1121
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1122
--
1123

    
1124
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1125
    LANGUAGE sql STRICT
1126
    AS $_$
1127
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1128
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1129
FROM util.col_names($1::text::regtype) f (name)
1130
$_$;
1131

    
1132

    
1133
--
1134
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1135
--
1136

    
1137
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1138

    
1139

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

    
1144
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1145
    LANGUAGE sql STRICT
1146
    AS $_$
1147
SELECT util.mk_map_table($1);
1148
SELECT util.truncate($1);
1149
$_$;
1150

    
1151

    
1152
--
1153
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1154
--
1155

    
1156
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1157
    LANGUAGE sql STRICT
1158
    AS $_$
1159
SELECT util.eval(
1160
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1161
$_$;
1162

    
1163

    
1164
--
1165
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1166
--
1167

    
1168
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1169
    LANGUAGE plpgsql STRICT
1170
    AS $_$
1171
DECLARE
1172
    old text[] = ARRAY(SELECT util.col_names(table_));
1173
    new text[] = ARRAY(SELECT util.map_values(names));
1174
BEGIN
1175
    old = old[1:array_length(new, 1)]; -- truncate to same length
1176
    PERFORM util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1177
        ||quote_ident(key)||$$ TO $$||quote_ident(value))
1178
    FROM each(hstore(old, new));
1179
END;
1180
$_$;
1181

    
1182

    
1183
--
1184
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1185
--
1186

    
1187
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1188

    
1189

    
1190
--
1191
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1192
--
1193

    
1194
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1195
    LANGUAGE plpgsql STRICT
1196
    AS $_$
1197
DECLARE
1198
    sql text = $$ALTER TABLE $$||table_||$$
1199
$$||NULLIF(array_to_string(ARRAY(
1200
    SELECT
1201
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1202
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1203
    FROM
1204
    (
1205
        SELECT
1206
          quote_ident(col_name) AS col_name_sql
1207
        , util.col_type((table_, col_name)) AS curr_type
1208
        , type AS target_type
1209
        FROM unnest(col_casts)
1210
    ) s
1211
    WHERE curr_type != target_type
1212
), '
1213
, '), '');
1214
BEGIN
1215
    RAISE NOTICE '%', sql;
1216
    EXECUTE COALESCE(sql, '');
1217
END;
1218
$_$;
1219

    
1220

    
1221
--
1222
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1223
--
1224

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

    
1227

    
1228
--
1229
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1230
--
1231

    
1232
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1233
    LANGUAGE plpgsql STABLE STRICT
1234
    AS $_$
1235
DECLARE
1236
    hstore hstore;
1237
BEGIN
1238
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1239
        table_||$$))$$ INTO STRICT hstore;
1240
    RETURN hstore;
1241
END;
1242
$_$;
1243

    
1244

    
1245
--
1246
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1247
--
1248

    
1249
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1250
    LANGUAGE sql STABLE STRICT
1251
    AS $_$
1252
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1253
$_$;
1254

    
1255

    
1256
--
1257
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1258
--
1259

    
1260
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1261
    LANGUAGE plpgsql STRICT
1262
    AS $_$
1263
DECLARE
1264
    row record;
1265
BEGIN
1266
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1267
    LOOP
1268
        IF row.global_name != row.name THEN
1269
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1270
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1271
        END IF;
1272
    END LOOP;
1273
END;
1274
$_$;
1275

    
1276

    
1277
--
1278
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1279
--
1280

    
1281
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1282

    
1283

    
1284
--
1285
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1286
--
1287

    
1288
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1289
    LANGUAGE plpgsql STRICT
1290
    AS $_$
1291
BEGIN
1292
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1293
END;
1294
$_$;
1295

    
1296

    
1297
--
1298
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1299
--
1300

    
1301
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1302

    
1303

    
1304
--
1305
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1306
--
1307

    
1308
CREATE FUNCTION try_create(sql text) RETURNS void
1309
    LANGUAGE plpgsql STRICT
1310
    AS $$
1311
BEGIN
1312
    EXECUTE sql;
1313
EXCEPTION
1314
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1315
    WHEN undefined_column THEN NULL;
1316
    WHEN duplicate_column THEN NULL;
1317
END;
1318
$$;
1319

    
1320

    
1321
--
1322
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1323
--
1324

    
1325
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1326

    
1327

    
1328
--
1329
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1330
--
1331

    
1332
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1333
    LANGUAGE sql STRICT
1334
    AS $_$
1335
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1336
$_$;
1337

    
1338

    
1339
--
1340
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1341
--
1342

    
1343
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1344

    
1345

    
1346
--
1347
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1348
--
1349

    
1350
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1351
    LANGUAGE sql IMMUTABLE
1352
    AS $_$
1353
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1354
$_$;
1355

    
1356

    
1357
--
1358
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1359
--
1360

    
1361
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1362
    LANGUAGE sql STABLE STRICT
1363
    SET search_path TO pg_temp
1364
    AS $_$
1365
SELECT $1::text
1366
$_$;
1367

    
1368

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

    
1373
CREATE FUNCTION typeof(expr text, table_ regtype) RETURNS regtype
1374
    LANGUAGE plpgsql STABLE STRICT
1375
    AS $_$
1376
DECLARE
1377
    type regtype;
1378
BEGIN
1379
    EXECUTE $$SELECT pg_typeof($$||expr||$$) FROM (SELECT (NULL::$$||table_||
1380
    $$).*) _s$$ INTO STRICT type;
1381
    RETURN type;
1382
END;
1383
$_$;
1384

    
1385

    
1386
--
1387
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1388
--
1389

    
1390
CREATE AGGREGATE all_same(anyelement) (
1391
    SFUNC = all_same_transform,
1392
    STYPE = anyarray,
1393
    FINALFUNC = all_same_final
1394
);
1395

    
1396

    
1397
--
1398
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1399
--
1400

    
1401
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1402

    
1403

    
1404
--
1405
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1406
--
1407

    
1408
CREATE AGGREGATE join_strs(text, text) (
1409
    SFUNC = join_strs_transform,
1410
    STYPE = text
1411
);
1412

    
1413

    
1414
--
1415
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1416
--
1417

    
1418
CREATE OPERATOR -> (
1419
    PROCEDURE = map_get,
1420
    LEFTARG = regclass,
1421
    RIGHTARG = text
1422
);
1423

    
1424

    
1425
SET default_tablespace = '';
1426

    
1427
SET default_with_oids = false;
1428

    
1429
--
1430
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1431
--
1432

    
1433
CREATE TABLE map (
1434
    "from" text NOT NULL,
1435
    "to" text,
1436
    filter text,
1437
    notes text
1438
);
1439

    
1440

    
1441
--
1442
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1443
--
1444

    
1445

    
1446

    
1447
--
1448
-- Name: map_pkey; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
1449
--
1450

    
1451
ALTER TABLE ONLY map
1452
    ADD CONSTRAINT map_pkey PRIMARY KEY ("from");
1453

    
1454

    
1455
--
1456
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1457
--
1458

    
1459
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1460

    
1461

    
1462
--
1463
-- PostgreSQL database dump complete
1464
--
1465

    
(17-17/27)