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

    
26

    
27
SET search_path = util, pg_catalog;
28

    
29
--
30
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
31
--
32

    
33
CREATE TYPE col_cast AS (
34
	col_name text,
35
	type regtype
36
);
37

    
38

    
39
--
40
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
41
--
42

    
43
CREATE TYPE col_ref AS (
44
	table_ regclass,
45
	name text
46
);
47

    
48

    
49
--
50
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
51
--
52

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

    
60

    
61
--
62
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
63
--
64

    
65
CREATE TYPE datatype AS ENUM (
66
    'str',
67
    'float'
68
);
69

    
70

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

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

    
81

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

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

    
101

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

    
106
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.';
107

    
108

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

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

    
128

    
129
--
130
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
131
--
132

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

    
147

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

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

    
165

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

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

    
176

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

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

    
187

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

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

    
200

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

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

    
211

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

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

    
222

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

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

    
233

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

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

    
244

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

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

    
255

    
256
--
257
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
258
--
259

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

    
266

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

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

    
291

    
292
--
293
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
294
--
295

    
296
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
297
    LANGUAGE plpgsql IMMUTABLE STRICT
298
    AS $$
299
DECLARE
300
    result value%TYPE := util._map(map, value::text)::unknown;
301
BEGIN
302
    RETURN result;
303
END;
304
$$;
305

    
306

    
307
--
308
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
309
--
310

    
311
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
312
    LANGUAGE sql IMMUTABLE
313
    AS $_$
314
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
315
$_$;
316

    
317

    
318
--
319
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
320
--
321

    
322
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
323
    LANGUAGE sql IMMUTABLE
324
    AS $_$
325
SELECT util.join_strs(value, '; ')
326
FROM
327
(
328
    SELECT *
329
    FROM
330
    (
331
        SELECT
332
        DISTINCT ON (value)
333
        *
334
        FROM
335
        (VALUES
336
              (1, $1)
337
            , (2, $2)
338
            , (3, $3)
339
            , (4, $4)
340
            , (5, $5)
341
            , (6, $6)
342
            , (7, $7)
343
            , (8, $8)
344
            , (9, $9)
345
            , (10, $10)
346
        )
347
        AS v (sort_order, value)
348
        WHERE value IS NOT NULL
349
    )
350
    AS v
351
    ORDER BY sort_order
352
)
353
AS v
354
$_$;
355

    
356

    
357
--
358
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
359
--
360

    
361
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
362
    LANGUAGE sql IMMUTABLE
363
    AS $_$
364
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
365
$_$;
366

    
367

    
368
--
369
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
370
--
371

    
372
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
373
    LANGUAGE sql IMMUTABLE
374
    AS $_$
375
SELECT util.join_strs(value, ' ')
376
FROM
377
(
378
    SELECT *
379
    FROM
380
    (
381
        SELECT
382
        DISTINCT ON (value)
383
        *
384
        FROM
385
        (VALUES
386
              (1, $1)
387
            , (2, $2)
388
            , (3, $3)
389
            , (4, $4)
390
            , (5, $5)
391
            , (6, $6)
392
            , (7, $7)
393
            , (8, $8)
394
            , (9, $9)
395
            , (10, $10)
396
        )
397
        AS v (sort_order, value)
398
        WHERE value IS NOT NULL
399
    )
400
    AS v
401
    ORDER BY sort_order
402
)
403
AS v
404
$_$;
405

    
406

    
407
--
408
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
409
--
410

    
411
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
412
    LANGUAGE sql IMMUTABLE
413
    AS $_$
414
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
415
$_$;
416

    
417

    
418
--
419
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
420
--
421

    
422
CREATE FUNCTION _not(value boolean) RETURNS boolean
423
    LANGUAGE sql IMMUTABLE
424
    AS $_$
425
SELECT NOT $1
426
$_$;
427

    
428

    
429
--
430
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
431
--
432

    
433
CREATE FUNCTION _now() RETURNS timestamp with time zone
434
    LANGUAGE sql STABLE
435
    AS $$
436
SELECT now()
437
$$;
438

    
439

    
440
--
441
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
442
--
443

    
444
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
445
    LANGUAGE plpgsql IMMUTABLE
446
    AS $$
447
DECLARE
448
    type util.datatype NOT NULL := type; -- add NOT NULL
