Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET lock_timeout = 0;
7
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11

    
12
--
13
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
CREATE SCHEMA util;
17

    
18

    
19
--
20
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
21
--
22

    
23
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.
24

    
25
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.';
26

    
27

    
28
SET search_path = util, pg_catalog;
29

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

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

    
39

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

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

    
49

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

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

    
61

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

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

    
71

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

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

    
82

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

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

    
102

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

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

    
109

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

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

    
129

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

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

    
148

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

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

    
166

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

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

    
177

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

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

    
188

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

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

    
201

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

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

    
212

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

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

    
223

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

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

    
234

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

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

    
245

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

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

    
256

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

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

    
267

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

    
272
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
273
    LANGUAGE plpgsql IMMUTABLE STRICT
274
    AS $$
275
DECLARE
276
    result value%TYPE := util._map(map, value::text)::unknown;
277
BEGIN
278
    RETURN result;
279
END;
280
$$;
281

    
282

    
283
--
284
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
285
--
286

    
287
CREATE FUNCTION _map(map hstore, value text) RETURNS text
288
    LANGUAGE plpgsql IMMUTABLE STRICT
289
    AS $$
290
DECLARE
291
    match text := map -> value;
292
BEGIN
293
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
294
        match := map -> '*'; -- use default entry
295
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
296
        END IF;
297
    END IF;
298
    
299
    -- Interpret result
300
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
301
    ELSIF match = '*' THEN RETURN value;
302
    ELSE RETURN match;
303
    END IF;
304
END;
305
$$;
306

    
307

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

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

    
318

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

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

    
357

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

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

    
368

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

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

    
407

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

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

    
418

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

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

    
429

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

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

    
440

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

    
445
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
446
    LANGUAGE sql IMMUTABLE
447
    AS $_$
448
SELECT util."_nullIf"($1, $2, $3::util.datatype)
449
$_$;
450

    
451

    
452
--
453
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
454
--
455

    
456
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
457
    LANGUAGE plpgsql IMMUTABLE
458
    AS $$
459
DECLARE
460
    type util.datatype NOT NULL := type; -- add NOT NULL
461
BEGIN
462
    IF type = 'str' THEN RETURN nullif(value::text, "null");
463
    -- Invalid value is ignored, but invalid null value generates error
464
    ELSIF type = 'float' THEN
465
        DECLARE
466
            -- Outside the try block so that invalid null value generates error
467
            "null" double precision := "null"::double precision;
468
        BEGIN
469
            RETURN nullif(value::double precision, "null");
470
        EXCEPTION
471
            WHEN data_exception THEN RETURN value; -- ignore invalid value
472
        END;
473
    END IF;
474
END;
475
$$;
476

    
477

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

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

    
497

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

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

    
504

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

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

    
515

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

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

    
526

    
527
--
528
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
529
--
530

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

    
544

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

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

    
551

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

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

    
562

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

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

    
579

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

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

    
590

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

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

    
601

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

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

    
612

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

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

    
619

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

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

    
630

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

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

    
646

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

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

    
653

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

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

    
669

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

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

    
693

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

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

    
716

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

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

    
727

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

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

    
734

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

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

    
750

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

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

    
767

    
768
--
769
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
770
--
771

    
772
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
773
    LANGUAGE sql STABLE STRICT
774
    AS $_$
775
SELECT attname::text
776
FROM pg_attribute
777
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
778
ORDER BY attnum
779
$_$;
780

    
781

    
782
--
783
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
784
--
785

    
786
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
787
    LANGUAGE plpgsql STABLE STRICT
788
    AS $_$
