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: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
819
--
820

    
821
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
822
    LANGUAGE sql IMMUTABLE
823
    AS $_$
824
SELECT position($1 in $2) > 0 /*1-based offset*/
825
$_$;
826

    
827

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

    
832
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
833
    LANGUAGE plpgsql STRICT
834
    AS $$
835
BEGIN
836
    PERFORM util.eval(sql);
837
EXCEPTION
838
    WHEN duplicate_table  THEN NULL;
839
    WHEN duplicate_object THEN NULL; -- e.g. constraint
840
    WHEN duplicate_column THEN NULL;
841
    WHEN invalid_table_definition THEN
842
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
843
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
844
        END IF;
845
END;
846
$$;
847

    
848

    
849
--
850
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
851
--
852

    
853
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
854

    
855

    
856
--
857
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
858
--
859

    
860
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
861
    LANGUAGE sql STABLE STRICT
862
    AS $_$
863
SELECT util.eval2set($$
864
SELECT col
865
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
866
LEFT JOIN $$||$2||$$ ON "to" = col
867
WHERE "from" IS NULL
868
$$, NULL::text)
869
$_$;
870

    
871

    
872
--
873
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
874
--
875

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

    
878

    
879
--
880
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
881
--
882

    
883
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
884
    LANGUAGE sql STRICT
885
    AS $_$
886
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
887
$_$;
888

    
889

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

    
894
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
895

    
896

    
897
--
898
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
899
--
900

    
901
CREATE FUNCTION drop_column(col col_ref) RETURNS void
902
    LANGUAGE sql STRICT
903
    AS $_$
904
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
905
quote_ident($1.name))
906
$_$;
907

    
908

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

    
913
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
914

    
915

    
916
--
917
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
918
--
919

    
920
CREATE FUNCTION drop_table(table_ text) RETURNS void
921
    LANGUAGE sql STRICT
922
    AS $_$
923
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
924
$_$;
925

    
926

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

    
931
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
932

    
933

    
934
--
935
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
936
--
937

    
938
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
939
    LANGUAGE sql IMMUTABLE
940
    AS $_$
941
SELECT util.array_fill($1, 0)
942
$_$;
943

    
944

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

    
949
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)';
950

    
951

    
952
--
953
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
954
--
955

    
956
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
957
    LANGUAGE sql IMMUTABLE
958
    AS $_$
959
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
960
$_$;
961

    
962

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

    
967
CREATE FUNCTION eval(sql text) RETURNS void
968
    LANGUAGE plpgsql STRICT
969
    AS $$
970
BEGIN
971
    RAISE NOTICE '%', sql;
972
    EXECUTE sql;
973
END;
974
$$;
975

    
976

    
977
--
978
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
979
--
980

    
981
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
982
    LANGUAGE plpgsql
983
    AS $$
984
BEGIN
985
	RAISE NOTICE '%', sql;
986
	RETURN QUERY EXECUTE sql;
987
END;
988
$$;
989

    
990

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

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

    
997

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

    
1002
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1003
    LANGUAGE plpgsql
1004
    AS $$
1005
DECLARE
1006
	ret_val ret_type_null%TYPE;
1007
BEGIN
1008
	RAISE NOTICE '%', sql;
1009
	EXECUTE sql INTO STRICT ret_val;
1010
	RETURN ret_val;
1011
END;
1012
$$;
1013

    
1014

    
1015
--
1016
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1017
--
1018

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

    
1021

    
1022
--
1023
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1024
--
1025

    
1026
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1027
    LANGUAGE sql
1028
    AS $_$
1029
SELECT util.eval2val($$SELECT $$||$1, $2)
1030
$_$;
1031

    
1032

    
1033
--
1034
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1035
--
1036

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

    
1039

    
1040
--
1041
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1042
--
1043

    
1044
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1045
    LANGUAGE sql
1046
    AS $_$
1047
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1048
$_$;
1049

    
1050

    
1051
--
1052
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1053
--
1054

    
1055
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1056
ret_type_null: NULL::ret_type';
1057

    
1058

    
1059
--
1060
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1061
--
1062

    
1063
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1064
    LANGUAGE sql STABLE STRICT