449
BEGIN
450
    IF type = 'str' THEN RETURN nullif(value::text, "null");
451
    -- Invalid value is ignored, but invalid null value generates error
452
    ELSIF type = 'float' THEN
453
        DECLARE
454
            -- Outside the try block so that invalid null value generates error
455
            "null" double precision := "null"::double precision;
456
        BEGIN
457
            RETURN nullif(value::double precision, "null");
458
        EXCEPTION
459
            WHEN data_exception THEN RETURN value; -- ignore invalid value
460
        END;
461
    END IF;
462
END;
463
$$;
464

    
465

    
466
--
467
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
468
--
469

    
470
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
471
    LANGUAGE sql IMMUTABLE
472
    AS $_$
473
SELECT util."_nullIf"($1, $2, $3::util.datatype)
474
$_$;
475

    
476

    
477
--
478
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
479
--
480

    
481
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
482
    LANGUAGE sql IMMUTABLE
483
    AS $_$
484
SELECT bool_or(value)
485
FROM
486
(VALUES
487
      ($1)
488
    , ($2)
489
    , ($3)
490
    , ($4)
491
    , ($5)
492
)
493
AS v (value)
494
$_$;
495

    
496

    
497
--
498
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
499
--
500

    
501
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.';
502

    
503

    
504
--
505
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
506
--
507

    
508
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
509
    LANGUAGE sql IMMUTABLE
510
    AS $_$
511
SELECT $2 - $1
512
$_$;
513

    
514

    
515
--
516
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
517
--
518

    
519
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
520
    LANGUAGE sql IMMUTABLE
521
    AS $_$
522
SELECT regexp_split_to_table($1, $2)
523
$_$;
524

    
525

    
526
--
527
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
528
--
529

    
530
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
531
    LANGUAGE sql IMMUTABLE
532
    AS $_$
533
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
534
$_$;
535

    
536

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

    
541
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
542
    LANGUAGE plpgsql IMMUTABLE
543
    AS $$
544
DECLARE
545
	value_cmp         state%TYPE = ARRAY[value];
546
	state             state%TYPE = COALESCE(state, value_cmp);
547
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
548
BEGIN
549
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
550
END;
551
$$;
552

    
553

    
554
--
555
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
556
--
557

    
558
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
559
    LANGUAGE sql IMMUTABLE
560
    AS $_$
561
SELECT pg_catalog.array_fill($1, ARRAY[$2])
562
$_$;
563

    
564

    
565
--
566
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
567
--
568

    
569
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
570
    LANGUAGE sql IMMUTABLE
571
    AS $_$
572
SELECT util.array_length($1, 1)
573
$_$;
574

    
575

    
576
--
577
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
578
--
579

    
580
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
581
    LANGUAGE sql IMMUTABLE
582
    AS $_$
583
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
584
$_$;
585

    
586

    
587
--
588
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
589
--
590

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

    
593

    
594
--
595
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
596
--
597

    
598
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
599
    LANGUAGE sql STABLE STRICT
600
    AS $_$
601
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
602
$_$;
603

    
604

    
605
--
606
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
607
--
608

    
609
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
610
    LANGUAGE plpgsql STRICT
611
    AS $_$
612
BEGIN
613
    -- not yet clustered (ARRAY[] compares NULLs literally)
614
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
615
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
616
    END IF;
617
END;
618
$_$;
619

    
620

    
621
--
622
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
623
--
624

    
625
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
626

    
627

    
628
--
629
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
630
--
631

    
632
CREATE FUNCTION col_comment(col col_ref) RETURNS text
633
    LANGUAGE plpgsql STABLE STRICT
634
    AS $$
635
DECLARE
636
	comment text;
637
BEGIN
638
	SELECT description
639
	FROM pg_attribute
640
	LEFT JOIN pg_description ON objoid = attrelid
641
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
642
	WHERE attrelid = col.table_ AND attname = col.name
643
	INTO STRICT comment
644
	;
645
	RETURN comment;
646
EXCEPTION
647
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
648
END;
649
$$;
650

    
651

    
652
--
653
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
654
--
655

    
656
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
657
    LANGUAGE plpgsql STABLE STRICT
658
    AS $$
659
DECLARE
660
	default_sql text;
661
BEGIN
662
	SELECT adsrc
663
	FROM pg_attribute
