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: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1149
--
1150

    
1151
CREATE FUNCTION grants_users() RETURNS SETOF text
1152
    LANGUAGE sql IMMUTABLE
1153
    AS $$
1154
VALUES ('bien_read'), ('public_')
1155
$$;
1156

    
1157

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

    
1162
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1163
    LANGUAGE sql IMMUTABLE
1164
    AS $_$
1165
SELECT substring($2 for length($1)) = $1
1166
$_$;
1167

    
1168

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

    
1173
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1174
    LANGUAGE sql IMMUTABLE
1175
    AS $_$
1176
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1177
$_$;
1178

    
1179

    
1180
--
1181
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1182
--
1183

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

    
1186

    
1187
--
1188
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1189
--
1190

    
1191
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1192
    LANGUAGE sql STABLE STRICT
1193
    AS $_$
1194
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1195
$_$;
1196

    
1197

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

    
1202
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1203
    LANGUAGE sql IMMUTABLE
1204
    AS $_$
1205
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1206
$_$;
1207

    
1208

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

    
1213
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1214
    LANGUAGE sql IMMUTABLE
1215
    AS $_$
1216
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1217
$_$;
1218

    
1219

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

    
1224
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1225
    LANGUAGE sql IMMUTABLE STRICT
1226
    AS $_$
1227
SELECT $1 || $3 || $2
1228
$_$;
1229

    
1230

    
1231
--
1232
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1233
--
1234

    
1235
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1236
    LANGUAGE sql IMMUTABLE
1237
    AS $_$
1238
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1239
$_$;
1240

    
1241

    
1242
--
1243
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1244
--
1245

    
1246
CREATE FUNCTION map_filter_insert() RETURNS trigger
1247
    LANGUAGE plpgsql
1248
    AS $$
1249
BEGIN
1250
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1251
	RETURN new;
1252
END;
1253
$$;
1254

    
1255

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

    
1260
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1261
    LANGUAGE plpgsql STABLE STRICT
1262
    AS $_$
1263
DECLARE
1264
    value text;
1265
BEGIN
1266
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1267
        INTO value USING key;
1268
    RETURN value;
1269
END;
1270
$_$;
1271

    
1272

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

    
1277
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1278
    LANGUAGE sql IMMUTABLE
1279
    AS $_$
1280
SELECT util._map(util.nulls_map($1), $2)
1281
$_$;
1282

    
1283

    
1284
--
1285
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1286
--
1287

    
1288
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].
1289

    
1290
[1] inlining of function calls, which is different from constant folding
1291
[2] _map()''s profiling query
1292
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1293
and map_nulls()''s profiling query
1294
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1295
both take ~920 ms.
1296
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.';
1297

    
1298

    
1299
--
1300
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1301
--
1302

    
1303
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1304
    LANGUAGE plpgsql STABLE STRICT
1305
    AS $_$
1306
BEGIN
1307
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1308
END;
1309
$_$;
1310

    
1311

    
1312
--
1313
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1314
--
1315

    
1316
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1317
    LANGUAGE sql STRICT
1318
    AS $_$
1319
SELECT util.create_if_not_exists($$
1320
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1321
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1322
||quote_literal($2)||$$;
1323
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1324
$$)
1325
$_$;
1326

    
1327

    
1328
--
1329
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1330
--
1331

    
1332
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1333

    
1334

    
1335
--
1336
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1337
--
1338

    
1339
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1340
    LANGUAGE plpgsql STRICT
1341
    AS $_$
1342
DECLARE
1343
    type regtype = util.typeof(expr, col.table_::text::regtype);
1344
    col_name_sql text = quote_ident(col.name);
1345
BEGIN
1346
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1347
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1348
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1349
$$||expr||$$;
1350
$$);
1351
END;
1352
$_$;
1353

    
1354

    
1355
--
1356
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1357
--
1358

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

    
1361

    
1362
--
1363
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1364
--
1365

    
1366
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1367
    LANGUAGE sql STRICT
1368
    AS $_$