1065
    AS $_$
1066
SELECT col_name
1067
FROM unnest($2) s (col_name)
1068
WHERE util.col_exists(($1, col_name))
1069
$_$;
1070

    
1071

    
1072
--
1073
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1074
--
1075

    
1076
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1077
    LANGUAGE sql IMMUTABLE
1078
    AS $_$
1079
-- STRICT handles NULLs, so that the array will always be a value
1080
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1081
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1082
) END
1083
$_$;
1084

    
1085

    
1086
--
1087
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1088
--
1089

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

    
1092

    
1093
--
1094
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1095
--
1096

    
1097
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1098
    LANGUAGE plpgsql STRICT
1099
    AS $_$
1100
DECLARE
1101
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1102
$$||query;
1103
BEGIN
1104
	EXECUTE mk_view;
1105
EXCEPTION
1106
WHEN invalid_table_definition THEN
1107
	IF SQLERRM = 'cannot drop columns from view'
1108
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1109
	THEN
1110
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1111
		EXECUTE mk_view;
1112
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1113
	END IF;
1114
END;
1115
$_$;
1116

    
1117

    
1118
--
1119
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1120
--
1121

    
1122
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1123

    
1124

    
1125
--
1126
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1127
--
1128

    
1129
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1130
    LANGUAGE sql IMMUTABLE
1131
    AS $_$
1132
SELECT substring($2 for length($1)) = $1
1133
$_$;
1134

    
1135

    
1136
--
1137
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1138
--
1139

    
1140
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1141
    LANGUAGE sql IMMUTABLE
1142
    AS $_$
1143
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1144
$_$;
1145

    
1146

    
1147
--
1148
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1149
--
1150

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

    
1153

    
1154
--
1155
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1156
--
1157

    
1158
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1159
    LANGUAGE sql STABLE STRICT
1160
    AS $_$
1161
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1162
$_$;
1163

    
1164

    
1165
--
1166
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1167
--
1168

    
1169
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1170
    LANGUAGE sql IMMUTABLE
1171
    AS $_$
1172
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1173
$_$;
1174

    
1175

    
1176
--
1177
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1178
--
1179

    
1180
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1181
    LANGUAGE sql IMMUTABLE
1182
    AS $_$
1183
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1184
$_$;
1185

    
1186

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

    
1191
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1192
    LANGUAGE sql IMMUTABLE STRICT
1193
    AS $_$
1194
SELECT $1 || $3 || $2
1195
$_$;
1196

    
1197

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

    
1202
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer) RETURNS integer
1203
    LANGUAGE sql IMMUTABLE
1204
    AS $_$
1205
SELECT COALESCE(util.offset2row_num($2) + $1 - 1, 2147483647)
1206
$_$;
1207

    
1208

    
1209
--
1210
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1211
--
1212

    
1213
CREATE FUNCTION map_filter_insert() RETURNS trigger
1214
    LANGUAGE plpgsql
1215
    AS $$
1216
BEGIN
1217
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1218
	RETURN new;
1219
END;
1220
$$;
1221

    
1222

    
1223
--
1224
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1225
--
1226

    
1227
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1228
    LANGUAGE plpgsql STABLE STRICT
1229
    AS $_$
1230
DECLARE
1231
    value text;
1232
BEGIN
1233
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1234
        INTO value USING key;
1235
    RETURN value;
1236
END;
1237
$_$;
1238

    
1239

    
1240
--
1241
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1242
--
1243

    
1244
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1245
    LANGUAGE sql IMMUTABLE
1246
    AS $_$
1247
SELECT util._map(util.nulls_map($1), $2)
1248
$_$;
1249

    
1250

    
1251
--
1252
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1253
--
1254

    
1255
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].
1256

    
1257
[1] inlining of function calls, which is different from constant folding
1258
[2] _map()''s profiling query
1259
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1260
and map_nulls()''s profiling query
1261
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1262
both take ~920 ms.
1263
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.';
1264

    
1265

    
1266
--
1267
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1268
--
1269

    
1270
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1271
    LANGUAGE plpgsql STABLE STRICT