664
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
665
	WHERE attrelid = col.table_ AND attname = col.name
666
	INTO STRICT default_sql
667
	;
668
	RETURN default_sql;
669
EXCEPTION
670
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
671
END;
672
$$;
673

    
674

    
675
--
676
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
677
--
678

    
679
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
680
    LANGUAGE sql STABLE
681
    AS $_$
682
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
683
$_$;
684

    
685

    
686
--
687
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
688
--
689

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

    
692

    
693
--
694
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
695
--
696

    
697
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
698
    LANGUAGE plpgsql STRICT
699
    AS $$
700
BEGIN
701
    PERFORM util.col_type(col);
702
    RETURN true;
703
EXCEPTION
704
    WHEN undefined_column THEN RETURN false;
705
END;
706
$$;
707

    
708

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

    
713
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
714
    LANGUAGE plpgsql STABLE STRICT
715
    AS $$
716
DECLARE
717
    prefix text := util.name(type)||'.';
718
BEGIN
719
    RETURN QUERY
720
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
721
        FROM util.col_names(type) f (name_);
722
END;
723
$$;
724

    
725

    
726
--
727
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
728
--
729

    
730
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
731
    LANGUAGE plpgsql STABLE STRICT
732
    AS $_$
733
BEGIN
734
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
735
END;
736
$_$;
737

    
738

    
739
--
740
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
741
--
742

    
743
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
744
    LANGUAGE sql STABLE STRICT
745
    AS $_$
746
SELECT attname::text
747
FROM pg_attribute
748
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
749
ORDER BY attnum
750
$_$;
751

    
752

    
753
--
754
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
755
--
756

    
757
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
758
    LANGUAGE plpgsql STABLE STRICT
759
    AS $$
760
DECLARE
761
    type regtype;
762
BEGIN
763
    SELECT atttypid FROM pg_attribute
764
    WHERE attrelid = col.table_ AND attname = col.name
765
    INTO STRICT type
766
    ;
767
    RETURN type;
768
EXCEPTION
769
    WHEN no_data_found THEN
770
        RAISE undefined_column USING MESSAGE =
771
            concat('undefined column: ', col.name);
772
END;
773
$$;
774

    
775

    
776
--
777
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
778
--
779

    
780
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
781
    LANGUAGE sql IMMUTABLE
782
    AS $_$
783
SELECT position($1 in $2) > 0 /*1-based offset*/
784
$_$;
785

    
786

    
787
--
788
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
789
--
790

    
791
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
792
    LANGUAGE plpgsql STRICT
793
    AS $$
794
BEGIN
795
    PERFORM util.eval(sql);
796
EXCEPTION
797
    WHEN duplicate_table  THEN NULL;
798
    WHEN duplicate_object THEN NULL; -- e.g. constraint
799
    WHEN duplicate_column THEN NULL;
800
    WHEN invalid_table_definition THEN
801
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
802
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
803
        END IF;
804
END;
805
$$;
806

    
807

    
808
--
809
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
810
--
811

    
812
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
813

    
814

    
815
--
816
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
817
--
818

    
819
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
820
    LANGUAGE sql STABLE STRICT
821
    AS $_$
822
SELECT util.eval2set($$
823
SELECT col
824
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
825
LEFT JOIN $$||$2||$$ ON "to" = col
826
WHERE "from" IS NULL
827
$$, NULL::text)
828
$_$;
829

    
830

    
831
--
832
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
833
--
834

    
835
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS 'gets table_''s derived columns (all the columns not in the names table)';
836

    
837

    
838
--
839
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
840
--
841

    
842
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
843
    LANGUAGE sql STRICT
844
    AS $_$
845
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
846
$_$;
847

    
848

    
849
--
850
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
851
--
852

    
853
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
854

    
855

    
856
--
857
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
858
--
859

    
860
CREATE FUNCTION drop_column(col col_ref) RETURNS void
861
    LANGUAGE sql STRICT
862
    AS $_$
863
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
864
quote_ident($1.name))
865
$_$;
866

    
867

    
868
--
869
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
870
--
871

    
872
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
873

    
874

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

    
879
CREATE FUNCTION drop_table(table_ text) RETURNS void
880
    LANGUAGE sql STRICT
881
    AS $_$