789
BEGIN
790
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
791
END;
792
$_$;
793

    
794

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

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

    
817

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

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

    
828

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

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

    
839

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

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

    
860

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

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

    
867

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

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

    
883

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

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

    
890

    
891
--
892
-- Name: diff_cols(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
893
--
894

    
895
CREATE FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
896
    LANGUAGE sql STABLE
897
    AS $_$
898
SELECT * FROM
899
util.eval2set($1, $3) left_ (left_)
900
FULL JOIN
901
util.eval2set($2, $3) right_ (right_)
902
ON left_ = right_
903
WHERE left_ IS DISTINCT FROM right_
904
ORDER BY left_, right_
905
$_$;
906

    
907

    
908
--
909
-- Name: FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
910
--
911

    
912
COMMENT ON FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS 'col_type_null (*required*): NULL::col_type
913
usage:
914
SELECT * FROM util.diff_cols($$VALUES (''1''), (''2''), (''4'')$$, $$VALUES (''1''), (''3''), (''4'')$$, NULL::text)
915
';
916

    
917

    
918
--
919
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
920
--
921

    
922
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
923
    LANGUAGE sql STRICT
924
    AS $_$
925
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
926
$_$;
927

    
928

    
929
--
930
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
931
--
932

    
933
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
934

    
935

    
936
--
937
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
938
--
939

    
940
CREATE FUNCTION drop_column(col col_ref) RETURNS void
941
    LANGUAGE sql STRICT
942
    AS $_$
943
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
944
quote_ident($1.name))
945
$_$;
946

    
947

    
948
--
949
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
950
--
951

    
952
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
953

    
954

    
955
--
956
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
957
--
958

    
959
CREATE FUNCTION drop_table(table_ text) RETURNS void
960
    LANGUAGE sql STRICT
961
    AS $_$
962
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
963
$_$;
964

    
965

    
966
--
967
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
968
--
969

    
970
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
971

    
972

    
973
--
974
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
975
--
976

    
977
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
978
    LANGUAGE sql IMMUTABLE
979
    AS $_$
980
SELECT util.array_fill($1, 0)
981
$_$;
982

    
983

    
984
--
985
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
986
--
987

    
988
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)';
989

    
990

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

    
995
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
996
    LANGUAGE sql IMMUTABLE
997
    AS $_$
998
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
999
$_$;
1000

    
1001

    
1002
--
1003
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1004
--
1005

    
1006
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1007
    LANGUAGE sql IMMUTABLE
1008
    AS $_$
1009
SELECT regexp_replace($2, '("?)$', $1||'\1')
1010
$_$;
1011

    
1012

    
1013
--
1014
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1015
--
1016

    
1017
CREATE FUNCTION eval(sql text) RETURNS void
1018
    LANGUAGE plpgsql STRICT
1019
    AS $$
1020
BEGIN
1021
    RAISE NOTICE '%', sql;
1022
    EXECUTE sql;
1023
END;
1024
$$;
1025

    
1026

    
1027
--
1028
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1029
--
1030

    
1031
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1032
    LANGUAGE plpgsql
1033
    AS $$
1034
BEGIN
1035
	RAISE NOTICE '%', sql;
1036
	RETURN QUERY EXECUTE sql;
1037
END;
1038
$$;
1039

    
1040

    
1041
--
1042
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1043
--
1044

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

    
1047

    
1048
--
1049
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1050
--
1051

    
1052
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1053
    LANGUAGE plpgsql
1054
    AS $$
1055
DECLARE
1056
	ret_val ret_type_null%TYPE;
1057
BEGIN
1058
	RAISE NOTICE '%', sql;
1059
	EXECUTE sql INTO STRICT ret_val;
1060
	RETURN ret_val;
1061
END;
1062
$$;
1063

    
1064

    
1065
--
1066
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1067
--
1068

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

    
1071

    
1072
--
1073
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1074
--
1075

    
1076
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1077
    LANGUAGE sql
1078
    AS $_$
1079
SELECT util.eval2val($$SELECT $$||$1, $2)
1080
$_$;
1081

    
1082

    
1083
--
1084
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1085
--
1086

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

    
1089

    
1090
--
1091
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1092
--
1093

    
1094
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1095
    LANGUAGE sql
1096
    AS $_$
1097
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1098
$_$;
1099

    
1100

    
1101
--
1102
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1103
--
1104

    
1105
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1106
ret_type_null: NULL::ret_type';
1107

    
1108

    
1109
--
1110
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1111
--
1112

    
1113
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1114
    LANGUAGE sql STABLE STRICT
1115
    AS $_$
1116
SELECT col_name
1117
FROM unnest($2) s (col_name)
1118
WHERE util.col_exists(($1, col_name))
1119
$_$;
1120

    
1121

    
1122
--
1123
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1124
--
1125

    
1126
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1127
    LANGUAGE sql
1128
    AS $_$
1129
SELECT util.eval2set($$EXPLAIN $$||$1)
1130
$_$;
1131

    
1132

    
1133
--
1134
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1135
--
1136

    
1137
CREATE FUNCTION explain2notice(sql text) RETURNS void
1138
    LANGUAGE plpgsql
1139
    AS $_$
1140
BEGIN
1141
	RAISE NOTICE '%', $$EXPLAIN:
1142
$$||util.explain2str(sql);
1143
END;
1144
$_$;
1145

    
1146

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

    
1151
CREATE FUNCTION explain2str(sql text) RETURNS text
1152
    LANGUAGE sql
1153
    AS $_$
1154
SELECT util.join_strs(explain, $$
1155
$$) FROM util.explain($1)
1156
$_$;
1157

    
1158

    
1159
SET default_tablespace = '';
1160

    
1161
SET default_with_oids = false;
1162

    
1163
--
1164
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1165
--
1166

    
1167
CREATE TABLE explain (
1168
    line text NOT NULL
1169
);
1170

    
1171

    
1172
--
1173
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1174
--
1175

    
1176
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1177
    LANGUAGE sql
1178
    AS $_$
1179
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1180
$$||quote_nullable($1)||$$
1181
)$$)
1182
$_$;
1183

    
1184

    
1185
--
1186
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1187
--
1188

    
1189
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS 'usage:
1190
PERFORM util.explain2table($$
1191
query
1192
$$);';
1193

    
1194

    
1195
--
1196
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1197
--
1198

    
1199
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1200
    LANGUAGE sql IMMUTABLE
1201
    AS $_$
1202
-- STRICT handles NULLs, so that the array will always be a value
1203
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1204
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1205
) END
1206
$_$;
1207

    
1208

    
1209
--
1210
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1211
--
1212

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

    
1215

    
1216
--
1217
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1218
--
1219

    
1220
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1221
    LANGUAGE plpgsql
1222
    AS $_$
1223
DECLARE
1224
	PG_EXCEPTION_DETAIL text;
1225
	recreate_users_cmd text = util.save_drop_views(users);
1226
BEGIN
1227
	PERFORM util.eval(cmd);
1228
	PERFORM util.eval(recreate_users_cmd);