1272
    AS $_$
1273
BEGIN
1274
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1275
END;
1276
$_$;
1277

    
1278

    
1279
--
1280
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1281
--
1282

    
1283
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1284
    LANGUAGE sql STRICT
1285
    AS $_$
1286
SELECT util.create_if_not_exists($$
1287
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1288
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1289
||quote_literal($2)||$$;
1290
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1291
$$)
1292
$_$;
1293

    
1294

    
1295
--
1296
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1297
--
1298

    
1299
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1300

    
1301

    
1302
--
1303
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1304
--
1305

    
1306
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1307
    LANGUAGE plpgsql STRICT
1308
    AS $_$
1309
DECLARE
1310
    type regtype = util.typeof(expr, col.table_::text::regtype);
1311
    col_name_sql text = quote_ident(col.name);
1312
BEGIN
1313
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1314
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1315
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1316
$$||expr||$$;
1317
$$);
1318
END;
1319
$_$;
1320

    
1321

    
1322
--
1323
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1324
--
1325

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

    
1328

    
1329
--
1330
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1331
--
1332

    
1333
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1334
    LANGUAGE sql STRICT
1335
    AS $_$
1336
SELECT util.create_if_not_exists($$
1337
CREATE TABLE $$||$1||$$
1338
(
1339
    LIKE util.map INCLUDING ALL
1340
);
1341

    
1342
CREATE TRIGGER map_filter_insert
1343
  BEFORE INSERT
1344
  ON $$||$1||$$
1345
  FOR EACH ROW
1346
  EXECUTE PROCEDURE util.map_filter_insert();
1347
$$)
1348
$_$;
1349

    
1350

    
1351
--
1352
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1353
--
1354

    
1355
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1356
    LANGUAGE sql STRICT
1357
    AS $_$
1358
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1359
$_$;
1360

    
1361

    
1362
--
1363
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1364
--
1365

    
1366
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1367

    
1368

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

    
1373
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1374
    LANGUAGE plpgsql STRICT
1375
    AS $_$
1376
BEGIN
1377
	EXECUTE $$
1378
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1379
  RETURNS SETOF $$||view_||$$ AS
1380
$BODY1$
1381
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1382
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN util.offset2row_num($2) AND util.limit2row_num($1, $2)
1383
$BODY1$
1384
  LANGUAGE sql STABLE
1385
  COST 100
1386
  ROWS 1000
1387
$$;
1388
-- Also create subset function which turns off enable_sort
1389
	EXECUTE $$
1390
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1391
  RETURNS SETOF $$||view_||$$
1392
  SET enable_sort TO 'off'
1393
  AS
1394
$BODY1$
1395
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1396
$BODY1$
1397
  LANGUAGE sql STABLE
1398
  COST 100
1399
  ROWS 1000
1400
;
1401
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1402
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1403
If you want to run EXPLAIN and get expanded output, use the regular subset
1404
function instead. (When a config param is set on a function, EXPLAIN produces
1405
just a function scan.)
1406
';
1407
$$;
1408
END;
1409
$_$;
1410

    
1411

    
1412
--
1413
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1414
--
1415

    
1416
CREATE FUNCTION name(type regtype) RETURNS text
1417
    LANGUAGE sql STABLE STRICT
1418
    AS $_$
1419
SELECT typname::text FROM pg_type WHERE oid = $1
1420
$_$;
1421

    
1422

    
1423
--
1424
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1425
--
1426

    
1427
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1428
    LANGUAGE sql IMMUTABLE
1429
    AS $_$
1430
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1431
$_$;
1432

    
1433

    
1434
--
1435
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1436
--
1437

    
1438
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1439
    LANGUAGE sql IMMUTABLE
1440
    AS $_$
1441
SELECT $1 IS NOT NULL
1442
$_$;
1443

    
1444

    
1445
--
1446
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1447
--
1448

    
1449
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1450
    LANGUAGE sql IMMUTABLE
1451
    AS $_$