882
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
883
$_$;
884

    
885

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

    
890
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
891

    
892

    
893
--
894
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
895
--
896

    
897
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
898
    LANGUAGE sql IMMUTABLE
899
    AS $_$
900
SELECT util.array_fill($1, 0)
901
$_$;
902

    
903

    
904
--
905
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
906
--
907

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

    
910

    
911
--
912
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
913
--
914

    
915
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
916
    LANGUAGE sql IMMUTABLE
917
    AS $_$
918
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
919
$_$;
920

    
921

    
922
--
923
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
924
--
925

    
926
CREATE FUNCTION eval(sql text) RETURNS void
927
    LANGUAGE plpgsql STRICT
928
    AS $$
929
BEGIN
930
    RAISE NOTICE '%', sql;
931
    EXECUTE sql;
932
END;
933
$$;
934

    
935

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

    
940
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
941
    LANGUAGE plpgsql
942
    AS $$
943
BEGIN
944
	RAISE NOTICE '%', sql;
945
	RETURN QUERY EXECUTE sql;
946
END;
947
$$;
948

    
949

    
950
--
951
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
952
--
953

    
954
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
955

    
956

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

    
961
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
962
    LANGUAGE plpgsql
963
    AS $$
964
DECLARE
965
	ret_val ret_type_null%TYPE;
966
BEGIN
967
	RAISE NOTICE '%', sql;
968
	EXECUTE sql INTO STRICT ret_val;
969
	RETURN ret_val;
970
END;
971
$$;
972

    
973

    
974
--
975
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
976
--
977

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

    
980

    
981
--
982
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
983
--
984

    
985
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
986
    LANGUAGE sql
987
    AS $_$
988
SELECT util.eval2val($$SELECT $$||$1, $2)
989
$_$;
990

    
991

    
992
--
993
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
994
--
995

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

    
998

    
999
--
1000
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1001
--
1002

    
1003
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1004
    LANGUAGE sql
1005
    AS $_$
1006
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1007
$_$;
1008

    
1009

    
1010
--
1011
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1012
--
1013

    
1014
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1015
ret_type_null: NULL::ret_type';
1016

    
1017

    
1018
--
1019
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1020
--
1021

    
1022
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1023
    LANGUAGE sql STABLE STRICT
1024
    AS $_$
1025
SELECT col_name
1026
FROM unnest($2) s (col_name)
1027
WHERE util.col_exists(($1, col_name))
1028
$_$;
1029

    
1030

    
1031
--
1032
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1033
--
1034

    
1035
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1036
    LANGUAGE sql IMMUTABLE
1037
    AS $_$
1038
-- STRICT handles NULLs, so that the array will always be a value
1039
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1040
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1041
) END
1042
$_$;
1043

    
1044

    
1045
--
1046
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1047
--
1048

    
1049
COMMENT ON FUNCTION fix_array("array" anyarray) IS 'ensures that an array will always have proper non-NULL dimensions';
1050

    
1051

    
1052
--
1053
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1054
--
1055

    
1056
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1057
    LANGUAGE plpgsql STRICT
1058
    AS $_$
1059
DECLARE
1060
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1061
$$||query;
1062
BEGIN
1063
	EXECUTE mk_view;
1064
EXCEPTION
1065
WHEN invalid_table_definition THEN
1066
	IF SQLERRM = 'cannot drop columns from view'
1067
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1068
	THEN
1069
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1070
		EXECUTE mk_view;
1071
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1072
	END IF;
1073
END;
1074
$_$;
1075

    
1076

    
1077
--
1078
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1079
--
1080

    
1081
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1082

    
1083

    
1084
--
1085
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1086
--
1087

    
1088
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1089
    LANGUAGE sql IMMUTABLE
1090
    AS $_$
1091
SELECT substring($2 for length($1)) = $1
1092
$_$;
1093

    
1094

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

    
1099
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1100
    LANGUAGE sql IMMUTABLE
1101
    AS $_$