1229
EXCEPTION
1230
WHEN dependent_objects_still_exist THEN
1231
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1232
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1233
	users = array(SELECT * FROM util.regexp_matches_group(
1234
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1235
	IF util.is_empty(users) THEN RAISE; END IF;
1236
	PERFORM util.force_recreate(cmd, users);
1237
END;
1238
$_$;
1239

    
1240

    
1241
--
1242
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1243
--
1244

    
1245
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS 'idempotent
1246

    
1247
users: not necessary to provide this because it will be autopopulated';
1248

    
1249

    
1250
--
1251
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1252
--
1253

    
1254
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1255
    LANGUAGE plpgsql STRICT
1256
    AS $_$
1257
DECLARE
1258
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1259
$$||query;
1260
BEGIN
1261
	EXECUTE mk_view;
1262
EXCEPTION
1263
WHEN invalid_table_definition THEN
1264
	IF SQLERRM = 'cannot drop columns from view'
1265
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1266
	THEN
1267
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1268
		EXECUTE mk_view;
1269
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1270
	END IF;
1271
END;
1272
$_$;
1273

    
1274

    
1275
--
1276
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1277
--
1278

    
1279
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1280

    
1281

    
1282
--
1283
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1284
--
1285

    
1286
CREATE FUNCTION grants_users() RETURNS SETOF text
1287
    LANGUAGE sql IMMUTABLE
1288
    AS $$
1289
VALUES ('bien_read'), ('public_')
1290
$$;
1291

    
1292

    
1293
--
1294
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1295
--
1296

    
1297
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1298
    LANGUAGE sql IMMUTABLE
1299
    AS $_$
1300
SELECT substring($2 for length($1)) = $1
1301
$_$;
1302

    
1303

    
1304
--
1305
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1306
--
1307

    
1308
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1309
    LANGUAGE sql IMMUTABLE
1310
    AS $_$
1311
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1312
$_$;
1313

    
1314

    
1315
--
1316
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1317
--
1318

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

    
1321

    
1322
--
1323
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1324
--
1325

    
1326
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1327
    LANGUAGE sql STABLE STRICT
1328
    AS $_$
1329
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1330
$_$;
1331

    
1332

    
1333
--
1334
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1335
--
1336

    
1337
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1338
    LANGUAGE sql IMMUTABLE
1339
    AS $_$
1340
SELECT util.array_length($1) = 0
1341
$_$;
1342

    
1343

    
1344
--
1345
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1346
--
1347

    
1348
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1349
    LANGUAGE sql IMMUTABLE
1350
    AS $_$
1351
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1352
$_$;
1353

    
1354

    
1355
--
1356
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1357
--
1358

    
1359
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1360
    LANGUAGE sql IMMUTABLE
1361
    AS $_$
1362
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1363
$_$;
1364

    
1365

    
1366
--
1367
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1368
--
1369

    
1370
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1371
    LANGUAGE sql IMMUTABLE STRICT
1372
    AS $_$
1373
SELECT $1 || $3 || $2
1374
$_$;
1375

    
1376

    
1377
--
1378
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1379
--
1380

    
1381
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1382
    LANGUAGE sql IMMUTABLE
1383
    AS $_$
1384
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1385
$_$;
1386

    
1387

    
1388
--
1389
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1390
--
1391

    
1392
CREATE FUNCTION map_filter_insert() RETURNS trigger
1393
    LANGUAGE plpgsql
1394
    AS $$
1395
BEGIN
1396
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1397
	RETURN new;
1398
END;
1399
$$;
1400

    
1401

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

    
1406
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1407
    LANGUAGE plpgsql STABLE STRICT
1408
    AS $_$
1409
DECLARE
1410
    value text;
1411
BEGIN
1412
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1413
        INTO value USING key;
1414
    RETURN value;
1415
END;
1416
$_$;
1417

    
1418

    
1419
--
1420
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1421
--
1422

    
1423
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1424
    LANGUAGE sql IMMUTABLE
1425
    AS $_$
1426
SELECT util._map(util.nulls_map($1), $2)
1427
$_$;
1428

    
1429

    
1430
--
1431
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1432
--
1433

    
1434
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].
1435

    
1436
[1] inlining of function calls, which is different from constant folding
1437
[2] _map()''s profiling query
1438
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1439
and map_nulls()''s profiling query
1440
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1441
both take ~920 ms.
1442
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.';
1443

    
1444

    
1445
--
1446
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1447
--
1448

    
1449
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1450
    LANGUAGE plpgsql STABLE STRICT
1451
    AS $_$
1452
BEGIN
1453
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1454
END;
1455
$_$;
1456

    
1457

    
1458
--
1459
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1460
--
1461

    
1462
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1463
    LANGUAGE sql STRICT
1464
    AS $_$
1465
SELECT util.create_if_not_exists($$
1466
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1467
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1468
||quote_literal($2)||$$;
1469
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1470
$$)
1471
$_$;
1472

    
1473

    
1474
--
1475
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1476
--
1477

    
1478
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1479

    
1480

    
1481
--
1482
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1483
--
1484

    
1485
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1486
    LANGUAGE plpgsql STRICT
1487
    AS $_$
1488
DECLARE
1489
    type regtype = util.typeof(expr, col.table_::text::regtype);
1490
    col_name_sql text = quote_ident(col.name);
1491
BEGIN
1492
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1493
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1494
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1495
$$||expr||$$;
1496
$$);
1497
END;
1498
$_$;
1499

    
1500

    
1501
--
1502
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1503
--
1504

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

    
1507

    
1508
--
1509
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1510
--
1511

    
1512
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1513
    LANGUAGE sql STRICT
1514
    AS $_$
1515
SELECT util.create_if_not_exists($$
1516
CREATE TABLE $$||$1||$$
1517
(
1518
    LIKE util.map INCLUDING ALL
1519
);
1520

    
1521
CREATE TRIGGER map_filter_insert
1522
  BEFORE INSERT
1523
  ON $$||$1||$$
1524
  FOR EACH ROW
1525
  EXECUTE PROCEDURE util.map_filter_insert();
1526
$$)
1527
$_$;
1528

    
1529

    
1530
--
1531
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1532
--
1533

    
1534
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1535
    LANGUAGE sql STRICT
1536
    AS $_$
1537
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1538
$_$;
1539

    
1540

    
1541
--
1542
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1543
--
1544

    
1545
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1546

    
1547

    
1548
--
1549
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1550
--
1551

    
1552
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1553
    LANGUAGE plpgsql STRICT
1554
    AS $_$
1555
DECLARE
1556
	view_qual_name text = util.qual_name(view_);
1557
BEGIN
1558
	EXECUTE $$
1559
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1560
  RETURNS SETOF $$||view_||$$ AS
1561
$BODY1$
1562
SELECT * FROM $$||view_qual_name||$$
1563
ORDER BY sort_col
1564
LIMIT $1 OFFSET $2
1565
$BODY1$
1566
  LANGUAGE sql STABLE
1567
  COST 100
1568
  ROWS 1000