1452
SELECT util.hstore($1, NULL) || '*=>*'
1453
$_$;
1454

    
1455

    
1456
--
1457
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1458
--
1459

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

    
1462

    
1463
--
1464
-- Name: offset2row_num(integer); Type: FUNCTION; Schema: util; Owner: -
1465
--
1466

    
1467
CREATE FUNCTION offset2row_num(offset_ integer) RETURNS integer
1468
    LANGUAGE sql IMMUTABLE
1469
    AS $_$
1470
SELECT COALESCE($1, 0)+1
1471
$_$;
1472

    
1473

    
1474
--
1475
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1476
--
1477

    
1478
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1479
    LANGUAGE plpgsql IMMUTABLE STRICT
1480
    AS $$
1481
BEGIN
1482
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1483
END;
1484
$$;
1485

    
1486

    
1487
--
1488
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1489
--
1490

    
1491
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1492
    LANGUAGE sql STRICT
1493
    AS $_$
1494
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1495
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1496
FROM util.col_names($1::text::regtype) f (name);
1497
SELECT NULL::void; -- don't fold away functions called in previous query
1498
$_$;
1499

    
1500

    
1501
--
1502
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1503
--
1504

    
1505
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1506

    
1507

    
1508
--
1509
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1510
--
1511

    
1512
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1513
    LANGUAGE sql STRICT
1514
    AS $_$
1515
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1516
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1517
SELECT util.set_col_names($1, $2);
1518
$_$;
1519

    
1520

    
1521
--
1522
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1523
--
1524

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

    
1528

    
1529
--
1530
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1531
--
1532

    
1533
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1534
    LANGUAGE sql STRICT
1535
    AS $_$
1536
SELECT util.drop_table($1);
1537
SELECT util.mk_map_table($1);
1538
$_$;
1539

    
1540

    
1541
--
1542
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1543
--
1544

    
1545
CREATE FUNCTION schema(type regtype) RETURNS text
1546
    LANGUAGE sql STABLE
1547
    AS $_$
1548
SELECT nspname::text
1549
FROM pg_type
1550
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1551
WHERE pg_type.oid = $1
1552
$_$;
1553

    
1554

    
1555
--
1556
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1557
--
1558

    
1559
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1560
    LANGUAGE sql STABLE
1561
    AS $_$
1562
SELECT util.schema(pg_typeof($1))
1563
$_$;
1564

    
1565

    
1566
--
1567
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1568
--
1569

    
1570
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1571
    LANGUAGE sql STABLE
1572
    AS $_$
1573
SELECT quote_ident(util.schema($1))
1574
$_$;
1575

    
1576

    
1577
--
1578
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1579
--
1580

    
1581
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1582
    LANGUAGE sql STRICT
1583
    AS $_$
1584
SELECT util.eval(
1585
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1586
$_$;
1587

    
1588

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

    
1593
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1594
    LANGUAGE plpgsql STRICT
1595
    AS $_$
1596
DECLARE
1597
    old text[] = ARRAY(SELECT util.col_names(table_));
1598
    new text[] = ARRAY(SELECT util.map_values(names));
1599
BEGIN
1600
    old = old[1:array_length(new, 1)]; -- truncate to same length
1601
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1602
||$$ TO $$||quote_ident(value))
1603
    FROM each(hstore(old, new))
1604
    WHERE value != key -- not same name
1605
    ;
1606
END;
1607
$_$;
1608

    
1609

    
1610
--
1611
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1612
--
1613

    
1614
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1615

    
1616

    
1617
--
1618
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1619
--
1620

    
1621
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1622
    LANGUAGE plpgsql STRICT
1623
    AS $_$
1624
DECLARE
1625
	row_ util.map;
1626
BEGIN
1627
	-- rename any metadata cols rather than re-adding them with new names
1628
	BEGIN
1629
		PERFORM util.set_col_names(table_, names);
1630
	EXCEPTION
1631
		WHEN array_subscript_error THEN -- selective suppress
1632
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
1633
				-- metadata cols not yet added
1634
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
1635
			END IF;
1636
	END;
1637
	
1638
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1639
	LOOP
1640
		PERFORM util.mk_const_col((table_, row_."to"),
1641
			substring(row_."from" from 2));
1642
	END LOOP;
1643
	
1644
	PERFORM util.set_col_names(table_, names);