1102
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1103
$_$;
1104

    
1105

    
1106
--
1107
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1108
--
1109

    
1110
COMMENT ON FUNCTION hstore(keys text[], value text) IS 'avoids repeating the same value for each key';
1111

    
1112

    
1113
--
1114
-- Name: hstore(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1115
--
1116

    
1117
CREATE FUNCTION hstore(keys text[], value anyelement) RETURNS hstore
1118
    LANGUAGE sql IMMUTABLE
1119
    AS $_$
1120
SELECT util.hstore($1, $2::text)
1121
$_$;
1122

    
1123

    
1124
--
1125
-- Name: FUNCTION hstore(keys text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1126
--
1127

    
1128
COMMENT ON FUNCTION hstore(keys text[], value anyelement) IS 'avoids repeating the same value for each key';
1129

    
1130

    
1131
--
1132
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1133
--
1134

    
1135
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1136
    LANGUAGE sql STABLE STRICT
1137
    AS $_$
1138
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1139
$_$;
1140

    
1141

    
1142
--
1143
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1144
--
1145

    
1146
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1147
    LANGUAGE sql IMMUTABLE STRICT
1148
    AS $_$
1149
SELECT $1 || $3 || $2
1150
$_$;
1151

    
1152

    
1153
--
1154
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1155
--
1156

    
1157
CREATE FUNCTION map_filter_insert() RETURNS trigger
1158
    LANGUAGE plpgsql
1159
    AS $$
1160
BEGIN
1161
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1162
	RETURN new;
1163
END;
1164
$$;
1165

    
1166

    
1167
--
1168
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1169
--
1170

    
1171
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1172
    LANGUAGE plpgsql STABLE STRICT
1173
    AS $_$
1174
DECLARE
1175
    value text;
1176
BEGIN
1177
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1178
        INTO value USING key;
1179
    RETURN value;
1180
END;
1181
$_$;
1182

    
1183

    
1184
--
1185
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1186
--
1187

    
1188
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1189
    LANGUAGE sql IMMUTABLE
1190
    AS $_$
1191
SELECT util._map(util.nulls_map($1), $2)
1192
$_$;
1193

    
1194

    
1195
--
1196
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1197
--
1198

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

    
1201
[1] inlining of function calls, which is different from constant folding
1202
[2] _map()''s profiling query
1203
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1204
and map_nulls()''s profiling query
1205
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1206
both take ~920 ms.
1207
also, /inputs/REMIB/Specimen/postprocess.sql > country takes the same amount of time (56000 ms) to build with map_nulls() as with a literal hstore.';
1208

    
1209

    
1210
--
1211
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1212
--
1213

    
1214
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1215
    LANGUAGE plpgsql STABLE STRICT
1216
    AS $_$
1217
BEGIN
1218
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1219
END;
1220
$_$;
1221

    
1222

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

    
1227
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1228
    LANGUAGE sql STRICT
1229
    AS $_$
1230
SELECT util.create_if_not_exists($$
1231
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1232
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1233
||quote_literal($2)||$$;
1234
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1235
$$)
1236
$_$;
1237

    
1238

    
1239
--
1240
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1241
--
1242

    
1243
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1244

    
1245

    
1246
--
1247
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1248
--
1249

    
1250
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1251
    LANGUAGE plpgsql STRICT
1252
    AS $_$
1253
DECLARE
1254
    type regtype = util.typeof(expr, col.table_::text::regtype);
1255
    col_name_sql text = quote_ident(col.name);
1256
BEGIN
1257
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1258
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1259
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1260
$$||expr||$$;
1261
$$);
1262
END;
1263
$_$;
1264

    
1265

    
1266
--
1267
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1268
--
1269

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

    
1272

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

    
1277
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1278
    LANGUAGE sql STRICT
1279
    AS $_$
1280
SELECT util.create_if_not_exists($$
1281
CREATE TABLE $$||$1||$$
1282
(
1283
    LIKE util.map INCLUDING ALL
1284
);
1285

    
1286
CREATE TRIGGER map_filter_insert
1287
  BEFORE INSERT
1288
  ON $$||$1||$$
1289
  FOR EACH ROW
1290
  EXECUTE PROCEDURE util.map_filter_insert();
1291
$$)
1292
$_$;
1293

    
1294

    
1295
--
1296
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1297
--
1298

    
1299
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1300
    LANGUAGE sql STRICT
1301
    AS $_$
1302
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1303
$_$;
1304

    
1305

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

    
1310
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1311

    
1312

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

    
1317
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1318
    LANGUAGE plpgsql STRICT
1319
    AS $_$
1320
BEGIN
1321
	EXECUTE $$
1322
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1323
  RETURNS SETOF $$||view_||$$ AS
1324
$BODY1$
1325
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1326
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
1327
$BODY1$
1328
  LANGUAGE sql STABLE
1329
  COST 100
1330
  ROWS 1000
1331
$$;
1332
-- Also create subset function which turns off enable_sort
1333
	EXECUTE $$
1334
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1335
  RETURNS SETOF $$||view_||$$
1336
  SET enable_sort TO 'off'
1337
  AS
1338
$BODY1$
1339
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1340
$BODY1$
1341
  LANGUAGE sql STABLE
1342
  COST 100
1343
  ROWS 1000
1344
;
1345
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1346
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1347
If you want to run EXPLAIN and get expanded output, use the regular subset
1348
function instead. (When a config param is set on a function, EXPLAIN produces
1349
just a function scan.)
1350
';
1351
$$;
1352
END;
1353
$_$;
1354

    
1355

    
1356
--
1357
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1358
--
1359

    
1360
CREATE FUNCTION name(type regtype) RETURNS text
1361
    LANGUAGE sql STABLE STRICT
1362
    AS $_$
1363
SELECT typname::text FROM pg_type WHERE oid = $1
1364
$_$;
1365

    
1366

    
1367
--
1368
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1369
--
1370

    
1371
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1372
    LANGUAGE sql IMMUTABLE
1373
    AS $_$
1374
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1375
$_$;
1376

    
1377

    
1378
--
1379
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1380
--
1381

    
1382
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1383
    LANGUAGE sql IMMUTABLE
1384
    AS $_$
1385
SELECT $1 IS NOT NULL
1386
$_$;
1387

    
1388

    
1389
--
1390
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1391
--
1392

    
1393
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1394
    LANGUAGE sql IMMUTABLE
1395
    AS $_$
1396
SELECT util.hstore($1, NULL) || '*=>*'
1397
$_$;
1398

    
1399

    
1400
--
1401
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1402
--
1403

    
1404
COMMENT ON FUNCTION nulls_map(nulls text[]) IS 'for use with _map()';
1405

    
1406

    
1407
--
1408
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1409
--
1410

    
1411
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1412
    LANGUAGE plpgsql IMMUTABLE STRICT
1413
    AS $$
1414
BEGIN
1415
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1416
END;
1417
$$;
1418

    
1419

    
1420
--
1421
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1422
--
1423

    
1424
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1425
    LANGUAGE sql STRICT
1426
    AS $_$
1427
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1428
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1429
FROM util.col_names($1::text::regtype) f (name);
1430
SELECT NULL::void; -- don't fold away functions called in previous query
1431
$_$;
1432

    
1433

    
1434
--
1435
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1436
--
1437

    
1438
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1439

    
1440

    
1441
--
1442
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1443
--
1444

    
1445
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1446
    LANGUAGE sql STRICT
1447
    AS $_$
1448
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1449
SELECT util.set_col_names($1, $2);
1450
$_$;
1451

    
1452

    
1453
--
1454
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1455
--
1456

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

    
1460

    
1461
--
1462
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1463
--
1464

    
1465
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1466
    LANGUAGE sql STRICT
1467
    AS $_$
1468
SELECT util.drop_table($1);
1469
SELECT util.mk_map_table($1);
1470
$_$;
1471

    
1472

    
1473
--
1474
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1475
--
1476

    
1477
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1478
    LANGUAGE sql STRICT
1479
    AS $_$
1480
SELECT util.eval(
1481
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1482
$_$;
1483

    
1484

    
1485
--
1486
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1487
--
1488

    
1489
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1490
    LANGUAGE plpgsql STRICT
1491
    AS $_$
1492
DECLARE
1493
    old text[] = ARRAY(SELECT util.col_names(table_));
1494
    new text[] = ARRAY(SELECT util.map_values(names));
1495
BEGIN
1496
    old = old[1:array_length(new, 1)]; -- truncate to same length
1497
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1498
||$$ TO $$||quote_ident(value))
1499
    FROM each(hstore(old, new))
1500
    WHERE value != key -- not same name
1501
    ;
1502
END;
1503
$_$;
1504

    
1505

    
1506
--
1507
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1508
--
1509

    
1510
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1511

    
1512

    
1513
--
1514
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1515
--
1516

    
1517
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1518
    LANGUAGE plpgsql STRICT
1519
    AS $_$
1520
DECLARE
1521
	row_ util.map;
1522
BEGIN
1523
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1524
	LOOP
1525
		PERFORM util.mk_const_col((table_, row_."to"),
1526
			substring(row_."from" from 2));
1527
	END LOOP;
1528
	
1529
	PERFORM util.set_col_names(table_, names);
1530
END;
1531
$_$;
1532

    
1533

    
1534
--
1535
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1536
--
1537

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

    
1541

    
1542
--
1543
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1544
--
1545

    
1546
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1547
    LANGUAGE plpgsql STRICT
1548
    AS $_$
1549
DECLARE
1550
    sql text = $$ALTER TABLE $$||table_||$$
1551
$$||NULLIF(array_to_string(ARRAY(
1552
    SELECT
1553
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1554
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1555
    FROM
1556
    (
1557
        SELECT
1558
          quote_ident(col_name) AS col_name_sql
1559
        , util.col_type((table_, col_name)) AS curr_type
1560
        , type AS target_type
1561
        FROM unnest(col_casts)
1562
    ) s
1563
    WHERE curr_type != target_type
1564
), '
1565
, '), '');
1566
BEGIN
1567
    RAISE NOTICE '%', sql;
1568
    EXECUTE COALESCE(sql, '');
1569
END;
1570
$_$;
1571

    
1572

    
1573
--
1574
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1575
--
1576

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

    
1579

    
1580
--
1581
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1582
--
1583

    
1584
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1585
    LANGUAGE plpgsql STABLE STRICT
1586
    AS $_$
1587
DECLARE
1588
    hstore hstore;
1589
BEGIN
1590
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1591
        table_||$$))$$ INTO STRICT hstore;
1592
    RETURN hstore;
1593
END;
1594
$_$;
1595

    
1596

    
1597
--
1598
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1599
--
1600

    
1601
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1602
    LANGUAGE sql STABLE STRICT
1603
    AS $_$
1604
SELECT COUNT(*) > 0 FROM pg_constraint
1605
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1606
$_$;
1607

    
1608

    
1609
--
1610
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1611
--
1612

    
1613
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';
1614

    
1615

    
1616
--
1617
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1618
--
1619

    
1620
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1621
    LANGUAGE sql STRICT
1622
    AS $_$
1623
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1624
||quote_ident($2)||$$ CHECK (true)$$)
1625
$_$;
1626

    
1627

    
1628
--
1629
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1630
--
1631

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

    
1635

    
1636
--
1637
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1638
--
1639

    
1640
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1641
    LANGUAGE sql STABLE STRICT
