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(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
225
--
226

    
227
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
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(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
236
--
237

    
238
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
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(text, text); Type: FUNCTION; Schema: util; Owner: -
247
--
248

    
249
CREATE FUNCTION _label(label text, value text) RETURNS text
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: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
528
--
529

    
530
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
531
    LANGUAGE sql STABLE STRICT
532
    AS $_$
533
SELECT util.derived_cols($1, $2)
534
UNION
535
SELECT util.eval2set($$
536
SELECT col
537
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
538
JOIN $$||$2||$$ ON "to" = col
539
WHERE "from" LIKE ':%'
540
$$, NULL::text)
541
$_$;
542

    
543

    
544
--
545
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
546
--
547

    
548
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS 'gets table_''s added columns (all the columns not in the original data)';
549

    
550

    
551
--
552
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
553
--
554

    
555
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
556
    LANGUAGE sql IMMUTABLE
557
    AS $_$
558
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
559
$_$;
560

    
561

    
562
--
563
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
564
--
565

    
566
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
567
    LANGUAGE plpgsql IMMUTABLE
568
    AS $$
569
DECLARE
570
	value_cmp         state%TYPE = ARRAY[value];
571
	state             state%TYPE = COALESCE(state, value_cmp);
572
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
573
BEGIN
574
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
575
END;
576
$$;
577

    
578

    
579
--
580
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
581
--
582

    
583
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
584
    LANGUAGE sql IMMUTABLE
585
    AS $_$
586
SELECT pg_catalog.array_fill($1, ARRAY[$2])
587
$_$;
588

    
589

    
590
--
591
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
592
--
593

    
594
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
595
    LANGUAGE sql IMMUTABLE
596
    AS $_$
597
SELECT util.array_length($1, 1)
598
$_$;
599

    
600

    
601
--
602
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
603
--
604

    
605
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
606
    LANGUAGE sql IMMUTABLE
607
    AS $_$
608
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
609
$_$;
610

    
611

    
612
--
613
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
614
--
615

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

    
618

    
619
--
620
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
621
--
622

    
623
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
624
    LANGUAGE sql STABLE STRICT
625
    AS $_$
626
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
627
$_$;
628

    
629

    
630
--
631
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
635
    LANGUAGE plpgsql STRICT
636
    AS $_$
637
BEGIN
638
    -- not yet clustered (ARRAY[] compares NULLs literally)
639
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
640
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
641
    END IF;
642
END;
643
$_$;
644

    
645

    
646
--
647
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
648
--
649

    
650
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
651

    
652

    
653
--
654
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
655
--
656

    
657
CREATE FUNCTION col__min(col col_ref) RETURNS integer
658
    LANGUAGE sql STABLE
659
    AS $_$
660
SELECT util.eval2val($$
661
SELECT $$||quote_ident($1.name)||$$
662
FROM $$||$1.table_||$$
663
ORDER BY $$||quote_ident($1.name)||$$ ASC
664
LIMIT 1
665
$$, NULL::integer)
666
$_$;
667

    
668

    
669
--
670
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
671
--
672

    
673
CREATE FUNCTION col_comment(col col_ref) RETURNS text
674
    LANGUAGE plpgsql STABLE STRICT
675
    AS $$
676
DECLARE
677
	comment text;
678
BEGIN
679
	SELECT description
680
	FROM pg_attribute
681
	LEFT JOIN pg_description ON objoid = attrelid
682
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
683
	WHERE attrelid = col.table_ AND attname = col.name
684
	INTO STRICT comment
685
	;
686
	RETURN comment;
687
EXCEPTION
688
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
689
END;
690
$$;
691

    
692

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

    
697
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
698
    LANGUAGE plpgsql STABLE STRICT
699
    AS $$
700
DECLARE
701
	default_sql text;
702
BEGIN
703
	SELECT adsrc
704
	FROM pg_attribute
705
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
706
	WHERE attrelid = col.table_ AND attname = col.name
707
	INTO STRICT default_sql
708
	;
709
	RETURN default_sql;
710
EXCEPTION
711
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
712
END;
713
$$;
714

    
715

    
716
--
717
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
718
--
719

    
720
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
721
    LANGUAGE sql STABLE
722
    AS $_$
723
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
724
$_$;
725

    
726

    
727
--
728
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
729
--
730

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

    
733

    
734
--
735
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
736
--
737

    
738
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
739
    LANGUAGE plpgsql STRICT
740
    AS $$
741
BEGIN
742
    PERFORM util.col_type(col);
743
    RETURN true;
744
EXCEPTION
745
    WHEN undefined_column THEN RETURN false;
746
END;
747
$$;
748

    
749

    
750
--
751
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
752
--
753

    
754
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
755
    LANGUAGE plpgsql STABLE STRICT
756
    AS $$
757
DECLARE
758
    prefix text := util.name(type)||'.';
759
BEGIN
760
    RETURN QUERY
761
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
762
        FROM util.col_names(type) f (name_);
763
END;
764
$$;
765

    
766

    
767
--
768
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
769
--
770

    
771
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
772
    LANGUAGE plpgsql STABLE STRICT
773
    AS $_$
774
BEGIN
775
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
776
END;
777
$_$;
778

    
779

    
780
--
781
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
782
--
783

    
784
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
785
    LANGUAGE sql STABLE STRICT
786
    AS $_$
787
SELECT attname::text
788
FROM pg_attribute
789
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
790
ORDER BY attnum
791
$_$;
792

    
793

    
794
--
795
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
796
--
797

    
798
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
799
    LANGUAGE plpgsql STABLE STRICT
800
    AS $$
801
DECLARE
802
    type regtype;
803
BEGIN
804
    SELECT atttypid FROM pg_attribute
805
    WHERE attrelid = col.table_ AND attname = col.name
806
    INTO STRICT type
807
    ;
808
    RETURN type;
809
EXCEPTION
810
    WHEN no_data_found THEN
811
        RAISE undefined_column USING MESSAGE =
812
            concat('undefined column: ', col.name);
813
END;
814
$$;
815

    
816

    
817
--
818
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
819
--
820

    
821
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
822
    LANGUAGE sql IMMUTABLE
823
    AS $_$
824
SELECT util.esc_name__append($2, $1)
825
$_$;
826

    
827

    
828
--
829
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
830
--
831

    
832
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
833
    LANGUAGE sql IMMUTABLE
834
    AS $_$
835
SELECT position($1 in $2) > 0 /*1-based offset*/
836
$_$;
837

    
838

    
839
--
840
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
841
--
842

    
843
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
844
    LANGUAGE plpgsql STRICT
845
    AS $$
846
BEGIN
847
    PERFORM util.eval(sql);
848
EXCEPTION
849
    WHEN duplicate_table  THEN NULL;
850
    WHEN duplicate_object THEN NULL; -- e.g. constraint
851
    WHEN duplicate_column THEN NULL;
852
    WHEN invalid_table_definition THEN
853
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
854
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
855
        END IF;
856
END;
857
$$;
858

    
859

    
860
--
861
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
862
--
863

    
864
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
865

    
866

    
867
--
868
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
869
--
870

    
871
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
872
    LANGUAGE sql STABLE STRICT
873
    AS $_$
874
SELECT util.eval2set($$
875
SELECT col
876
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
877
LEFT JOIN $$||$2||$$ ON "to" = col
878
WHERE "from" IS NULL
879
$$, NULL::text)
880
$_$;
881

    
882

    
883
--
884
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
885
--
886

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

    
889

    
890
--
891
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
892
--
893

    
894
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
895
    LANGUAGE sql STRICT
896
    AS $_$
897
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
898
$_$;
899

    
900

    
901
--
902
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
903
--
904

    
905
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
906

    
907

    
908
--
909
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
910
--
911

    
912
CREATE FUNCTION drop_column(col col_ref) RETURNS void
913
    LANGUAGE sql STRICT
914
    AS $_$
915
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
916
quote_ident($1.name))
917
$_$;
918

    
919

    
920
--
921
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
922
--
923

    
924
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
925

    
926

    
927
--
928
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
929
--
930

    
931
CREATE FUNCTION drop_table(table_ text) RETURNS void
932
    LANGUAGE sql STRICT
933
    AS $_$
934
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
935
$_$;
936

    
937

    
938
--
939
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
940
--
941

    
942
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
943

    
944

    
945
--
946
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
947
--
948

    
949
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
950
    LANGUAGE sql IMMUTABLE
951
    AS $_$
952
SELECT util.array_fill($1, 0)
953
$_$;
954

    
955

    
956
--
957
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
958
--
959

    
960
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)';
961

    
962

    
963
--
964
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
965
--
966

    
967
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
968
    LANGUAGE sql IMMUTABLE