1645
END;
1646
$_$;
1647

    
1648

    
1649
--
1650
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1651
--
1652

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

    
1656

    
1657
--
1658
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660

    
1661
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1662
    LANGUAGE plpgsql STRICT
1663
    AS $_$
1664
DECLARE
1665
    sql text = $$ALTER TABLE $$||table_||$$
1666
$$||NULLIF(array_to_string(ARRAY(
1667
    SELECT
1668
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1669
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1670
    FROM
1671
    (
1672
        SELECT
1673
          quote_ident(col_name) AS col_name_sql
1674
        , util.col_type((table_, col_name)) AS curr_type
1675
        , type AS target_type
1676
        FROM unnest(col_casts)
1677
    ) s
1678
    WHERE curr_type != target_type
1679
), '
1680
, '), '');
1681
BEGIN
1682
    RAISE NOTICE '%', sql;
1683
    EXECUTE COALESCE(sql, '');
1684
END;
1685
$_$;
1686

    
1687

    
1688
--
1689
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1690
--
1691

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

    
1694

    
1695
--
1696
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1697
--
1698

    
1699
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1700
    LANGUAGE plpgsql STABLE STRICT
1701
    AS $_$
1702
DECLARE
1703
    hstore hstore;
1704
BEGIN
1705
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1706
        table_||$$))$$ INTO STRICT hstore;
1707
    RETURN hstore;
1708
END;
1709
$_$;
1710

    
1711

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

    
1716
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1717
    LANGUAGE sql STABLE STRICT
1718
    AS $_$
1719
SELECT COUNT(*) > 0 FROM pg_constraint
1720
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1721
$_$;
1722

    
1723

    
1724
--
1725
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1726
--
1727

    
1728
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';
1729

    
1730

    
1731
--
1732
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1733
--
1734

    
1735
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1736
    LANGUAGE sql STRICT
1737
    AS $_$
1738
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1739
||quote_ident($2)||$$ CHECK (true)$$)
1740
$_$;
1741

    
1742

    
1743
--
1744
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1745
--
1746

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

    
1750

    
1751
--
1752
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1753
--
1754

    
1755
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1756
    LANGUAGE sql STABLE STRICT
1757
    AS $_$
1758
SELECT util.table_flag__get($1, 'nulls_mapped')
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1764
--
1765

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

    
1768

    
1769
--
1770
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1771
--
1772

    
1773
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1774
    LANGUAGE sql STRICT
1775
    AS $_$
1776
SELECT util.table_flag__set($1, 'nulls_mapped')
1777
$_$;
1778

    
1779

    
1780
--
1781
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1782
--
1783

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

    
1787

    
1788
--
1789
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1790
--
1791

    
1792
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1793
    LANGUAGE sql STABLE STRICT
1794
    AS $_$
1795
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1796
$_$;
1797

    
1798

    
1799
--
1800
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1801
--
1802

    
1803
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1804
    LANGUAGE plpgsql STRICT
1805
    AS $_$
1806
DECLARE
1807
    row record;
1808
BEGIN
1809
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1810
    LOOP
1811
        IF row.global_name != row.name THEN
1812
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1813
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1814
        END IF;
1815
    END LOOP;
1816
END;
1817
$_$;
1818

    
1819

    
1820
--
1821
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1822
--
1823

    
1824
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1825

    
1826

    
1827
--
1828
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1829
--
1830

    
1831
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
1832
    LANGUAGE sql STRICT
1833
    AS $_$
1834
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
1835
SELECT NULL::void; -- don't fold away functions called in previous query
1836
$_$;
1837

    
1838

    
1839
--
1840
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1841
--
1842

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

    
1846

    
1847
--
1848
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1849
--
1850

    
1851
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1852
    LANGUAGE plpgsql STRICT
1853
    AS $_$
1854
BEGIN
1855
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1856
END;
1857
$_$;
1858

    
1859

    
1860
--
1861
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1862
--
1863

    
1864
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1865

    
1866

    
1867
--
1868
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1869
--
1870

    
1871
CREATE FUNCTION try_create(sql text) RETURNS void
1872
    LANGUAGE plpgsql STRICT