1642
    AS $_$
1643
SELECT util.table_flag__get($1, 'nulls_mapped')
1644
$_$;
1645

    
1646

    
1647
--
1648
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1649
--
1650

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

    
1653

    
1654
--
1655
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1656
--
1657

    
1658
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1659
    LANGUAGE sql STRICT
1660
    AS $_$
1661
SELECT util.table_flag__set($1, 'nulls_mapped')
1662
$_$;
1663

    
1664

    
1665
--
1666
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1667
--
1668

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

    
1672

    
1673
--
1674
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1675
--
1676

    
1677
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1678
    LANGUAGE sql STABLE STRICT
1679
    AS $_$
1680
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1681
$_$;
1682

    
1683

    
1684
--
1685
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1686
--
1687

    
1688
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1689
    LANGUAGE plpgsql STRICT
1690
    AS $_$
1691
DECLARE
1692
    row record;
1693
BEGIN
1694
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1695
    LOOP
1696
        IF row.global_name != row.name THEN
1697
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1698
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1699
        END IF;
1700
    END LOOP;
1701
END;
1702
$_$;
1703

    
1704

    
1705
--
1706
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1707
--
1708

    
1709
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1710

    
1711

    
1712
--
1713
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1714
--
1715

    
1716
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
1717
    LANGUAGE sql STRICT