969
    AS $_$
970
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
971
$_$;
972

    
973

    
974
--
975
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
976
--
977

    
978
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
979
    LANGUAGE sql IMMUTABLE
980
    AS $_$
981
SELECT regexp_replace($2, '("?)$', $1||'\1')
982
$_$;
983

    
984

    
985
--
986
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
987
--
988

    
989
CREATE FUNCTION eval(sql text) RETURNS void
990
    LANGUAGE plpgsql STRICT
991
    AS $$
992
BEGIN
993
    RAISE NOTICE '%', sql;
994
    EXECUTE sql;
995
END;
996
$$;
997

    
998

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

    
1003
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1004
    LANGUAGE plpgsql
1005
    AS $$
1006
BEGIN
1007
	RAISE NOTICE '%', sql;
1008
	RETURN QUERY EXECUTE sql;
1009
END;
1010
$$;
1011

    
1012

    
1013
--
1014
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1015
--
1016

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

    
1019

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

    
1024
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1025
    LANGUAGE plpgsql
1026
    AS $$
1027
DECLARE
1028
	ret_val ret_type_null%TYPE;
1029
BEGIN
1030
	RAISE NOTICE '%', sql;
1031
	EXECUTE sql INTO STRICT ret_val;
1032
	RETURN ret_val;