1369
SELECT util.create_if_not_exists($$
1370
CREATE TABLE $$||$1||$$
1371
(
1372
    LIKE util.map INCLUDING ALL
1373
);
1374

    
1375
CREATE TRIGGER map_filter_insert
1376
  BEFORE INSERT
1377
  ON $$||$1||$$
1378
  FOR EACH ROW
1379
  EXECUTE PROCEDURE util.map_filter_insert();
1380
$$)
1381
$_$;
1382

    
1383

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

    
1388
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1389
    LANGUAGE sql STRICT
1390
    AS $_$
1391
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1392
$_$;
1393

    
1394

    
1395
--
1396
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1397
--
1398

    
1399
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1400

    
1401

    
1402
--
1403
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1404
--
1405

    
1406
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1407
    LANGUAGE plpgsql STRICT
1408
    AS $_$
1409
DECLARE
1410
	view_qual_name text = util.qual_name(view_);
1411
BEGIN
1412
	EXECUTE $$
1413
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1414
  RETURNS SETOF $$||view_||$$ AS
1415
$BODY1$
1416
SELECT * FROM $$||view_qual_name||$$
1417
ORDER BY sort_col
1418
LIMIT $1 OFFSET $2
1419
$BODY1$
1420
  LANGUAGE sql STABLE
1421
  COST 100
1422
  ROWS 1000
1423
$$;
1424
	
1425
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1426
END;
1427
$_$;
1428

    
1429

    
1430
--
1431
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1432
--
1433

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

    
1473

    
1474
--
1475
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1476
--
1477

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

    
1506

    
1507
--
1508
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1509
--
1510

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

    
1513

    
1514
--
1515
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1516
--
1517

    
1518
CREATE FUNCTION name(type regtype) RETURNS text
1519
    LANGUAGE sql STABLE STRICT
1520
    AS $_$
1521
SELECT typname::text FROM pg_type WHERE oid = $1
1522
$_$;
1523

    
1524

    
1525
--
1526
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1527
--
1528

    
1529
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1530
    LANGUAGE sql IMMUTABLE
1531
    AS $_$
1532
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1533
$_$;
1534

    
1535

    
1536
--
1537
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1538
--
1539

    
1540
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1541
    LANGUAGE sql IMMUTABLE
1542
    AS $_$
1543
SELECT $1 IS NOT NULL
1544
$_$;
1545

    
1546

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

    
1551
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1552
    LANGUAGE sql IMMUTABLE
1553
    AS $_$
1554
SELECT util.hstore($1, NULL) || '*=>*'
1555
$_$;
1556

    
1557

    
1558
--
1559
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1560
--
1561

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

    
1564

    
1565
--
1566
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1567
--
1568

    
1569
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1570
    LANGUAGE sql IMMUTABLE
1571
    AS $_$
1572
SELECT $2 + COALESCE($1, 0)
1573
$_$;
1574

    
1575

    
1576
--
1577
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1578
--
1579

    
1580
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1581
    LANGUAGE sql STABLE
1582
    AS $_$
1583
SELECT util.type_qual_name($1::text::regtype)
1584
$_$;
1585

    
1586

    
1587
--
1588
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1589
--
1590

    
1591
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1592
    LANGUAGE plpgsql IMMUTABLE STRICT
1593
    AS $$
1594
BEGIN
1595
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1596
END;
1597
$$;
1598

    
1599

    
1600
--
1601
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
1602
--
1603

    
1604
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
1605
    LANGUAGE sql IMMUTABLE
1606
    AS $_$
1607
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
1608
$_$;
1609

    
1610

    
1611
--
1612
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1613
--
1614

    
1615
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1616
    LANGUAGE sql STRICT
1617
    AS $_$
1618
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1619
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1620
FROM util.col_names($1::text::regtype) f (name);
1621
SELECT NULL::void; -- don't fold away functions called in previous query
1622
$_$;
1623

    
1624

    
1625
--
1626
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1627
--
1628

    
1629
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1630

    
1631

    
1632
--
1633
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1634
--
1635

    
1636
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1637
    LANGUAGE sql STRICT
1638
    AS $_$
1639
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1640
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1641
SELECT util.set_col_names($1, $2);
1642
$_$;
1643

    
1644

    
1645
--
1646
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1647
--
1648

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

    
1652

    
1653
--
1654
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1655
--
1656

    
1657
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1658
    LANGUAGE sql STRICT