1569
$$;
1570
	
1571
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1572
END;
1573
$_$;
1574

    
1575

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

    
1580
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1581
    LANGUAGE plpgsql STRICT
1582
    AS $_$
1583
DECLARE
1584
	view_qual_name text = util.qual_name(view_);
1585
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1586
BEGIN
1587
	EXECUTE $$
1588
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1589
  RETURNS integer AS
1590
$BODY1$
1591
SELECT $$||quote_ident(row_num_col)||$$
1592
FROM $$||view_qual_name||$$
1593
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1594
LIMIT 1
1595
$BODY1$
1596
  LANGUAGE sql STABLE
1597
  COST 100;
1598
$$;
1599
	
1600
	EXECUTE $$
1601
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1602
  RETURNS SETOF $$||view_||$$ AS
1603
$BODY1$
1604
SELECT * FROM $$||view_qual_name||$$
1605
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1606
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1607
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1608
ORDER BY $$||quote_ident(row_num_col)||$$
1609
$BODY1$
1610
  LANGUAGE sql STABLE
1611
  COST 100
1612
  ROWS 1000
1613
$$;
1614
	
1615
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1616
END;
1617
$_$;
1618

    
1619

    
1620
--
1621
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1622
--
1623

    
1624
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1625
    LANGUAGE plpgsql STRICT
1626
    AS $_$
1627
DECLARE
1628
	view_qual_name text = util.qual_name(view_);
1629
BEGIN
1630
	EXECUTE $$
1631
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1632
  RETURNS SETOF $$||view_||$$
1633
  SET enable_sort TO 'off'
1634
  AS
1635
$BODY1$
1636
SELECT * FROM $$||view_qual_name||$$($2, $3)
1637
$BODY1$
1638
  LANGUAGE sql STABLE
1639
  COST 100
1640
  ROWS 1000
1641
;
1642
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1643
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1644
If you want to run EXPLAIN and get expanded output, use the regular subset
1645
function instead. (When a config param is set on a function, EXPLAIN produces
1646
just a function scan.)
1647
';
1648
$$;
1649
END;
1650
$_$;
1651

    
1652

    
1653
--
1654
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1655
--
1656

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

    
1659

    
1660
--
1661
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1662
--
1663

    
1664
CREATE FUNCTION name(type regtype) RETURNS text
1665
    LANGUAGE sql STABLE STRICT
1666
    AS $_$
1667
SELECT typname::text FROM pg_type WHERE oid = $1
1668
$_$;
1669

    
1670

    
1671
--
1672
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1673
--
1674

    
1675
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1676
    LANGUAGE sql IMMUTABLE
1677
    AS $_$
1678
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1679
$_$;
1680

    
1681

    
1682
--
1683
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1684
--
1685

    
1686
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1687
    LANGUAGE sql IMMUTABLE
1688
    AS $_$
1689
SELECT $1 IS NOT NULL
1690
$_$;
1691

    
1692

    
1693
--
1694
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1695
--
1696

    
1697
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1698
    LANGUAGE sql IMMUTABLE
1699
    AS $_$
1700
SELECT util.hstore($1, NULL) || '*=>*'
1701
$_$;
1702

    
1703

    
1704
--
1705
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1706
--
1707

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

    
1710

    
1711
--
1712
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1713
--
1714

    
1715
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1716
    LANGUAGE sql IMMUTABLE
1717
    AS $_$
1718
SELECT $2 + COALESCE($1, 0)
1719
$_$;
1720

    
1721

    
1722
--
1723
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1724
--
1725

    
1726
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1727
    LANGUAGE sql STABLE
1728
    AS $_$
1729
SELECT util.type_qual_name($1::text::regtype)
1730
$_$;
1731

    
1732

    
1733
--
1734
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1735
--
1736

    
1737
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1738
    LANGUAGE plpgsql IMMUTABLE STRICT
1739
    AS $$
1740
BEGIN
1741
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1742
END;
1743
$$;
1744

    
1745

    
1746
--
1747
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
1748
--
1749

    
1750
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
1751
    LANGUAGE sql IMMUTABLE
1752
    AS $_$
1753
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
1754
$_$;
1755

    
1756

    
1757
--
1758
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1759
--
1760

    
1761
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1762
    LANGUAGE sql STRICT
1763
    AS $_$