1033
END;
1034
$$;
1035

    
1036

    
1037
--
1038
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1039
--
1040

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

    
1043

    
1044
--
1045
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047

    
1048
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1049
    LANGUAGE sql
1050
    AS $_$
1051
SELECT util.eval2val($$SELECT $$||$1, $2)
1052
$_$;
1053

    
1054

    
1055
--
1056
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1057
--
1058

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

    
1061

    
1062
--
1063
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1064
--
1065

    
1066
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1067
    LANGUAGE sql
1068
    AS $_$
1069
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1070
$_$;
1071

    
1072

    
1073
--
1074
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1075
--
1076

    
1077
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1078
ret_type_null: NULL::ret_type';
1079

    
1080

    
1081
--
1082
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1083
--
1084

    
1085
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1086
    LANGUAGE sql STABLE STRICT
1087
    AS $_$
1088
SELECT col_name
1089
FROM unnest($2) s (col_name)
1090
WHERE util.col_exists(($1, col_name))
1091
$_$;
1092

    
1093

    
1094
--
1095
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1096
--
1097

    
1098
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1099
    LANGUAGE sql IMMUTABLE
1100
    AS $_$
1101
-- STRICT handles NULLs, so that the array will always be a value
1102
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1103
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1104
) END
1105
$_$;
1106

    
1107

    
1108
--
1109
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1110
--
1111

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

    
1114

    
1115
--
1116
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1117
--
1118

    
1119
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1120
    LANGUAGE plpgsql STRICT
1121
    AS $_$
1122
DECLARE
1123
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1124
$$||query;
1125
BEGIN
1126
	EXECUTE mk_view;
1127
EXCEPTION
1128
WHEN invalid_table_definition THEN
1129
	IF SQLERRM = 'cannot drop columns from view'
1130
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1131
	THEN
1132
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1133
		EXECUTE mk_view;
1134
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1135
	END IF;
1136
END;
1137
$_$;
1138

    
1139

    
1140
--
1141
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1142
--
1143

    
1144
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1145

    
1146

    
1147
--
1148
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1149
--
1150

    
1151
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1152
    LANGUAGE sql IMMUTABLE
1153
    AS $_$
1154
SELECT substring($2 for length($1)) = $1
1155
$_$;
1156

    
1157

    
1158
--
1159
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1160
--
1161

    
1162
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1163
    LANGUAGE sql IMMUTABLE
1164
    AS $_$