1659
    AS $_$
1660
SELECT util.drop_table($1);
1661
SELECT util.mk_map_table($1);
1662
$_$;
1663

    
1664

    
1665
--
1666
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1667
--
1668

    
1669
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
1670
    LANGUAGE plpgsql STRICT
1671
    AS $_$
1672
DECLARE
1673
	result text = NULL;
1674
BEGIN
1675
	BEGIN
1676
		result = util.show_create_view(view_);
1677
		PERFORM util.eval($$DROP VIEW $$||view_);
1678
	EXCEPTION
1679
		WHEN undefined_table THEN NULL;
1680
	END;
1681
	RETURN result;
1682
END;
1683
$_$;
1684

    
1685

    
1686
--
1687
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1688
--
1689

    
1690
CREATE FUNCTION schema(type regtype) RETURNS text
1691
    LANGUAGE sql STABLE
1692
    AS $_$
1693
SELECT nspname::text
1694
FROM pg_type
1695
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1696
WHERE pg_type.oid = $1
1697
$_$;
1698

    
1699

    
1700
--
1701
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1702
--
1703

    
1704
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1705
    LANGUAGE sql STABLE
1706
    AS $_$
1707
SELECT util.schema(pg_typeof($1))
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1713
--
1714

    
1715
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1716
    LANGUAGE sql STABLE
1717
    AS $_$
1718
SELECT quote_ident(util.schema($1))
1719
$_$;
1720

    
1721

    
1722
--
1723
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1724
--
1725

    
1726
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1727
    LANGUAGE sql STRICT
1728
    AS $_$
1729
SELECT util.eval(
1730
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1731
$_$;
1732

    
1733

    
1734
--
1735
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1736
--
1737

    
1738
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1739
    LANGUAGE plpgsql STRICT
1740
    AS $_$
1741
DECLARE
1742
    old text[] = ARRAY(SELECT util.col_names(table_));
1743
    new text[] = ARRAY(SELECT util.map_values(names));
1744
BEGIN
1745
    old = old[1:array_length(new, 1)]; -- truncate to same length
1746
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1747
||$$ TO $$||quote_ident(value))
1748
    FROM each(hstore(old, new))
1749
    WHERE value != key -- not same name
1750
    ;
1751
END;
1752
$_$;
1753

    
1754

    
1755
--
1756
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1757
--
1758

    
1759
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1760

    
1761

    
1762
--
1763
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1764
--
1765

    
1766
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1767
    LANGUAGE plpgsql STRICT
1768
    AS $_$
1769
DECLARE
1770
	row_ util.map;
1771
BEGIN
1772
	-- rename any metadata cols rather than re-adding them with new names
1773
	BEGIN
1774
		PERFORM util.set_col_names(table_, names);
1775
	EXCEPTION
1776
		WHEN array_subscript_error THEN -- selective suppress
1777
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
1778
				-- metadata cols not yet added
1779
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
1780
			END IF;
1781
	END;
1782
	
1783
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1784
	LOOP
1785
		PERFORM util.mk_const_col((table_, row_."to"),
1786
			substring(row_."from" from 2));
1787
	END LOOP;
1788
	
1789
	PERFORM util.set_col_names(table_, names);
1790
END;
1791
$_$;
1792

    
1793

    
1794
--
1795
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1796
--
1797

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

    
1801

    
1802
--
1803
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1804
--
1805

    
1806
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1807
    LANGUAGE plpgsql STRICT
1808
    AS $_$
1809
DECLARE
1810
    sql text = $$ALTER TABLE $$||table_||$$