1764
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1765
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1766
FROM util.col_names($1::text::regtype) f (name);
1767
SELECT NULL::void; -- don't fold away functions called in previous query
1768
$_$;
1769

    
1770

    
1771
--
1772
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1773
--
1774

    
1775
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1776

    
1777

    
1778
--
1779
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1780
--
1781

    
1782
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1783
    LANGUAGE sql STRICT
1784
    AS $_$
1785
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1786
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1787
SELECT util.set_col_names($1, $2);
1788
$_$;
1789

    
1790

    
1791
--
1792
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1793
--
1794

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

    
1798

    
1799
--
1800
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1801
--
1802

    
1803
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1804
    LANGUAGE sql STRICT
1805
    AS $_$
1806
SELECT util.drop_table($1);
1807
SELECT util.mk_map_table($1);
1808
$_$;
1809

    
1810

    
1811
--
1812
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1813
--
1814

    
1815
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
1816
    LANGUAGE plpgsql STRICT
1817
    AS $_$
1818
DECLARE
1819
	result text = NULL;
1820
BEGIN
1821
	BEGIN
1822
		result = util.show_create_view(view_);
1823
		PERFORM util.eval($$DROP VIEW $$||view_);
1824
	EXCEPTION
1825
		WHEN undefined_table THEN NULL;
1826
	END;
1827
	RETURN result;
1828
END;
1829
$_$;
1830

    
1831

    
1832
--
1833
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
1834
--
1835

    
1836
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
1837
    LANGUAGE sql
1838
    AS $_$
1839
SELECT concat(util.save_drop_view(unnest)) FROM unnest($1)
1840
$_$;
1841

    
1842

    
1843
--
1844
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1845
--
1846

    
1847
CREATE FUNCTION schema(type regtype) RETURNS text
1848
    LANGUAGE sql STABLE
1849
    AS $_$
1850
SELECT nspname::text
1851
FROM pg_type
1852
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1853
WHERE pg_type.oid = $1
1854
$_$;
1855

    
1856

    
1857
--
1858
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1859
--
1860

    
1861
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1862
    LANGUAGE sql STABLE
1863
    AS $_$
1864
SELECT util.schema(pg_typeof($1))
1865
$_$;
1866

    
1867

    
1868
--
1869
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1870
--
1871

    
1872
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1873
    LANGUAGE sql STABLE
1874
    AS $_$
1875
SELECT quote_ident(util.schema($1))
1876
$_$;
1877

    
1878

    
1879
--
1880
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1881
--
1882

    
1883
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1884
    LANGUAGE sql STRICT
1885
    AS $_$
1886
SELECT util.eval(
1887
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1888
$_$;
1889

    
1890

    
1891
--
1892
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1893
--
1894

    
1895
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1896
    LANGUAGE plpgsql STRICT
1897
    AS $_$
1898
DECLARE
1899
    old text[] = ARRAY(SELECT util.col_names(table_));
1900
    new text[] = ARRAY(SELECT util.map_values(names));
1901
BEGIN
1902
    old = old[1:array_length(new, 1)]; -- truncate to same length
1903
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1904
||$$ TO $$||quote_ident(value))
1905
    FROM each(hstore(old, new))
1906
    WHERE value != key -- not same name
1907
    ;
1908
END;
1909
$_$;
1910

    
1911

    
1912
--
1913
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1914
--
1915

    
1916
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1917

    
1918

    
1919
--
1920
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1921
--
1922

    
1923
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1924
    LANGUAGE plpgsql STRICT
1925
    AS $_$
1926
DECLARE
1927
	row_ util.map;
1928
BEGIN
1929
	-- rename any metadata cols rather than re-adding them with new names
1930
	BEGIN
1931
		PERFORM util.set_col_names(table_, names);
1932
	EXCEPTION
1933
		WHEN array_subscript_error THEN -- selective suppress
1934
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
1935
				-- metadata cols not yet added
1936
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
1937
			END IF;
1938
	END;
1939
	
1940
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1941
	LOOP
1942
		PERFORM util.mk_const_col((table_, row_."to"),
1943
			substring(row_."from" from 2));
1944
	END LOOP;
1945
	
1946
	PERFORM util.set_col_names(table_, names);
1947
END;
1948
$_$;
1949

    
1950

    
1951
--
1952
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1953
--
1954

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

    
1958

    
1959
--
1960
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1961
--
1962

    
1963
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1964
    LANGUAGE plpgsql STRICT
1965
    AS $_$
1966
DECLARE
1967
    sql text = $$ALTER TABLE $$||table_||$$