1718
    AS $_$
1719
SELECT util.drop_column(($1, col)) FROM util.derived_cols($1, $2) f (col);
1720
SELECT NULL::void; -- don't fold away functions called in previous query
1721
$_$;
1722

    
1723

    
1724
--
1725
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1726
--
1727

    
1728
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS 'trims table_ to include only original columns, as defined by the names table.
1729
idempotent.';
1730

    
1731

    
1732
--
1733
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1734
--
1735

    
1736
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1737
    LANGUAGE plpgsql STRICT
1738
    AS $_$
1739
BEGIN
1740
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1741
END;
1742
$_$;
1743

    
1744

    
1745
--
1746
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1747
--
1748

    
1749
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1750

    
1751

    
1752
--
1753
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1754
--
1755

    
1756
CREATE FUNCTION try_create(sql text) RETURNS void
1757
    LANGUAGE plpgsql STRICT
1758
    AS $$
1759
BEGIN
1760
    PERFORM util.eval(sql);
1761
EXCEPTION
1762
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1763
    WHEN undefined_column THEN NULL;
1764
    WHEN duplicate_column THEN NULL;
1765
END;
1766
$$;
1767

    
1768

    
1769
--
1770
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1771
--
1772

    
1773
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1774

    
1775

    
1776
--
1777
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779

    
1780
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1781
    LANGUAGE sql STRICT