1811
$$||NULLIF(array_to_string(ARRAY(
1812
    SELECT
1813
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1814
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1815
    FROM
1816
    (
1817
        SELECT
1818
          quote_ident(col_name) AS col_name_sql
1819
        , util.col_type((table_, col_name)) AS curr_type
1820
        , type AS target_type
1821
        FROM unnest(col_casts)
1822
    ) s
1823
    WHERE curr_type != target_type
1824
), '
1825
, '), '');
1826
BEGIN
1827
    RAISE NOTICE '%', sql;
1828
    EXECUTE COALESCE(sql, '');
1829
END;
1830
$_$;
1831

    
1832

    
1833
--
1834
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1835
--
1836

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

    
1839

    
1840
--
1841
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1842
--
1843

    
1844
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
1845
    LANGUAGE sql STABLE
1846
    AS $_$
1847
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
1848
$$||util.show_grants_for($1)
1849
$_$;
1850

    
1851

    
1852
--
1853
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
1854
--
1855

    
1856
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
1857
    LANGUAGE sql STABLE
1858
    AS $_$
1859
SELECT concat(cmd)
1860
FROM
1861
(
1862
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
1863
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
1864
$$ ELSE '' END) AS cmd
1865
	FROM util.grants_users() f (user_)
1866
) s
1867
$_$;
1868

    
1869

    
1870
--
1871
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1872
--
1873

    
1874
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1875
    LANGUAGE plpgsql STABLE STRICT
1876
    AS $_$
1877
DECLARE
1878
    hstore hstore;
1879
BEGIN
1880
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1881
        table_||$$))$$ INTO STRICT hstore;
1882
    RETURN hstore;
1883
END;
1884
$_$;
1885

    
1886

    
1887
--
1888
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1889
--
1890

    
1891
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1892
    LANGUAGE sql STABLE STRICT
1893
    AS $_$
1894
SELECT COUNT(*) > 0 FROM pg_constraint
1895
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1896
$_$;
1897

    
1898

    
1899
--
1900
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1901
--
1902

    
1903
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';
1904

    
1905

    
1906
--
1907
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1908
--
1909

    
1910
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1911
    LANGUAGE sql STRICT
1912
    AS $_$
1913
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1914
||quote_ident($2)||$$ CHECK (true)$$)
1915
$_$;
1916

    
1917

    
1918
--
1919
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1920
--
1921

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

    
1925

    
1926
--
1927
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1928
--
1929

    
1930
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1931
    LANGUAGE sql STABLE STRICT
1932
    AS $_$
1933
SELECT util.table_flag__get($1, 'nulls_mapped')
1934
$_$;
1935

    
1936

    
1937
--
1938
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1939
--
1940

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

    
1943

    
1944
--
1945
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1946
--
1947

    
1948
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1949
    LANGUAGE sql STRICT
1950
    AS $_$
1951
SELECT util.table_flag__set($1, 'nulls_mapped')
1952
$_$;
1953

    
1954

    
1955
--
1956
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1957
--
1958

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

    
1962

    
1963
--
1964
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1965
--
1966

    
1967
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1968
    LANGUAGE sql STABLE STRICT
1969
    AS $_$
1970
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1971
$_$;
1972

    
1973

    
1974
--
1975
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1976
--
1977

    
1978
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1979
    LANGUAGE plpgsql STRICT
1980
    AS $_$
1981
DECLARE
1982
    row record;
1983
BEGIN
1984
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1985
    LOOP
1986
        IF row.global_name != row.name THEN
1987
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1988
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1989
        END IF;
1990
    END LOOP;
1991
END;
1992
$_$;
1993

    
1994

    
1995
--
1996
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1997
--
1998

    
1999
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
2000

    
2001

    
2002
--
2003
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2004
--
2005

    
2006
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2007
    LANGUAGE sql STRICT
2008
    AS $_$
2009
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2010
SELECT NULL::void; -- don't fold away functions called in previous query
2011
$_$;
2012

    
2013

    
2014
--
2015
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2016
--
2017

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

    
2021

    
2022
--
2023
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2024
--
2025

    
2026
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2027
    LANGUAGE plpgsql STRICT
2028
    AS $_$
2029
BEGIN
2030
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2031
END;
2032
$_$;
2033

    
2034

    
2035
--
2036
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2037
--
2038

    
2039
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
2040

    
2041

    
2042
--
2043
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2044
--
2045

    
2046
CREATE FUNCTION try_create(sql text) RETURNS void
2047
    LANGUAGE plpgsql STRICT
2048
    AS $$
2049
BEGIN
2050
    PERFORM util.eval(sql);
2051
EXCEPTION
2052
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2053
    WHEN undefined_column THEN NULL;