1165
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1166
$_$;
1167

    
1168

    
1169
--
1170
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1171
--
1172

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

    
1175

    
1176
--
1177
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1178
--
1179

    
1180
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1181
    LANGUAGE sql STABLE STRICT
1182
    AS $_$
1183
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1184
$_$;
1185

    
1186

    
1187
--
1188
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1189
--
1190

    
1191
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1192
    LANGUAGE sql IMMUTABLE
1193
    AS $_$
1194
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1195
$_$;
1196

    
1197

    
1198
--
1199
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1200
--
1201

    
1202
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1203
    LANGUAGE sql IMMUTABLE
1204
    AS $_$
1205
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1206
$_$;
1207

    
1208

    
1209
--
1210
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1211
--
1212

    
1213
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1214
    LANGUAGE sql IMMUTABLE STRICT
1215
    AS $_$
1216
SELECT $1 || $3 || $2
1217
$_$;
1218

    
1219

    
1220
--
1221
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1222
--
1223

    
1224
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1225
    LANGUAGE sql IMMUTABLE
1226
    AS $_$
1227
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1228
$_$;
1229

    
1230

    
1231
--
1232
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1233
--
1234

    
1235
CREATE FUNCTION map_filter_insert() RETURNS trigger
1236
    LANGUAGE plpgsql
1237
    AS $$
1238
BEGIN
1239
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1240
	RETURN new;
1241
END;
1242
$$;
1243

    
1244

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

    
1249
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1250
    LANGUAGE plpgsql STABLE STRICT
1251
    AS $_$
1252
DECLARE
1253
    value text;
1254
BEGIN
1255
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1256
        INTO value USING key;
1257
    RETURN value;
1258
END;
1259
$_$;
1260

    
1261

    
1262
--
1263
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1264
--
1265

    
1266
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1267
    LANGUAGE sql IMMUTABLE
1268
    AS $_$
1269
SELECT util._map(util.nulls_map($1), $2)
1270
$_$;
1271

    
1272

    
1273
--
1274
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1275
--
1276

    
1277
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].
1278

    
1279
[1] inlining of function calls, which is different from constant folding
1280
[2] _map()''s profiling query
1281
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1282
and map_nulls()''s profiling query
1283
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1284
both take ~920 ms.
1285
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.';
1286

    
1287

    
1288
--
1289
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1290
--
1291

    
1292
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1293
    LANGUAGE plpgsql STABLE STRICT
1294
    AS $_$
1295
BEGIN
1296
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1297
END;
1298
$_$;
1299

    
1300

    
1301
--
1302
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1303
--
1304

    
1305
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1306
    LANGUAGE sql STRICT
1307
    AS $_$
1308
SELECT util.create_if_not_exists($$
1309
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1310
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1311
||quote_literal($2)||$$;
1312
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1313
$$)
1314
$_$;
1315

    
1316

    
1317
--
1318
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1319
--
1320

    
1321
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1322

    
1323

    
1324
--
1325
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327

    
1328
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1329
    LANGUAGE plpgsql STRICT
1330
    AS $_$
1331
DECLARE
1332
    type regtype = util.typeof(expr, col.table_::text::regtype);
1333
    col_name_sql text = quote_ident(col.name);
1334
BEGIN
1335
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1336
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1337
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1338
$$||expr||$$;
1339
$$);
1340
END;
1341
$_$;
1342

    
1343

    
1344
--
1345
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1346
--
1347

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

    
1350

    
1351
--
1352
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1353
--
1354

    
1355
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1356
    LANGUAGE sql STRICT
1357
    AS $_$
1358
SELECT util.create_if_not_exists($$
1359
CREATE TABLE $$||$1||$$
1360
(
1361
    LIKE util.map INCLUDING ALL
1362
);
1363

    
1364
CREATE TRIGGER map_filter_insert
1365
  BEFORE INSERT
1366
  ON $$||$1||$$
1367
  FOR EACH ROW
1368
  EXECUTE PROCEDURE util.map_filter_insert();
1369
$$)
1370
$_$;
1371

    
1372

    
1373
--
1374
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1375
--
1376

    
1377
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1378
    LANGUAGE sql STRICT
1379
    AS $_$