1782
    AS $_$
1783
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1784
$_$;
1785

    
1786

    
1787
--
1788
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1789
--
1790

    
1791
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1792

    
1793

    
1794
--
1795
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1796
--
1797

    
1798
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1799
    LANGUAGE sql IMMUTABLE
1800
    AS $_$
1801
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1802
$_$;
1803

    
1804

    
1805
--
1806
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
1807
--
1808

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

    
1811

    
1812
--
1813
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1814
--
1815

    
1816
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1817
    LANGUAGE sql STABLE STRICT
1818
    SET search_path TO pg_temp
1819
    AS $_$
1820
SELECT $1::text
1821
$_$;
1822

    
1823

    
1824
--
1825
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
1826
--
1827

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

    
1830

    
1831
--
1832
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
1833
--
1834

    
1835
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
1836
    LANGUAGE plpgsql STABLE
1837
    AS $_$
1838
DECLARE
1839
    type regtype;
1840
BEGIN
1841
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
1842
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
1843
    RETURN type;
1844
END;
1845
$_$;
1846

    
1847

    
1848
--
1849
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1850
--
1851

    
1852
CREATE AGGREGATE all_same(anyelement) (
1853
    SFUNC = all_same_transform,
1854
    STYPE = anyarray,
1855
    FINALFUNC = all_same_final
1856
);
1857

    
1858

    
1859
--
1860
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1861
--
1862

    
1863
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1864

    
1865

    
1866
--
1867
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1868
--
1869

    
1870
CREATE AGGREGATE join_strs(text, text) (
1871
    SFUNC = join_strs_transform,
1872
    STYPE = text
1873
);
1874

    
1875

    
1876
--
1877
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1878
--
1879

    
1880
CREATE OPERATOR -> (
1881
    PROCEDURE = map_get,
1882
    LEFTARG = regclass,
1883
    RIGHTARG = text
1884
);
1885

    
1886

    
1887
--
1888
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
1889
--
1890

    
1891
CREATE OPERATOR => (
1892
    PROCEDURE = hstore,
1893
    LEFTARG = text[],
1894
    RIGHTARG = anyelement
1895
);
1896

    
1897

    
1898
--
1899
-- Name: OPERATOR => (text[], anyelement); Type: COMMENT; Schema: util; Owner: -
1900
--
1901

    
1902
COMMENT ON OPERATOR => (text[], anyelement) IS 'usage: array[''key1'', ...]::text[] => ''value''';
1903

    
1904

    
1905
SET default_tablespace = '';
1906

    
1907
SET default_with_oids = false;
1908

    
1909
--
1910
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1911
--
1912

    
1913
CREATE TABLE map (
1914
    "from" text NOT NULL,
1915
    "to" text,
1916
    filter text,
1917
    notes text
1918
);
1919

    
1920

    
1921
--
1922
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1923
--
1924

    
1925

    
1926

    
1927
--
1928
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
1929
--
1930

    
1931
ALTER TABLE ONLY map
1932
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
1933

    
1934

    
1935
--
1936
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
1937
--
1938

    
1939
ALTER TABLE ONLY map
1940
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
1941

    
1942

    
1943
--
1944
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1945
--
1946

    
1947
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1948

    
1949

    
1950
--
1951
-- PostgreSQL database dump complete
1952
--
1953

    
(17-17/27)