1873
    AS $$
1874
BEGIN
1875
    PERFORM util.eval(sql);
1876
EXCEPTION
1877
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1878
    WHEN undefined_column THEN NULL;
1879
    WHEN duplicate_column THEN NULL;
1880
END;
1881
$$;
1882

    
1883

    
1884
--
1885
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1886
--
1887

    
1888
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1889

    
1890

    
1891
--
1892
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1893
--
1894

    
1895
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1896
    LANGUAGE sql STRICT
1897
    AS $_$
1898
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1899
$_$;
1900

    
1901

    
1902
--
1903
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1904
--
1905

    
1906
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1907

    
1908

    
1909
--
1910
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1911
--
1912

    
1913
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1914
    LANGUAGE sql IMMUTABLE
1915
    AS $_$
1916
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1917
$_$;
1918

    
1919

    
1920
--
1921
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
1922
--
1923

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

    
1926

    
1927
--
1928
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1929
--
1930

    
1931
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1932
    LANGUAGE sql STABLE STRICT
1933
    SET search_path TO pg_temp
1934
    AS $_$
1935
SELECT $1::text
1936
$_$;
1937

    
1938

    
1939
--
1940
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
1941
--
1942

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

    
1945

    
1946
--
1947
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
1948
--
1949

    
1950
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
1951
    LANGUAGE plpgsql STABLE
1952
    AS $_$
1953
DECLARE
1954
    type regtype;
1955
BEGIN
1956
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
1957
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
1958
    RETURN type;
1959
END;
1960
$_$;
1961

    
1962

    
1963
--
1964
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1965
--
1966

    
1967
CREATE AGGREGATE all_same(anyelement) (
1968
    SFUNC = all_same_transform,
1969
    STYPE = anyarray,
1970
    FINALFUNC = all_same_final
1971
);
1972

    
1973

    
1974
--
1975
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1976
--
1977

    
1978
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1979

    
1980

    
1981
--
1982
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1983
--
1984

    
1985
CREATE AGGREGATE join_strs(text, text) (
1986
    SFUNC = join_strs_transform,
1987
    STYPE = text
1988
);
1989

    
1990

    
1991
--
1992
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1993
--
1994

    
1995
CREATE OPERATOR -> (
1996
    PROCEDURE = map_get,
1997
    LEFTARG = regclass,
1998
    RIGHTARG = text
1999
);
2000

    
2001

    
2002
--
2003
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2004
--
2005

    
2006
CREATE OPERATOR => (
2007
    PROCEDURE = hstore,
2008
    LEFTARG = text[],
2009
    RIGHTARG = text
2010
);
2011

    
2012

    
2013
--
2014
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2015
--
2016

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

    
2019

    
2020
--
2021
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2022
--
2023

    
2024
CREATE OPERATOR ?*>= (
2025
    PROCEDURE = is_populated_more_often_than,
2026
    LEFTARG = anyelement,
2027
    RIGHTARG = anyelement
2028
);
2029

    
2030

    
2031
--
2032
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2033
--
2034

    
2035
CREATE OPERATOR ?>= (
2036
    PROCEDURE = is_more_complete_than,
2037
    LEFTARG = anyelement,
2038
    RIGHTARG = anyelement
2039
);
2040

    
2041

    
2042
SET default_tablespace = '';
2043

    
2044
SET default_with_oids = false;
2045

    
2046
--
2047
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2048
--
2049

    
2050
CREATE TABLE map (
2051
    "from" text NOT NULL,
2052
    "to" text,
2053
    filter text,
2054
    notes text
2055
);
2056

    
2057

    
2058
--
2059
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2060
--
2061

    
2062

    
2063

    
2064
--
2065
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2066
--
2067

    
2068
ALTER TABLE ONLY map
2069
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2070

    
2071

    
2072
--
2073
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2074
--
2075

    
2076
ALTER TABLE ONLY map
2077
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2078

    
2079

    
2080
--
2081
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2082
--
2083

    
2084
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2085

    
2086

    
2087
--
2088
-- PostgreSQL database dump complete
2089
--
2090

    
(19-19/29)