1380
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1381
$_$;
1382

    
1383

    
1384
--
1385
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1386
--
1387

    
1388
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1389

    
1390

    
1391
--
1392
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1393
--
1394

    
1395
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1396
    LANGUAGE plpgsql STRICT
1397
    AS $_$
1398
DECLARE
1399
	view_qual_name text = util.qual_name(view_);
1400
BEGIN
1401
	EXECUTE $$
1402
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1403
  RETURNS SETOF $$||view_||$$ AS
1404
$BODY1$
1405
SELECT * FROM $$||view_qual_name||$$
1406
ORDER BY sort_col
1407
LIMIT $1 OFFSET $2
1408
$BODY1$
1409
  LANGUAGE sql STABLE
1410
  COST 100
1411
  ROWS 1000
1412
$$;
1413
	
1414
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1415
END;
1416
$_$;
1417

    
1418

    
1419
--
1420
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1421
--
1422

    
1423
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1424
    LANGUAGE plpgsql STRICT
1425
    AS $_$
1426
DECLARE
1427
	view_qual_name text = util.qual_name(view_);
1428
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1429
BEGIN
1430
	EXECUTE $$
1431
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1432
  RETURNS integer AS
1433
$BODY1$
1434
SELECT $$||quote_ident(row_num_col)||$$
1435
FROM $$||view_qual_name||$$
1436
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1437
LIMIT 1
1438
$BODY1$
1439
  LANGUAGE sql STABLE
1440
  COST 100;
1441
$$;
1442
	
1443
	EXECUTE $$
1444
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1445
  RETURNS SETOF $$||view_||$$ AS
1446
$BODY1$
1447
SELECT * FROM $$||view_qual_name||$$
1448
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1449
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1450
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1451
ORDER BY $$||quote_ident(row_num_col)||$$
1452
$BODY1$
1453
  LANGUAGE sql STABLE
1454
  COST 100
1455
  ROWS 1000
1456
$$;
1457
	
1458
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1459
END;
1460
$_$;
1461

    
1462

    
1463
--
1464
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1465
--
1466

    
1467
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1468
    LANGUAGE plpgsql STRICT
1469
    AS $_$
1470
DECLARE
1471
	view_qual_name text = util.qual_name(view_);
1472
BEGIN
1473
	EXECUTE $$
1474
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1475
  RETURNS SETOF $$||view_||$$
1476
  SET enable_sort TO 'off'
1477
  AS
1478
$BODY1$
1479
SELECT * FROM $$||view_qual_name||$$($2, $3)
1480
$BODY1$
1481
  LANGUAGE sql STABLE
1482
  COST 100
1483
  ROWS 1000
1484
;
1485
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1486
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1487
If you want to run EXPLAIN and get expanded output, use the regular subset
1488
function instead. (When a config param is set on a function, EXPLAIN produces
1489
just a function scan.)
1490
';
1491
$$;
1492
END;
1493
$_$;
1494

    
1495

    
1496
--
1497
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1498
--
1499

    
1500
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS 'creates subset function which turns off enable_sort';
1501

    
1502

    
1503
--
1504
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1505
--
1506

    
1507
CREATE FUNCTION name(type regtype) RETURNS text
1508
    LANGUAGE sql STABLE STRICT
1509
    AS $_$
1510
SELECT typname::text FROM pg_type WHERE oid = $1
1511
$_$;
1512

    
1513

    
1514
--
1515
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1516
--
1517

    
1518
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1519
    LANGUAGE sql IMMUTABLE
1520
    AS $_$
1521
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1522
$_$;
1523

    
1524

    
1525
--
1526
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1527
--
1528

    
1529
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1530
    LANGUAGE sql IMMUTABLE
1531
    AS $_$
1532
SELECT $1 IS NOT NULL
1533
$_$;
1534

    
1535

    
1536
--
1537
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1538
--
1539

    
1540
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1541
    LANGUAGE sql IMMUTABLE
1542
    AS $_$
1543
SELECT util.hstore($1, NULL) || '*=>*'
1544
$_$;
1545

    
1546

    
1547
--
1548
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1549
--
1550

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

    
1553

    
1554
--
1555
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1556
--
1557

    
1558
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1559
    LANGUAGE sql IMMUTABLE