2054
    WHEN duplicate_column THEN NULL;
2055
END;
2056
$$;
2057

    
2058

    
2059
--
2060
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2061
--
2062

    
2063
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
2064

    
2065

    
2066
--
2067
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2068
--
2069

    
2070
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2071
    LANGUAGE sql STRICT
2072
    AS $_$
2073
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2074
$_$;
2075

    
2076

    
2077
--
2078
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2079
--
2080

    
2081
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
2082

    
2083

    
2084
--
2085
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2086
--
2087

    
2088
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2089
    LANGUAGE sql IMMUTABLE
2090
    AS $_$
2091
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2092
$_$;
2093

    
2094

    
2095
--
2096
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2097
--
2098

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

    
2101

    
2102
--
2103
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2104
--
2105

    
2106
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2107
    LANGUAGE sql STABLE STRICT
2108
    SET search_path TO pg_temp
2109
    AS $_$
2110
SELECT $1::text
2111
$_$;
2112

    
2113

    
2114
--
2115
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2116
--
2117

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

    
2120

    
2121
--
2122
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2123
--
2124

    
2125
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2126
    LANGUAGE plpgsql STABLE
2127
    AS $_$
2128
DECLARE
2129
    type regtype;
2130
BEGIN
2131
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2132
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2133
    RETURN type;
2134
END;
2135
$_$;
2136

    
2137

    
2138
--
2139
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2140
--
2141

    
2142
CREATE AGGREGATE all_same(anyelement) (
2143
    SFUNC = all_same_transform,
2144
    STYPE = anyarray,
2145
    FINALFUNC = all_same_final
2146
);
2147

    
2148

    
2149
--
2150
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2151
--
2152

    
2153
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2154

    
2155

    
2156
--
2157
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2158
--
2159

    
2160
CREATE AGGREGATE join_strs(text, text) (
2161
    SFUNC = join_strs_transform,
2162
    STYPE = text
2163
);
2164

    
2165

    
2166
--
2167
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2168
--
2169

    
2170
CREATE OPERATOR -> (
2171
    PROCEDURE = map_get,
2172
    LEFTARG = regclass,
2173
    RIGHTARG = text
2174
);
2175

    
2176

    
2177
--
2178
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2179
--
2180

    
2181
CREATE OPERATOR => (
2182
    PROCEDURE = hstore,
2183
    LEFTARG = text[],
2184
    RIGHTARG = text
2185
);
2186

    
2187

    
2188
--
2189
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2190
--
2191

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

    
2194

    
2195
--
2196
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2197
--
2198

    
2199
CREATE OPERATOR ?*>= (
2200
    PROCEDURE = is_populated_more_often_than,
2201
    LEFTARG = anyelement,
2202
    RIGHTARG = anyelement
2203
);
2204

    
2205

    
2206
--
2207
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2208
--
2209

    
2210
CREATE OPERATOR ?>= (
2211
    PROCEDURE = is_more_complete_than,
2212
    LEFTARG = anyelement,
2213
    RIGHTARG = anyelement
2214
);
2215

    
2216

    
2217
--
2218
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2219
--
2220

    
2221
CREATE OPERATOR ||% (
2222
    PROCEDURE = concat_esc,
2223
    LEFTARG = text,
2224
    RIGHTARG = text
2225
);
2226

    
2227

    
2228
--
2229
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2230
--
2231

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

    
2234

    
2235
SET default_tablespace = '';
2236

    
2237
SET default_with_oids = false;
2238

    
2239
--
2240
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2241
--
2242

    
2243
CREATE TABLE map (
2244
    "from" text NOT NULL,
2245
    "to" text,
2246
    filter text,
2247
    notes text
2248
);
2249

    
2250

    
2251
--
2252
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2253
--
2254

    
2255

    
2256

    
2257
--
2258
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2259
--
2260

    
2261
ALTER TABLE ONLY map
2262
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2263

    
2264

    
2265
--
2266
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2267
--
2268

    
2269
ALTER TABLE ONLY map
2270
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2271

    
2272

    
2273
--
2274
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2278

    
2279

    
2280
--
2281
-- PostgreSQL database dump complete
2282
--
2283

    
(19-19/29)