1968
$$||NULLIF(array_to_string(ARRAY(
1969
    SELECT
1970
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1971
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1972
    FROM
1973
    (
1974
        SELECT
1975
          quote_ident(col_name) AS col_name_sql
1976
        , util.col_type((table_, col_name)) AS curr_type
1977
        , type AS target_type
1978
        FROM unnest(col_casts)
1979
    ) s
1980
    WHERE curr_type != target_type
1981
), '
1982
, '), '');
1983
BEGIN
1984
    RAISE NOTICE '%', sql;
1985
    EXECUTE COALESCE(sql, '');
1986
END;
1987
$_$;
1988

    
1989

    
1990
--
1991
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1992
--
1993

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

    
1996

    
1997
--
1998
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1999
--
2000

    
2001
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2002
    LANGUAGE sql STABLE
2003
    AS $_$
2004
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2005
$$||util.show_grants_for($1)
2006
$_$;
2007

    
2008

    
2009
--
2010
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2011
--
2012

    
2013
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2014
    LANGUAGE sql STABLE
2015
    AS $_$
2016
SELECT concat(cmd)
2017
FROM
2018
(
2019
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2020
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2021
$$ ELSE '' END) AS cmd
2022
	FROM util.grants_users() f (user_)
2023
) s
2024
$_$;
2025

    
2026

    
2027
--
2028
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2029
--
2030

    
2031
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2032
    LANGUAGE plpgsql STABLE STRICT
2033
    AS $_$
2034
DECLARE
2035
    hstore hstore;
2036
BEGIN
2037
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2038
        table_||$$))$$ INTO STRICT hstore;
2039
    RETURN hstore;
2040
END;
2041
$_$;
2042

    
2043

    
2044
--
2045
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2046
--
2047

    
2048
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2049
    LANGUAGE sql STABLE STRICT
2050
    AS $_$
2051
SELECT COUNT(*) > 0 FROM pg_constraint
2052
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2053
$_$;
2054

    
2055

    
2056
--
2057
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2058
--
2059

    
2060
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';
2061

    
2062

    
2063
--
2064
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2065
--
2066

    
2067
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2068
    LANGUAGE sql STRICT
2069
    AS $_$
2070
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2071
||quote_ident($2)||$$ CHECK (true)$$)
2072
$_$;
2073

    
2074

    
2075
--
2076
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2077
--
2078

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

    
2082

    
2083
--
2084
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2085
--
2086

    
2087
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2088
    LANGUAGE sql STABLE STRICT
2089
    AS $_$
2090
SELECT util.table_flag__get($1, 'nulls_mapped')
2091
$_$;
2092

    
2093

    
2094
--
2095
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2096
--
2097

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

    
2100

    
2101
--
2102
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2103
--
2104

    
2105
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2106
    LANGUAGE sql STRICT
2107
    AS $_$
2108
SELECT util.table_flag__set($1, 'nulls_mapped')
2109
$_$;
2110

    
2111

    
2112
--
2113
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2114
--
2115

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

    
2119

    
2120
--
2121
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2122
--
2123

    
2124
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
2125
    LANGUAGE sql STABLE STRICT
2126
    AS $_$
2127
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
2128
$_$;
2129

    
2130

    
2131
--
2132
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2133
--
2134

    
2135
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2136
    LANGUAGE plpgsql STRICT
2137
    AS $_$
2138
DECLARE
2139
    row record;
2140
BEGIN
2141
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2142
    LOOP
2143
        IF row.global_name != row.name THEN
2144
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2145
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2146
        END IF;
2147
    END LOOP;
2148
END;
2149
$_$;
2150

    
2151

    
2152
--
2153
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2154
--
2155

    
2156
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
2157

    
2158

    
2159
--
2160
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2161
--
2162

    
2163
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2164
    LANGUAGE sql STRICT
2165
    AS $_$
2166
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2167
SELECT NULL::void; -- don't fold away functions called in previous query
2168
$_$;
2169

    
2170

    
2171
--
2172
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2173
--
2174

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

    
2178

    
2179
--
2180
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2181
--
2182

    
2183
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2184
    LANGUAGE plpgsql STRICT
2185
    AS $_$
2186
BEGIN
2187
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2188
END;
2189
$_$;
2190

    
2191

    
2192
--
2193
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2194
--
2195

    
2196
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
2197

    
2198

    
2199
--
2200
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2201
--
2202

    
2203
CREATE FUNCTION try_create(sql text) RETURNS void
2204
    LANGUAGE plpgsql STRICT