1560
    AS $_$
1561
SELECT $2 + COALESCE($1, 0)
1562
$_$;
1563

    
1564

    
1565
--
1566
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1567
--
1568

    
1569
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1570
    LANGUAGE sql STABLE
1571
    AS $_$
1572
SELECT util.type_qual_name($1::text::regtype)
1573
$_$;
1574

    
1575

    
1576
--
1577
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1578
--
1579

    
1580
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1581
    LANGUAGE plpgsql IMMUTABLE STRICT
1582
    AS $$
1583
BEGIN
1584
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1585
END;
1586
$$;
1587

    
1588

    
1589
--
1590
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1591
--
1592

    
1593
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1594
    LANGUAGE sql STRICT
1595
    AS $_$
1596
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1597
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1598
FROM util.col_names($1::text::regtype) f (name);
1599
SELECT NULL::void; -- don't fold away functions called in previous query
1600
$_$;
1601

    
1602

    
1603
--
1604
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1605
--
1606

    
1607
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1608

    
1609

    
1610
--
1611
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1612
--
1613

    
1614
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1615
    LANGUAGE sql STRICT
1616
    AS $_$
1617
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1618
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1619
SELECT util.set_col_names($1, $2);
1620
$_$;
1621

    
1622

    
1623
--
1624
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1625
--
1626

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

    
1630

    
1631
--
1632
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1633
--
1634

    
1635
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1636
    LANGUAGE sql STRICT
1637
    AS $_$
1638
SELECT util.drop_table($1);
1639
SELECT util.mk_map_table($1);
1640
$_$;
1641

    
1642

    
1643
--
1644
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1645
--
1646

    
1647
CREATE FUNCTION schema(type regtype) RETURNS text
1648
    LANGUAGE sql STABLE
1649
    AS $_$
1650
SELECT nspname::text
1651
FROM pg_type
1652
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1653
WHERE pg_type.oid = $1
1654
$_$;
1655

    
1656

    
1657
--
1658
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660

    
1661
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1662
    LANGUAGE sql STABLE
1663
    AS $_$
1664
SELECT util.schema(pg_typeof($1))
1665
$_$;
1666

    
1667

    
1668
--
1669
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1670
--
1671

    
1672
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1673
    LANGUAGE sql STABLE
1674
    AS $_$
1675
SELECT quote_ident(util.schema($1))
1676
$_$;
1677

    
1678

    
1679
--
1680
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1681
--
1682

    
1683
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1684
    LANGUAGE sql STRICT
1685
    AS $_$
1686
SELECT util.eval(
1687
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1688
$_$;
1689

    
1690

    
1691
--
1692
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1693
--
1694

    
1695
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1696
    LANGUAGE plpgsql STRICT
1697
    AS $_$
1698
DECLARE
1699
    old text[] = ARRAY(SELECT util.col_names(table_));
1700
    new text[] = ARRAY(SELECT util.map_values(names));
1701
BEGIN
1702
    old = old[1:array_length(new, 1)]; -- truncate to same length
1703
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1704
||$$ TO $$||quote_ident(value))
1705
    FROM each(hstore(old, new))
1706
    WHERE value != key -- not same name
1707
    ;
1708
END;
1709
$_$;
1710

    
1711

    
1712
--
1713
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1714
--
1715

    
1716
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1717

    
1718

    
1719
--
1720
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1721
--
1722

    
1723
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1724
    LANGUAGE plpgsql STRICT
1725
    AS $_$
1726
DECLARE
1727
	row_ util.map;
1728
BEGIN
1729
	-- rename any metadata cols rather than re-adding them with new names
1730
	BEGIN
1731
		PERFORM util.set_col_names(table_, names);
1732
	EXCEPTION
1733
		WHEN array_subscript_error THEN -- selective suppress
1734
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
1735
				-- metadata cols not yet added
1736
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
1737
			END IF;
1738
	END;
1739
	
1740
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1741
	LOOP
1742
		PERFORM util.mk_const_col((table_, row_."to"),
1743
			substring(row_."from" from 2));
1744
	END LOOP;
1745
	
1746
	PERFORM util.set_col_names(table_, names);
1747
END;
1748
$_$;
1749

    
1750

    
1751
--
1752
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1753
--
1754

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

    
1758

    
1759
--
1760
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1761
--
1762

    
1763
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1764
    LANGUAGE plpgsql STRICT
1765
    AS $_$
1766
DECLARE
1767
    sql text = $$ALTER TABLE $$||table_||$$
1768
$$||NULLIF(array_to_string(ARRAY(
1769
    SELECT
1770
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1771
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1772
    FROM
1773
    (
1774
        SELECT
1775
          quote_ident(col_name) AS col_name_sql
1776
        , util.col_type((table_, col_name)) AS curr_type
1777
        , type AS target_type
1778
        FROM unnest(col_casts)
1779
    ) s
1780
    WHERE curr_type != target_type
1781
), '
1782
, '), '');
1783
BEGIN
1784
    RAISE NOTICE '%', sql;
1785
    EXECUTE COALESCE(sql, '');
1786
END;
1787
$_$;
1788

    
1789

    
1790
--
1791
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1792
--
1793

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

    
1796

    
1797
--
1798
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1799
--
1800

    
1801
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1802
    LANGUAGE plpgsql STABLE STRICT
1803
    AS $_$
1804
DECLARE
1805
    hstore hstore;
1806
BEGIN
1807
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1808
        table_||$$))$$ INTO STRICT hstore;
1809
    RETURN hstore;
1810
END;
1811
$_$;
1812

    
1813

    
1814
--
1815
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1816
--
1817

    
1818
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1819
    LANGUAGE sql STABLE STRICT
1820
    AS $_$
1821
SELECT COUNT(*) > 0 FROM pg_constraint
1822
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1823
$_$;
1824

    
1825

    
1826
--
1827
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1828
--
1829

    
1830
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';
1831

    
1832

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

    
1837
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1838
    LANGUAGE sql STRICT
1839
    AS $_$
1840
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1841
||quote_ident($2)||$$ CHECK (true)$$)
1842
$_$;
1843

    
1844

    
1845
--
1846
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1847
--
1848

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

    
1852

    
1853
--
1854
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1858
    LANGUAGE sql STABLE STRICT
1859
    AS $_$
1860
SELECT util.table_flag__get($1, 'nulls_mapped')
1861
$_$;
1862

    
1863

    
1864
--
1865
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1866
--
1867

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

    
1870

    
1871
--
1872
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1873
--
1874

    
1875
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1876
    LANGUAGE sql STRICT
1877
    AS $_$
1878
SELECT util.table_flag__set($1, 'nulls_mapped')
1879
$_$;
1880

    
1881

    
1882
--
1883
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1884
--
1885

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

    
1889

    
1890
--
1891
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1892
--
1893

    
1894
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1895
    LANGUAGE sql STABLE STRICT
1896
    AS $_$
1897
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1898
$_$;
1899

    
1900

    
1901
--
1902
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1903
--
1904

    
1905
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1906
    LANGUAGE plpgsql STRICT
1907
    AS $_$
1908
DECLARE
1909
    row record;
1910
BEGIN
1911
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1912
    LOOP
1913
        IF row.global_name != row.name THEN
1914
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1915
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1916
        END IF;
1917
    END LOOP;
1918
END;
1919
$_$;
1920

    
1921

    
1922
--
1923
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1924
--
1925

    
1926
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1927

    
1928

    
1929
--
1930
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1931
--
1932

    
1933
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
1934
    LANGUAGE sql STRICT
1935
    AS $_$
1936
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
1937
SELECT NULL::void; -- don't fold away functions called in previous query
1938
$_$;
1939

    
1940

    
1941
--
1942
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1943
--
1944

    
1945
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS 'trims table_ to include only columns in the original data.
1946
idempotent.';
1947

    
1948

    
1949
--
1950
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1951
--
1952

    
1953
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1954
    LANGUAGE plpgsql STRICT
1955
    AS $_$
1956
BEGIN
1957
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1958
END;
1959
$_$;
1960

    
1961

    
1962
--
1963
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1964
--
1965

    
1966
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1967

    
1968

    
1969
--
1970
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1971
--
1972

    
1973
CREATE FUNCTION try_create(sql text) RETURNS void
1974
    LANGUAGE plpgsql STRICT