2205
    AS $$
2206
BEGIN
2207
    PERFORM util.eval(sql);
2208
EXCEPTION
2209
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2210
    WHEN undefined_column THEN NULL;
2211
    WHEN duplicate_column THEN NULL;
2212
END;
2213
$$;
2214

    
2215

    
2216
--
2217
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2218
--
2219

    
2220
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
2221

    
2222

    
2223
--
2224
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2225
--
2226

    
2227
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2228
    LANGUAGE sql STRICT
2229
    AS $_$
2230
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2231
$_$;
2232

    
2233

    
2234
--
2235
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2236
--
2237

    
2238
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
2239

    
2240

    
2241
--
2242
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2243
--
2244

    
2245
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2246
    LANGUAGE sql IMMUTABLE
2247
    AS $_$
2248
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2249
$_$;
2250

    
2251

    
2252
--
2253
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2254
--
2255

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

    
2258

    
2259
--
2260
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2261
--
2262

    
2263
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2264
    LANGUAGE sql STABLE STRICT
2265
    SET search_path TO pg_temp
2266
    AS $_$
2267
SELECT $1::text
2268
$_$;
2269

    
2270

    
2271
--
2272
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2273
--
2274

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

    
2277

    
2278
--
2279
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2280
--
2281

    
2282
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2283
    LANGUAGE plpgsql STABLE
2284
    AS $_$
2285
DECLARE
2286
    type regtype;
2287
BEGIN
2288
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2289
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2290
    RETURN type;
2291
END;
2292
$_$;
2293

    
2294

    
2295
--
2296
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2297
--
2298

    
2299
CREATE AGGREGATE all_same(anyelement) (
2300
    SFUNC = all_same_transform,
2301
    STYPE = anyarray,
2302
    FINALFUNC = all_same_final
2303
);
2304

    
2305

    
2306
--
2307
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2308
--
2309

    
2310
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2311

    
2312

    
2313
--
2314
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2315
--
2316

    
2317
CREATE AGGREGATE join_strs(text, text) (
2318
    SFUNC = join_strs_transform,
2319
    STYPE = text
2320
);
2321

    
2322

    
2323
--
2324
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2325
--
2326

    
2327
CREATE OPERATOR -> (
2328
    PROCEDURE = map_get,
2329
    LEFTARG = regclass,
2330
    RIGHTARG = text
2331
);
2332

    
2333

    
2334
--
2335
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2336
--
2337

    
2338
CREATE OPERATOR => (
2339
    PROCEDURE = hstore,
2340
    LEFTARG = text[],
2341
    RIGHTARG = text
2342
);
2343

    
2344

    
2345
--
2346
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2347
--
2348

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

    
2351

    
2352
--
2353
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2354
--
2355

    
2356
CREATE OPERATOR ?*>= (
2357
    PROCEDURE = is_populated_more_often_than,
2358
    LEFTARG = anyelement,
2359
    RIGHTARG = anyelement
2360
);
2361

    
2362

    
2363
--
2364
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2365
--
2366

    
2367
CREATE OPERATOR ?>= (
2368
    PROCEDURE = is_more_complete_than,
2369
    LEFTARG = anyelement,
2370
    RIGHTARG = anyelement
2371
);
2372

    
2373

    
2374
--
2375
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2376
--
2377

    
2378
CREATE OPERATOR ||% (
2379
    PROCEDURE = concat_esc,
2380
    LEFTARG = text,
2381
    RIGHTARG = text
2382
);
2383

    
2384

    
2385
--
2386
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2387
--
2388

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

    
2391

    
2392
--
2393
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2394
--
2395

    
2396
CREATE TABLE map (
2397
    "from" text NOT NULL,
2398
    "to" text,
2399
    filter text,
2400
    notes text
2401
);
2402

    
2403

    
2404
--
2405
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2406
--
2407

    
2408

    
2409

    
2410
--
2411
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2412
--
2413

    
2414

    
2415

    
2416
--
2417
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2418
--
2419

    
2420
ALTER TABLE ONLY map
2421
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2422

    
2423

    
2424
--
2425
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2426
--
2427

    
2428
ALTER TABLE ONLY map
2429
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2430

    
2431

    
2432
--
2433
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2434
--
2435

    
2436
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2437

    
2438

    
2439
--
2440
-- PostgreSQL database dump complete
2441
--
2442

    
(19-19/29)