1975
    AS $$
1976
BEGIN
1977
    PERFORM util.eval(sql);
1978
EXCEPTION
1979
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1980
    WHEN undefined_column THEN NULL;
1981
    WHEN duplicate_column THEN NULL;
1982
END;
1983
$$;
1984

    
1985

    
1986
--
1987
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1988
--
1989

    
1990
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1991

    
1992

    
1993
--
1994
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1995
--
1996

    
1997
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1998
    LANGUAGE sql STRICT
1999
    AS $_$
2000
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2001
$_$;
2002

    
2003

    
2004
--
2005
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2006
--
2007

    
2008
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
2009

    
2010

    
2011
--
2012
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2013
--
2014

    
2015
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2016
    LANGUAGE sql IMMUTABLE
2017
    AS $_$
2018
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2019
$_$;
2020

    
2021

    
2022
--
2023
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2024
--
2025

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

    
2028

    
2029
--
2030
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2031
--
2032

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

    
2040

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

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

    
2047

    
2048
--
2049
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2050
--
2051

    
2052
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2053
    LANGUAGE plpgsql STABLE
2054
    AS $_$
2055
DECLARE
2056
    type regtype;
2057
BEGIN
2058
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2059
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2060
    RETURN type;
2061
END;
2062
$_$;
2063

    
2064

    
2065
--
2066
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2067
--
2068

    
2069
CREATE AGGREGATE all_same(anyelement) (
2070
    SFUNC = all_same_transform,
2071
    STYPE = anyarray,
2072
    FINALFUNC = all_same_final
2073
);
2074

    
2075

    
2076
--
2077
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2078
--
2079

    
2080
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2081

    
2082

    
2083
--
2084
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2085
--
2086

    
2087
CREATE AGGREGATE join_strs(text, text) (
2088
    SFUNC = join_strs_transform,
2089
    STYPE = text
2090
);
2091

    
2092

    
2093
--
2094
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2095
--
2096

    
2097
CREATE OPERATOR -> (
2098
    PROCEDURE = map_get,
2099
    LEFTARG = regclass,
2100
    RIGHTARG = text
2101
);
2102

    
2103

    
2104
--
2105
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2106
--
2107

    
2108
CREATE OPERATOR => (
2109
    PROCEDURE = hstore,
2110
    LEFTARG = text[],
2111
    RIGHTARG = text
2112
);
2113

    
2114

    
2115
--
2116
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2117
--
2118

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

    
2121

    
2122
--
2123
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2124
--
2125

    
2126
CREATE OPERATOR ?*>= (
2127
    PROCEDURE = is_populated_more_often_than,
2128
    LEFTARG = anyelement,
2129
    RIGHTARG = anyelement
2130
);
2131

    
2132

    
2133
--
2134
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2135
--
2136

    
2137
CREATE OPERATOR ?>= (
2138
    PROCEDURE = is_more_complete_than,
2139
    LEFTARG = anyelement,
2140
    RIGHTARG = anyelement
2141
);
2142

    
2143

    
2144
--
2145
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2146
--
2147

    
2148
CREATE OPERATOR ||% (
2149
    PROCEDURE = concat_esc,
2150
    LEFTARG = text,
2151
    RIGHTARG = text
2152
);
2153

    
2154

    
2155
--
2156
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2157
--
2158

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

    
2161

    
2162
SET default_tablespace = '';
2163

    
2164
SET default_with_oids = false;
2165

    
2166
--
2167
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2168
--
2169

    
2170
CREATE TABLE map (
2171
    "from" text NOT NULL,
2172
    "to" text,
2173
    filter text,
2174
    notes text
2175
);
2176

    
2177

    
2178
--
2179
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2180
--
2181

    
2182

    
2183

    
2184
--
2185
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2186
--
2187

    
2188
ALTER TABLE ONLY map
2189
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2190

    
2191

    
2192
--
2193
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2194
--
2195

    
2196
ALTER TABLE ONLY map
2197
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2198

    
2199

    
2200
--
2201
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2202
--
2203

    
2204
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2205

    
2206

    
2207
--
2208
-- PostgreSQL database dump complete
2209
--
2210

    
(19-19/29)