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 '
24
IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
25

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

    
29

    
30
SET search_path = util, pg_catalog;
31

    
32
--
33
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34
--
35

    
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40

    
41

    
42
--
43
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44
--
45

    
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50

    
51

    
52
--
53
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54
--
55

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

    
63

    
64
--
65
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66
--
67

    
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72

    
73

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

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

    
84

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

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

    
104

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

    
109
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
110
_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.
111
';
112

    
113

    
114
--
115
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
116
--
117

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

    
133

    
134
--
135
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
136
--
137

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

    
152

    
153
--
154
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
155
--
156

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

    
170

    
171
--
172
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
173
--
174

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

    
181

    
182
--
183
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
184
--
185

    
186
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
187
    LANGUAGE sql IMMUTABLE
188
    AS $_$
189
SELECT $1 = $2
190
$_$;
191

    
192

    
193
--
194
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
195
--
196

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

    
205

    
206
--
207
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
208
--
209

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

    
216

    
217
--
218
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
219
--
220

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

    
227

    
228
--
229
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
230
--
231

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

    
238

    
239
--
240
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
241
--
242

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

    
249

    
250
--
251
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
252
--
253

    
254
CREATE FUNCTION _label(label text, value text) RETURNS text
255
    LANGUAGE sql IMMUTABLE
256
    AS $_$
257
SELECT coalesce($1 || ': ', '') || $2
258
$_$;
259

    
260

    
261
--
262
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
263
--
264

    
265
CREATE FUNCTION _lowercase(value text) RETURNS text
266
    LANGUAGE sql IMMUTABLE
267
    AS $_$
268
SELECT lower($1)
269
$_$;
270

    
271

    
272
--
273
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
274
--
275

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

    
286

    
287
--
288
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
289
--
290

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

    
311

    
312
--
313
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
314
--
315

    
316
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
317
    LANGUAGE sql IMMUTABLE
318
    AS $_$
319
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
320
$_$;
321

    
322

    
323
--
324
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
325
--
326

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

    
361

    
362
--
363
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
364
--
365

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

    
372

    
373
--
374
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
375
--
376

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

    
411

    
412
--
413
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
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
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
420
$_$;
421

    
422

    
423
--
424
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
425
--
426

    
427
CREATE FUNCTION _not(value boolean) RETURNS boolean
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT NOT $1
431
$_$;
432

    
433

    
434
--
435
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
436
--
437

    
438
CREATE FUNCTION _now() RETURNS timestamp with time zone
439
    LANGUAGE sql STABLE
440
    AS $$
441
SELECT now()
442
$$;
443

    
444

    
445
--
446
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
447
--
448

    
449
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
450
    LANGUAGE sql IMMUTABLE
451
    AS $_$
452
SELECT util."_nullIf"($1, $2, $3::util.datatype)
453
$_$;
454

    
455

    
456
--
457
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
458
--
459

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

    
481

    
482
--
483
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
484
--
485

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

    
501

    
502
--
503
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
504
--
505

    
506
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
507
_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.
508
';
509

    
510

    
511
--
512
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
513
--
514

    
515
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
516
    LANGUAGE sql IMMUTABLE
517
    AS $_$
518
SELECT $2 - $1
519
$_$;
520

    
521

    
522
--
523
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
524
--
525

    
526
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
527
    LANGUAGE sql IMMUTABLE
528
    AS $_$
529
SELECT regexp_split_to_table($1, $2)
530
$_$;
531

    
532

    
533
--
534
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
535
--
536

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

    
550

    
551
--
552
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
553
--
554

    
555
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
556
gets table_''s added columns (all the columns not in the original data)
557
';
558

    
559

    
560
--
561
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
562
--
563

    
564
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
565
    LANGUAGE sql IMMUTABLE
566
    AS $_$
567
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
568
$_$;
569

    
570

    
571
--
572
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
573
--
574

    
575
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
576
    LANGUAGE plpgsql IMMUTABLE
577
    AS $$
578
DECLARE
579
	value_cmp         state%TYPE = ARRAY[value];
580
	state             state%TYPE = COALESCE(state, value_cmp);
581
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
582
BEGIN
583
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
584
END;
585
$$;
586

    
587

    
588
--
589
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
590
--
591

    
592
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
593
    LANGUAGE sql IMMUTABLE
594
    AS $_$
595
SELECT pg_catalog.array_fill($1, ARRAY[$2])
596
$_$;
597

    
598

    
599
--
600
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
604
    LANGUAGE sql IMMUTABLE
605
    AS $_$
606
SELECT util.array_length($1, 1)
607
$_$;
608

    
609

    
610
--
611
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
612
--
613

    
614
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
618
$_$;
619

    
620

    
621
--
622
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
623
--
624

    
625
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
626
returns 0 instead of NULL for empty arrays
627
';
628

    
629

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

    
634
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
635
    LANGUAGE sql STABLE STRICT
636
    AS $_$
637
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
638
$_$;
639

    
640

    
641
--
642
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
643
--
644

    
645
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
646
    LANGUAGE plpgsql STRICT
647
    AS $_$
648
BEGIN
649
    -- not yet clustered (ARRAY[] compares NULLs literally)
650
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
651
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
652
    END IF;
653
END;
654
$_$;
655

    
656

    
657
--
658
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
659
--
660

    
661
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
662
idempotent
663
';
664

    
665

    
666
--
667
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
668
--
669

    
670
CREATE FUNCTION col__min(col col_ref) RETURNS integer
671
    LANGUAGE sql STABLE
672
    AS $_$
673
SELECT util.eval2val($$
674
SELECT $$||quote_ident($1.name)||$$
675
FROM $$||$1.table_||$$
676
ORDER BY $$||quote_ident($1.name)||$$ ASC
677
LIMIT 1
678
$$, NULL::integer)
679
$_$;
680

    
681

    
682
--
683
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
684
--
685

    
686
CREATE FUNCTION col_comment(col col_ref) RETURNS text
687
    LANGUAGE plpgsql STABLE STRICT
688
    AS $$
689
DECLARE
690
	comment text;
691
BEGIN
692
	SELECT description
693
	FROM pg_attribute
694
	LEFT JOIN pg_description ON objoid = attrelid
695
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
696
	WHERE attrelid = col.table_ AND attname = col.name
697
	INTO STRICT comment
698
	;
699
	RETURN comment;
700
EXCEPTION
701
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
702
END;
703
$$;
704

    
705

    
706
--
707
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
708
--
709

    
710
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
711
    LANGUAGE plpgsql STABLE STRICT
712
    AS $$
713
DECLARE
714
	default_sql text;
715
BEGIN
716
	SELECT adsrc
717
	FROM pg_attribute
718
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
719
	WHERE attrelid = col.table_ AND attname = col.name
720
	INTO STRICT default_sql
721
	;
722
	RETURN default_sql;
723
EXCEPTION
724
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
725
END;
726
$$;
727

    
728

    
729
--
730
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
731
--
732

    
733
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
734
    LANGUAGE sql STABLE
735
    AS $_$
736
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
737
$_$;
738

    
739

    
740
--
741
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
742
--
743

    
744
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
745
ret_type_null: NULL::ret_type
746
';
747

    
748

    
749
--
750
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
751
--
752

    
753
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
754
    LANGUAGE plpgsql STRICT
755
    AS $$
756
BEGIN
757
    PERFORM util.col_type(col);
758
    RETURN true;
759
EXCEPTION
760
    WHEN undefined_column THEN RETURN false;
761
END;
762
$$;
763

    
764

    
765
--
766
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
767
--
768

    
769
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
770
    LANGUAGE plpgsql STABLE STRICT
771
    AS $$
772
DECLARE
773
    prefix text := util.name(type)||'.';
774
BEGIN
775
    RETURN QUERY
776
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
777
        FROM util.col_names(type) f (name_);
778
END;
779
$$;
780

    
781

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

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

    
795

    
796
--
797
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
798
--
799

    
800
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
801
    LANGUAGE plpgsql STABLE STRICT
802
    AS $_$
803
BEGIN
804
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
805
END;
806
$_$;
807

    
808

    
809
--
810
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
811
--
812

    
813
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
814
    LANGUAGE plpgsql STABLE STRICT
815
    AS $$
816
DECLARE
817
    type regtype;
818
BEGIN
819
    SELECT atttypid FROM pg_attribute
820
    WHERE attrelid = col.table_ AND attname = col.name
821
    INTO STRICT type
822
    ;
823
    RETURN type;
824
EXCEPTION
825
    WHEN no_data_found THEN
826
        RAISE undefined_column USING MESSAGE =
827
            concat('undefined column: ', col.name);
828
END;
829
$$;
830

    
831

    
832
--
833
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
834
--
835

    
836
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
837
    LANGUAGE sql IMMUTABLE
838
    AS $_$
839
SELECT util.esc_name__append($2, $1)
840
$_$;
841

    
842

    
843
--
844
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
845
--
846

    
847
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
848
    LANGUAGE sql IMMUTABLE
849
    AS $_$
850
SELECT position($1 in $2) > 0 /*1-based offset*/
851
$_$;
852

    
853

    
854
--
855
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
856
--
857

    
858
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
859
    LANGUAGE plpgsql STRICT
860
    AS $$
861
BEGIN
862
    PERFORM util.eval(sql);
863
EXCEPTION
864
    WHEN duplicate_table  THEN NULL;
865
    WHEN duplicate_object THEN NULL; -- e.g. constraint
866
    WHEN duplicate_column THEN NULL;
867
    WHEN invalid_table_definition THEN
868
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
869
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
870
        END IF;
871
END;
872
$$;
873

    
874

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

    
879
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
880
idempotent
881
';
882

    
883

    
884
--
885
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
886
--
887

    
888
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
889
    LANGUAGE sql IMMUTABLE
890
    AS $_$
891
/* newline before so the query starts at the beginning of the line.
892
newline after to visually separate queries from one another. */
893
SELECT util.raise_notice($$
894
$$||$1||$$
895
$$)
896
$_$;
897

    
898

    
899
--
900
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
901
--
902

    
903
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
904
    LANGUAGE sql STABLE STRICT
905
    AS $_$
906
SELECT util.eval2set($$
907
SELECT col
908
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
909
LEFT JOIN $$||$2||$$ ON "to" = col
910
WHERE "from" IS NULL
911
$$, NULL::text)
912
$_$;
913

    
914

    
915
--
916
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
917
--
918

    
919
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
920
gets table_''s derived columns (all the columns not in the names table)
921
';
922

    
923

    
924
--
925
-- Name: diff_any(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
926
--
927

    
928
CREATE FUNCTION diff_any(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
929
    LANGUAGE sql STABLE
930
    AS $_$
931
SELECT * FROM
932
util.eval2col_pair($$
933
SELECT left_, right_
934
FROM      $$||$1||$$ left_
935
FULL JOIN $$||$2||$$ right_
936
ON left_ = right_
937
WHERE left_ IS DISTINCT FROM right_
938
ORDER BY left_, right_
939
$$, $3)
940
$_$;
941

    
942

    
943
--
944
-- Name: FUNCTION diff_any(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
945
--
946

    
947
COMMENT ON FUNCTION diff_any(left_ text, right_ text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
948
col_type_null (*required*): NULL::col_type
949
';
950

    
951

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

    
956
CREATE FUNCTION diff_queries(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
957
    LANGUAGE sql STABLE
958
    AS $_$
959
SELECT * FROM util.diff_any('('||$1||')', '('||$2||')', $3)
960
$_$;
961

    
962

    
963
--
964
-- Name: FUNCTION diff_queries(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
965
--
966

    
967
COMMENT ON FUNCTION diff_queries(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
968
col_type_null (*required*): NULL::col_type
969
usage:
970
SELECT * FROM util.diff_queries($$VALUES (''1''), (''2''), (''4'')$$, $$VALUES (''1''), (''3''), (''4'')$$, NULL::text)
971

    
972
to run EXPLAIN on the FULL JOIN query:
973
# run this function
974
# look for a NOTICE containing the expanded query that it ran
975
# run EXPLAIN on this expanded query
976
';
977

    
978

    
979
--
980
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
981
--
982

    
983
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
984
    LANGUAGE sql STABLE
985
    AS $_$
986
SELECT * FROM util.diff_any($1::text, $2::text, $3)
987
$_$;
988

    
989

    
990
--
991
-- Name: FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
992
--
993

    
994
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
995
col_type_null (*required*): NULL::col_type
996
usage:
997
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
998
';
999

    
1000

    
1001
--
1002
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1003
--
1004

    
1005
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1006
    LANGUAGE sql STRICT
1007
    AS $_$
1008
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1009
$_$;
1010

    
1011

    
1012
--
1013
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1014
--
1015

    
1016
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1017
idempotent
1018
';
1019

    
1020

    
1021
--
1022
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1023
--
1024

    
1025
CREATE FUNCTION drop_column(col col_ref) RETURNS void
1026
    LANGUAGE sql STRICT
1027
    AS $_$
1028
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1029
quote_ident($1.name))
1030
$_$;
1031

    
1032

    
1033
--
1034
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
1035
--
1036

    
1037
COMMENT ON FUNCTION drop_column(col col_ref) IS '
1038
idempotent
1039
';
1040

    
1041

    
1042
--
1043
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
1044
--
1045

    
1046
CREATE FUNCTION drop_table(table_ text) RETURNS void
1047
    LANGUAGE sql STRICT
1048
    AS $_$
1049
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
1050
$_$;
1051

    
1052

    
1053
--
1054
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
1055
--
1056

    
1057
COMMENT ON FUNCTION drop_table(table_ text) IS '
1058
idempotent
1059
';
1060

    
1061

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

    
1066
CREATE FUNCTION drop_view(view_ text) RETURNS void
1067
    LANGUAGE sql STRICT
1068
    AS $_$
1069
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1)
1070
$_$;
1071

    
1072

    
1073
--
1074
-- Name: FUNCTION drop_view(view_ text); Type: COMMENT; Schema: util; Owner: -
1075
--
1076

    
1077
COMMENT ON FUNCTION drop_view(view_ text) IS '
1078
idempotent
1079
';
1080

    
1081

    
1082
--
1083
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1084
--
1085

    
1086
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1087
    LANGUAGE sql IMMUTABLE
1088
    AS $_$
1089
SELECT util.array_fill($1, 0)
1090
$_$;
1091

    
1092

    
1093
--
1094
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1095
--
1096

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

    
1101

    
1102
--
1103
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1104
--
1105

    
1106
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1107
    LANGUAGE sql IMMUTABLE
1108
    AS $_$
1109
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1110
$_$;
1111

    
1112

    
1113
--
1114
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1115
--
1116

    
1117
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1118
    LANGUAGE sql IMMUTABLE
1119
    AS $_$
1120
SELECT regexp_replace($2, '("?)$', $1||'\1')
1121
$_$;
1122

    
1123

    
1124
--
1125
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1126
--
1127

    
1128
CREATE FUNCTION eval(sql text) RETURNS void
1129
    LANGUAGE plpgsql STRICT
1130
    AS $$
1131
BEGIN
1132
	PERFORM util.debug_print_sql(sql);
1133
	EXECUTE sql;
1134
END;
1135
$$;
1136

    
1137

    
1138
--
1139
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1140
--
1141

    
1142
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1143
    LANGUAGE plpgsql
1144
    AS $$
1145
BEGIN
1146
	PERFORM util.debug_print_sql(sql);
1147
	RETURN QUERY EXECUTE sql;
1148
END;
1149
$$;
1150

    
1151

    
1152
--
1153
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1154
--
1155

    
1156
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1157
col_type_null (*required*): NULL::col_type
1158
';
1159

    
1160

    
1161
--
1162
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1163
--
1164

    
1165
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1166
    LANGUAGE plpgsql
1167
    AS $$
1168
BEGIN
1169
	PERFORM util.debug_print_sql(sql);
1170
	RETURN QUERY EXECUTE sql;
1171
END;
1172
$$;
1173

    
1174

    
1175
--
1176
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1177
--
1178

    
1179
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1180
ret_type_null: NULL::ret_type
1181
';
1182

    
1183

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

    
1188
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1189
    LANGUAGE plpgsql
1190
    AS $$
1191
DECLARE
1192
	ret_val ret_type_null%TYPE;
1193
BEGIN
1194
	PERFORM util.debug_print_sql(sql);
1195
	EXECUTE sql INTO STRICT ret_val;
1196
	RETURN ret_val;
1197
END;
1198
$$;
1199

    
1200

    
1201
--
1202
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1203
--
1204

    
1205
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1206
ret_type_null: NULL::ret_type
1207
';
1208

    
1209

    
1210
--
1211
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1212
--
1213

    
1214
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1215
    LANGUAGE sql
1216
    AS $_$
1217
SELECT util.eval2val($$SELECT $$||$1, $2)
1218
$_$;
1219

    
1220

    
1221
--
1222
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1223
--
1224

    
1225
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1226
ret_type_null: NULL::ret_type
1227
';
1228

    
1229

    
1230
--
1231
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1232
--
1233

    
1234
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1235
    LANGUAGE sql
1236
    AS $_$
1237
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1238
$_$;
1239

    
1240

    
1241
--
1242
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1243
--
1244

    
1245
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1246
sql: can be NULL, which will be passed through
1247
ret_type_null: NULL::ret_type
1248
';
1249

    
1250

    
1251
--
1252
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1253
--
1254

    
1255
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1256
    LANGUAGE sql STABLE STRICT
1257
    AS $_$
1258
SELECT col_name
1259
FROM unnest($2) s (col_name)
1260
WHERE util.col_exists(($1, col_name))
1261
$_$;
1262

    
1263

    
1264
--
1265
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1266
--
1267

    
1268
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1269
    LANGUAGE sql
1270
    AS $_$
1271
SELECT util.eval2set($$EXPLAIN $$||$1)
1272
$_$;
1273

    
1274

    
1275
--
1276
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1277
--
1278

    
1279
CREATE FUNCTION explain2notice(sql text) RETURNS void
1280
    LANGUAGE plpgsql
1281
    AS $_$
1282
BEGIN
1283
	RAISE NOTICE '%', $$EXPLAIN:
1284
$$||util.explain2str(sql);
1285
END;
1286
$_$;
1287

    
1288

    
1289
--
1290
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1291
--
1292

    
1293
CREATE FUNCTION explain2str(sql text) RETURNS text
1294
    LANGUAGE sql
1295
    AS $_$
1296
SELECT util.join_strs(explain, $$
1297
$$) FROM util.explain($1)
1298
$_$;
1299

    
1300

    
1301
SET default_tablespace = '';
1302

    
1303
SET default_with_oids = false;
1304

    
1305
--
1306
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1307
--
1308

    
1309
CREATE TABLE explain (
1310
    line text NOT NULL
1311
);
1312

    
1313

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

    
1318
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1319
    LANGUAGE sql
1320
    AS $_$
1321
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1322
$$||quote_nullable($1)||$$
1323
)$$)
1324
$_$;
1325

    
1326

    
1327
--
1328
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1329
--
1330

    
1331
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1332
usage:
1333
PERFORM util.explain2table($$
1334
query
1335
$$);
1336
';
1337

    
1338

    
1339
--
1340
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1341
--
1342

    
1343
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1344
    LANGUAGE sql IMMUTABLE
1345
    AS $_$
1346
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1347
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1348
) END
1349
$_$;
1350

    
1351

    
1352
--
1353
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1354
--
1355

    
1356
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1357
ensures that an array will always have proper non-NULL dimensions
1358
';
1359

    
1360

    
1361
--
1362
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1363
--
1364

    
1365
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1366
    LANGUAGE plpgsql
1367
    AS $_$
1368
DECLARE
1369
	PG_EXCEPTION_DETAIL text;
1370
	recreate_users_cmd text = util.save_drop_views(users);
1371
BEGIN
1372
	PERFORM util.eval(cmd);
1373
	PERFORM util.eval(recreate_users_cmd);
1374
EXCEPTION
1375
WHEN dependent_objects_still_exist THEN
1376
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1377
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1378
	users = array(SELECT * FROM util.regexp_matches_group(
1379
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1380
	IF util.is_empty(users) THEN RAISE; END IF;
1381
	PERFORM util.force_recreate(cmd, users);
1382
END;
1383
$_$;
1384

    
1385

    
1386
--
1387
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1388
--
1389

    
1390
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1391
idempotent
1392

    
1393
users: not necessary to provide this because it will be autopopulated
1394
';
1395

    
1396

    
1397
--
1398
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1399
--
1400

    
1401
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1402
    LANGUAGE plpgsql STRICT
1403
    AS $_$
1404
DECLARE
1405
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1406
$$||query;
1407
BEGIN
1408
	EXECUTE mk_view;
1409
EXCEPTION
1410
WHEN invalid_table_definition THEN
1411
	IF SQLERRM = 'cannot drop columns from view'
1412
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1413
	THEN
1414
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1415
		EXECUTE mk_view;
1416
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1417
	END IF;
1418
END;
1419
$_$;
1420

    
1421

    
1422
--
1423
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1424
--
1425

    
1426
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1427
idempotent
1428
';
1429

    
1430

    
1431
--
1432
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1433
--
1434

    
1435
CREATE FUNCTION grants_users() RETURNS SETOF text
1436
    LANGUAGE sql IMMUTABLE
1437
    AS $$
1438
VALUES ('bien_read'), ('public_')
1439
$$;
1440

    
1441

    
1442
--
1443
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1444
--
1445

    
1446
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1447
    LANGUAGE sql IMMUTABLE
1448
    AS $_$
1449
SELECT substring($2 for length($1)) = $1
1450
$_$;
1451

    
1452

    
1453
--
1454
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1455
--
1456

    
1457
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1458
    LANGUAGE sql IMMUTABLE
1459
    AS $_$
1460
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1461
$_$;
1462

    
1463

    
1464
--
1465
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1466
--
1467

    
1468
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1469
avoids repeating the same value for each key
1470
';
1471

    
1472

    
1473
--
1474
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1475
--
1476

    
1477
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1478
    LANGUAGE sql IMMUTABLE
1479
    AS $_$
1480
SELECT COALESCE($1, $2)
1481
$_$;
1482

    
1483

    
1484
--
1485
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1486
--
1487

    
1488
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1489
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1490
';
1491

    
1492

    
1493
--
1494
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1495
--
1496

    
1497
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1498
    LANGUAGE sql STABLE STRICT
1499
    AS $_$
1500
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1501
$_$;
1502

    
1503

    
1504
--
1505
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1506
--
1507

    
1508
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1509
    LANGUAGE sql IMMUTABLE
1510
    AS $_$
1511
SELECT util.array_length($1) = 0
1512
$_$;
1513

    
1514

    
1515
--
1516
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1517
--
1518

    
1519
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1520
    LANGUAGE sql IMMUTABLE
1521
    AS $_$
1522
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1523
$_$;
1524

    
1525

    
1526
--
1527
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1528
--
1529

    
1530
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1531
    LANGUAGE sql IMMUTABLE
1532
    AS $_$
1533
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1534
$_$;
1535

    
1536

    
1537
--
1538
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1539
--
1540

    
1541
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1542
    LANGUAGE sql IMMUTABLE STRICT
1543
    AS $_$
1544
SELECT $1 || $3 || $2
1545
$_$;
1546

    
1547

    
1548
--
1549
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1550
--
1551

    
1552
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1553
    LANGUAGE sql IMMUTABLE
1554
    AS $_$
1555
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1556
$_$;
1557

    
1558

    
1559
--
1560
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1561
--
1562

    
1563
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1564
    LANGUAGE sql IMMUTABLE
1565
    AS $_$
1566
SELECT ltrim($1, $$
1567
$$)
1568
$_$;
1569

    
1570

    
1571
--
1572
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1573
--
1574

    
1575
CREATE FUNCTION map_filter_insert() RETURNS trigger
1576
    LANGUAGE plpgsql
1577
    AS $$
1578
BEGIN
1579
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1580
	RETURN new;
1581
END;
1582
$$;
1583

    
1584

    
1585
--
1586
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1587
--
1588

    
1589
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1590
    LANGUAGE plpgsql STABLE STRICT
1591
    AS $_$
1592
DECLARE
1593
    value text;
1594
BEGIN
1595
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1596
        INTO value USING key;
1597
    RETURN value;
1598
END;
1599
$_$;
1600

    
1601

    
1602
--
1603
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1604
--
1605

    
1606
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1607
    LANGUAGE sql IMMUTABLE
1608
    AS $_$
1609
SELECT util._map(util.nulls_map($1), $2)
1610
$_$;
1611

    
1612

    
1613
--
1614
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1615
--
1616

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

    
1620
[1] inlining of function calls, which is different from constant folding
1621
[2] _map()''s profiling query
1622
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1623
and map_nulls()''s profiling query
1624
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1625
both take ~920 ms.
1626
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.
1627
';
1628

    
1629

    
1630
--
1631
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1632
--
1633

    
1634
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1635
    LANGUAGE plpgsql STABLE STRICT
1636
    AS $_$
1637
BEGIN
1638
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1639
END;
1640
$_$;
1641

    
1642

    
1643
--
1644
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1645
--
1646

    
1647
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1648
    LANGUAGE sql
1649
    AS $_$
1650
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1651
$$||util.ltrim_nl($2))
1652
$_$;
1653

    
1654

    
1655
--
1656
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1657
--
1658

    
1659
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1660
idempotent
1661
';
1662

    
1663

    
1664
--
1665
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1666
--
1667

    
1668
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1669
    LANGUAGE sql
1670
    AS $_$
1671
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1672
$_$;
1673

    
1674

    
1675
--
1676
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1677
--
1678

    
1679
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1680
idempotent
1681
';
1682

    
1683

    
1684
--
1685
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1686
--
1687

    
1688
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1689
    LANGUAGE sql STRICT
1690
    AS $_$
1691
SELECT util.create_if_not_exists($$
1692
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1693
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1694
||quote_literal($2)||$$;
1695
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1696
constant
1697
';
1698
$$)
1699
$_$;
1700

    
1701

    
1702
--
1703
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1704
--
1705

    
1706
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1707
idempotent
1708
';
1709

    
1710

    
1711
--
1712
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1713
--
1714

    
1715
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1716
    LANGUAGE plpgsql STRICT
1717
    AS $_$
1718
DECLARE
1719
    type regtype = util.typeof(expr, col.table_::text::regtype);
1720
    col_name_sql text = quote_ident(col.name);
1721
BEGIN
1722
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1723
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1724
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1725
$$||expr||$$;
1726
$$);
1727
END;
1728
$_$;
1729

    
1730

    
1731
--
1732
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1733
--
1734

    
1735
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1736
idempotent
1737
';
1738

    
1739

    
1740
--
1741
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1742
--
1743

    
1744
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1745
    LANGUAGE sql STRICT
1746
    AS $_$
1747
SELECT util.create_if_not_exists($$
1748
CREATE TABLE $$||$1||$$
1749
(
1750
    LIKE util.map INCLUDING ALL
1751
);
1752

    
1753
CREATE TRIGGER map_filter_insert
1754
  BEFORE INSERT
1755
  ON $$||$1||$$
1756
  FOR EACH ROW
1757
  EXECUTE PROCEDURE util.map_filter_insert();
1758
$$)
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1764
--
1765

    
1766
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1767
    LANGUAGE sql IMMUTABLE
1768
    AS $_$
1769
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1770
$_$;
1771

    
1772

    
1773
--
1774
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1775
--
1776

    
1777
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1778
    LANGUAGE sql IMMUTABLE
1779
    AS $_$
1780
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1781
$_$;
1782

    
1783

    
1784
--
1785
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1786
--
1787

    
1788
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1789
usage:
1790
for *1* schema arg:
1791
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1792
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1793
';
1794

    
1795

    
1796
--
1797
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1798
--
1799

    
1800
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1801
    LANGUAGE sql IMMUTABLE
1802
    AS $_$
1803
SELECT $$SET LOCAL search_path TO $$||$1
1804
$_$;
1805

    
1806

    
1807
--
1808
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1809
--
1810

    
1811
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1812
    LANGUAGE sql STRICT
1813
    AS $_$
1814
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1815
$_$;
1816

    
1817

    
1818
--
1819
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1820
--
1821

    
1822
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1823
idempotent
1824
';
1825

    
1826

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

    
1831
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1832
    LANGUAGE plpgsql STRICT
1833
    AS $_$
1834
DECLARE
1835
	view_qual_name text = util.qual_name(view_);
1836
BEGIN
1837
	EXECUTE $$
1838
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1839
  RETURNS SETOF $$||view_||$$ AS
1840
$BODY1$
1841
SELECT * FROM $$||view_qual_name||$$
1842
ORDER BY sort_col
1843
LIMIT $1 OFFSET $2
1844
$BODY1$
1845
  LANGUAGE sql STABLE
1846
  COST 100
1847
  ROWS 1000
1848
$$;
1849
	
1850
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1851
END;
1852
$_$;
1853

    
1854

    
1855
--
1856
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1857
--
1858

    
1859
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1860
    LANGUAGE plpgsql STRICT
1861
    AS $_$
1862
DECLARE
1863
	view_qual_name text = util.qual_name(view_);
1864
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1865
BEGIN
1866
	EXECUTE $$
1867
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1868
  RETURNS integer AS
1869
$BODY1$
1870
SELECT $$||quote_ident(row_num_col)||$$
1871
FROM $$||view_qual_name||$$
1872
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1873
LIMIT 1
1874
$BODY1$
1875
  LANGUAGE sql STABLE
1876
  COST 100;
1877
$$;
1878
	
1879
	EXECUTE $$
1880
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1881
  RETURNS SETOF $$||view_||$$ AS
1882
$BODY1$
1883
SELECT * FROM $$||view_qual_name||$$
1884
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1885
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1886
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1887
ORDER BY $$||quote_ident(row_num_col)||$$
1888
$BODY1$
1889
  LANGUAGE sql STABLE
1890
  COST 100
1891
  ROWS 1000
1892
$$;
1893
	
1894
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1895
END;
1896
$_$;
1897

    
1898

    
1899
--
1900
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1901
--
1902

    
1903
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1904
    LANGUAGE plpgsql STRICT
1905
    AS $_$
1906
DECLARE
1907
	view_qual_name text = util.qual_name(view_);
1908
BEGIN
1909
	EXECUTE $$
1910
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1911
  RETURNS SETOF $$||view_||$$
1912
  SET enable_sort TO 'off'
1913
  AS
1914
$BODY1$
1915
SELECT * FROM $$||view_qual_name||$$($2, $3)
1916
$BODY1$
1917
  LANGUAGE sql STABLE
1918
  COST 100
1919
  ROWS 1000
1920
;
1921
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1922
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1923
If you want to run EXPLAIN and get expanded output, use the regular subset
1924
function instead. (When a config param is set on a function, EXPLAIN produces
1925
just a function scan.)
1926
';
1927
$$;
1928
END;
1929
$_$;
1930

    
1931

    
1932
--
1933
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1934
--
1935

    
1936
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
1937
creates subset function which turns off enable_sort
1938
';
1939

    
1940

    
1941
--
1942
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1943
--
1944

    
1945
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
1946
    LANGUAGE sql IMMUTABLE
1947
    AS $_$
1948
SELECT util.mk_set_search_path(util.schema_esc($1))
1949
$_$;
1950

    
1951

    
1952
--
1953
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
1954
--
1955

    
1956
CREATE FUNCTION name(table_ regclass) RETURNS text
1957
    LANGUAGE sql STABLE
1958
    AS $_$
1959
SELECT relname::text FROM pg_class WHERE oid = $1
1960
$_$;
1961

    
1962

    
1963
--
1964
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1965
--
1966

    
1967
CREATE FUNCTION name(type regtype) RETURNS text
1968
    LANGUAGE sql STABLE STRICT
1969
    AS $_$
1970
SELECT typname::text FROM pg_type WHERE oid = $1
1971
$_$;
1972

    
1973

    
1974
--
1975
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1976
--
1977

    
1978
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1979
    LANGUAGE sql IMMUTABLE
1980
    AS $_$
1981
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1982
$_$;
1983

    
1984

    
1985
--
1986
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1987
--
1988

    
1989
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1990
    LANGUAGE sql IMMUTABLE
1991
    AS $_$
1992
SELECT $1 IS NOT NULL
1993
$_$;
1994

    
1995

    
1996
--
1997
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1998
--
1999

    
2000
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2001
    LANGUAGE sql IMMUTABLE
2002
    AS $_$
2003
SELECT util.hstore($1, NULL) || '*=>*'
2004
$_$;
2005

    
2006

    
2007
--
2008
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2009
--
2010

    
2011
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2012
for use with _map()
2013
';
2014

    
2015

    
2016
--
2017
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2018
--
2019

    
2020
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2021
    LANGUAGE sql IMMUTABLE
2022
    AS $_$
2023
SELECT $2 + COALESCE($1, 0)
2024
$_$;
2025

    
2026

    
2027
--
2028
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2029
--
2030

    
2031
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2032
    LANGUAGE sql IMMUTABLE
2033
    AS $_$
2034
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2035
$_$;
2036

    
2037

    
2038
--
2039
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2040
--
2041

    
2042
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2043
    LANGUAGE sql STABLE STRICT
2044
    SET search_path TO pg_temp
2045
    AS $_$
2046
SELECT $1::text
2047
$_$;
2048

    
2049

    
2050
--
2051
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2052
--
2053

    
2054
CREATE FUNCTION qual_name(type regtype) RETURNS text
2055
    LANGUAGE sql STABLE STRICT
2056
    SET search_path TO pg_temp
2057
    AS $_$
2058
SELECT $1::text
2059
$_$;
2060

    
2061

    
2062
--
2063
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2064
--
2065

    
2066
COMMENT ON FUNCTION qual_name(type regtype) IS '
2067
a type''s schema-qualified name
2068
';
2069

    
2070

    
2071
--
2072
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2073
--
2074

    
2075
CREATE FUNCTION qual_name(type unknown) RETURNS text
2076
    LANGUAGE sql STABLE STRICT
2077
    AS $_$
2078
SELECT util.qual_name($1::text::regtype)
2079
$_$;
2080

    
2081

    
2082
--
2083
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2084
--
2085

    
2086
CREATE FUNCTION raise_notice(msg text) RETURNS void
2087
    LANGUAGE plpgsql IMMUTABLE STRICT
2088
    AS $$
2089
BEGIN
2090
	RAISE NOTICE '%', msg;
2091
END;
2092
$$;
2093

    
2094

    
2095
--
2096
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2097
--
2098

    
2099
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2100
    LANGUAGE plpgsql IMMUTABLE STRICT
2101
    AS $$
2102
BEGIN
2103
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2104
END;
2105
$$;
2106

    
2107

    
2108
--
2109
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2110
--
2111

    
2112
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2113
    LANGUAGE sql IMMUTABLE
2114
    AS $_$
2115
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2116
$_$;
2117

    
2118

    
2119
--
2120
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2121
--
2122

    
2123
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2124
    LANGUAGE sql
2125
    AS $_$
2126
SELECT util.drop_table($1);
2127
SELECT util.materialize_query($1, $2);
2128
$_$;
2129

    
2130

    
2131
--
2132
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2133
--
2134

    
2135
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2136
idempotent, but repeats action each time
2137
';
2138

    
2139

    
2140
--
2141
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2142
--
2143

    
2144
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2145
    LANGUAGE sql
2146
    AS $_$
2147
SELECT util.drop_table($1);
2148
SELECT util.materialize_view($1, $2);
2149
$_$;
2150

    
2151

    
2152
--
2153
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2154
--
2155

    
2156
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2157
idempotent, but repeats action each time
2158
';
2159

    
2160

    
2161
--
2162
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2163
--
2164

    
2165
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2166
    LANGUAGE sql STRICT
2167
    AS $_$
2168
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2169
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2170
FROM util.col_names($1::text::regtype) f (name);
2171
SELECT NULL::void; -- don't fold away functions called in previous query
2172
$_$;
2173

    
2174

    
2175
--
2176
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2177
--
2178

    
2179
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2180
idempotent
2181
';
2182

    
2183

    
2184
--
2185
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2186
--
2187

    
2188
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2189
    LANGUAGE sql STRICT
2190
    AS $_$
2191
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2192
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2193
SELECT util.set_col_names($1, $2);
2194
$_$;
2195

    
2196

    
2197
--
2198
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2199
--
2200

    
2201
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2202
idempotent.
2203
alters the names table, so it will need to be repopulated after running this function.
2204
';
2205

    
2206

    
2207
--
2208
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2209
--
2210

    
2211
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2212
    LANGUAGE sql STRICT
2213
    AS $_$
2214
SELECT util.drop_table($1);
2215
SELECT util.mk_map_table($1);
2216
$_$;
2217

    
2218

    
2219
--
2220
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2221
--
2222

    
2223
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2224
    LANGUAGE plpgsql STRICT
2225
    AS $_$
2226
DECLARE
2227
	result text = NULL;
2228
BEGIN
2229
	BEGIN
2230
		result = util.show_create_view(view_);
2231
		PERFORM util.eval($$DROP VIEW $$||view_);
2232
	EXCEPTION
2233
		WHEN undefined_table THEN NULL;
2234
	END;
2235
	RETURN result;
2236
END;
2237
$_$;
2238

    
2239

    
2240
--
2241
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2242
--
2243

    
2244
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2245
    LANGUAGE sql
2246
    AS $_$
2247
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2248
$_$;
2249

    
2250

    
2251
--
2252
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2253
--
2254

    
2255
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2256
    LANGUAGE sql STABLE
2257
    AS $_$
2258
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2259
$_$;
2260

    
2261

    
2262
--
2263
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2264
--
2265

    
2266
CREATE FUNCTION schema(table_ regclass) RETURNS text
2267
    LANGUAGE sql STABLE
2268
    AS $_$
2269
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2270
$_$;
2271

    
2272

    
2273
--
2274
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION schema(type regtype) RETURNS text
2278
    LANGUAGE sql STABLE
2279
    AS $_$
2280
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2281
$_$;
2282

    
2283

    
2284
--
2285
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2286
--
2287

    
2288
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2289
    LANGUAGE sql STABLE
2290
    AS $_$
2291
SELECT util.schema(pg_typeof($1))
2292
$_$;
2293

    
2294

    
2295
--
2296
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2297
--
2298

    
2299
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2300
    LANGUAGE sql STABLE
2301
    AS $_$
2302
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2303
$_$;
2304

    
2305

    
2306
--
2307
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2308
--
2309

    
2310
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2311
a schema bundle is a group of schemas with a common prefix
2312
';
2313

    
2314

    
2315
--
2316
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2317
--
2318

    
2319
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2320
    LANGUAGE sql
2321
    AS $_$
2322
SELECT util.schema_rename(old_schema,
2323
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2324
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2325
SELECT NULL::void; -- don't fold away functions called in previous query
2326
$_$;
2327

    
2328

    
2329
--
2330
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2331
--
2332

    
2333
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2334
    LANGUAGE plpgsql
2335
    AS $$
2336
BEGIN
2337
	-- don't schema_bundle_rm() the schema_bundle to keep!
2338
	IF replace = with_ THEN RETURN; END IF;
2339
	
2340
	PERFORM util.schema_bundle_rm(replace);
2341
	PERFORM util.schema_bundle_rename(with_, replace);
2342
END;
2343
$$;
2344

    
2345

    
2346
--
2347
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2348
--
2349

    
2350
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2351
    LANGUAGE sql
2352
    AS $_$
2353
SELECT util.schema_rm(schema)
2354
FROM util.schema_bundle_get_schemas($1) f (schema);
2355
SELECT NULL::void; -- don't fold away functions called in previous query
2356
$_$;
2357

    
2358

    
2359
--
2360
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2361
--
2362

    
2363
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2364
    LANGUAGE sql STABLE
2365
    AS $_$
2366
SELECT quote_ident(util.schema($1))
2367
$_$;
2368

    
2369

    
2370
--
2371
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2372
--
2373

    
2374
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2375
    LANGUAGE sql
2376
    AS $_$
2377
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2378
$_$;
2379

    
2380

    
2381
--
2382
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2383
--
2384

    
2385
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2386
    LANGUAGE plpgsql
2387
    AS $$
2388
BEGIN
2389
	-- don't schema_rm() the schema to keep!
2390
	IF replace = with_ THEN RETURN; END IF;
2391
	
2392
	PERFORM util.schema_rm(replace);
2393
	PERFORM util.schema_rename(with_, replace);
2394
END;
2395
$$;
2396

    
2397

    
2398
--
2399
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2400
--
2401

    
2402
CREATE FUNCTION schema_rm(schema text) RETURNS void
2403
    LANGUAGE sql
2404
    AS $_$
2405
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2406
$_$;
2407

    
2408

    
2409
--
2410
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412

    
2413
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2414
    LANGUAGE sql STRICT
2415
    AS $_$
2416
SELECT util.eval(
2417
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2418
$_$;
2419

    
2420

    
2421
--
2422
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2423
--
2424

    
2425
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2426
    LANGUAGE plpgsql STRICT
2427
    AS $_$
2428
DECLARE
2429
    old text[] = ARRAY(SELECT util.col_names(table_));
2430
    new text[] = ARRAY(SELECT util.map_values(names));
2431
BEGIN
2432
    old = old[1:array_length(new, 1)]; -- truncate to same length
2433
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2434
||$$ TO $$||quote_ident(value))
2435
    FROM each(hstore(old, new))
2436
    WHERE value != key -- not same name
2437
    ;
2438
END;
2439
$_$;
2440

    
2441

    
2442
--
2443
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2444
--
2445

    
2446
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2447
idempotent
2448
';
2449

    
2450

    
2451
--
2452
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2453
--
2454

    
2455
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2456
    LANGUAGE plpgsql STRICT
2457
    AS $_$
2458
DECLARE
2459
	row_ util.map;
2460
BEGIN
2461
	-- rename any metadata cols rather than re-adding them with new names
2462
	BEGIN
2463
		PERFORM util.set_col_names(table_, names);
2464
	EXCEPTION
2465
		WHEN array_subscript_error THEN -- selective suppress
2466
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2467
				-- metadata cols not yet added
2468
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2469
			END IF;
2470
	END;
2471
	
2472
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2473
	LOOP
2474
		PERFORM util.mk_const_col((table_, row_."to"),
2475
			substring(row_."from" from 2));
2476
	END LOOP;
2477
	
2478
	PERFORM util.set_col_names(table_, names);
2479
END;
2480
$_$;
2481

    
2482

    
2483
--
2484
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2485
--
2486

    
2487
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2488
idempotent.
2489
the metadata mappings must be *last* in the names table.
2490
';
2491

    
2492

    
2493
--
2494
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2495
--
2496

    
2497
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2498
    LANGUAGE plpgsql STRICT
2499
    AS $_$
2500
DECLARE
2501
    sql text = $$ALTER TABLE $$||table_||$$
2502
$$||NULLIF(array_to_string(ARRAY(
2503
    SELECT
2504
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2505
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2506
    FROM
2507
    (
2508
        SELECT
2509
          quote_ident(col_name) AS col_name_sql
2510
        , util.col_type((table_, col_name)) AS curr_type
2511
        , type AS target_type
2512
        FROM unnest(col_casts)
2513
    ) s
2514
    WHERE curr_type != target_type
2515
), '
2516
, '), '');
2517
BEGIN
2518
    PERFORM util.debug_print_sql(sql);
2519
    EXECUTE COALESCE(sql, '');
2520
END;
2521
$_$;
2522

    
2523

    
2524
--
2525
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2526
--
2527

    
2528
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2529
idempotent
2530
';
2531

    
2532

    
2533
--
2534
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2535
--
2536

    
2537
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2538
    LANGUAGE sql STABLE
2539
    AS $_$
2540
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2541
$$||util.show_grants_for($1)
2542
$_$;
2543

    
2544

    
2545
--
2546
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2547
--
2548

    
2549
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2550
    LANGUAGE sql STABLE
2551
    AS $_$
2552
SELECT string_agg(cmd, '')
2553
FROM
2554
(
2555
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2556
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2557
$$ ELSE '' END) AS cmd
2558
	FROM util.grants_users() f (user_)
2559
) s
2560
$_$;
2561

    
2562

    
2563
--
2564
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2565
--
2566

    
2567
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2568
    LANGUAGE plpgsql STABLE STRICT
2569
    AS $_$
2570
DECLARE
2571
    hstore hstore;
2572
BEGIN
2573
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2574
        table_||$$))$$ INTO STRICT hstore;
2575
    RETURN hstore;
2576
END;
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2582
--
2583

    
2584
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2585
    LANGUAGE sql STABLE STRICT
2586
    AS $_$
2587
SELECT COUNT(*) > 0 FROM pg_constraint
2588
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2589
$_$;
2590

    
2591

    
2592
--
2593
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2594
--
2595

    
2596
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2597
gets whether a status flag is set by the presence of a table constraint
2598
';
2599

    
2600

    
2601
--
2602
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2603
--
2604

    
2605
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2606
    LANGUAGE sql STRICT
2607
    AS $_$
2608
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2609
||quote_ident($2)||$$ CHECK (true)$$)
2610
$_$;
2611

    
2612

    
2613
--
2614
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2615
--
2616

    
2617
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2618
stores a status flag by the presence of a table constraint.
2619
idempotent.
2620
';
2621

    
2622

    
2623
--
2624
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2625
--
2626

    
2627
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2628
    LANGUAGE sql STABLE STRICT
2629
    AS $_$
2630
SELECT util.table_flag__get($1, 'nulls_mapped')
2631
$_$;
2632

    
2633

    
2634
--
2635
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2636
--
2637

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

    
2642

    
2643
--
2644
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2645
--
2646

    
2647
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2648
    LANGUAGE sql STRICT
2649
    AS $_$
2650
SELECT util.table_flag__set($1, 'nulls_mapped')
2651
$_$;
2652

    
2653

    
2654
--
2655
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2656
--
2657

    
2658
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2659
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2660
idempotent.
2661
';
2662

    
2663

    
2664
--
2665
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2666
--
2667

    
2668
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2669
    LANGUAGE plpgsql STRICT
2670
    AS $_$
2671
DECLARE
2672
    row record;
2673
BEGIN
2674
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2675
    LOOP
2676
        IF row.global_name != row.name THEN
2677
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2678
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2679
        END IF;
2680
    END LOOP;
2681
END;
2682
$_$;
2683

    
2684

    
2685
--
2686
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2687
--
2688

    
2689
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2690
idempotent
2691
';
2692

    
2693

    
2694
--
2695
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2696
--
2697

    
2698
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2699
    LANGUAGE sql STRICT
2700
    AS $_$
2701
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2702
SELECT NULL::void; -- don't fold away functions called in previous query
2703
$_$;
2704

    
2705

    
2706
--
2707
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2708
--
2709

    
2710
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2711
trims table_ to include only columns in the original data.
2712
idempotent.
2713
';
2714

    
2715

    
2716
--
2717
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2718
--
2719

    
2720
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2721
    LANGUAGE plpgsql STRICT
2722
    AS $_$
2723
BEGIN
2724
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2725
END;
2726
$_$;
2727

    
2728

    
2729
--
2730
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2731
--
2732

    
2733
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2734
idempotent
2735
';
2736

    
2737

    
2738
--
2739
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2740
--
2741

    
2742
CREATE FUNCTION try_create(sql text) RETURNS void
2743
    LANGUAGE plpgsql STRICT
2744
    AS $$
2745
BEGIN
2746
    PERFORM util.eval(sql);
2747
EXCEPTION
2748
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2749
    WHEN undefined_column THEN NULL;
2750
    WHEN duplicate_column THEN NULL;
2751
END;
2752
$$;
2753

    
2754

    
2755
--
2756
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2757
--
2758

    
2759
COMMENT ON FUNCTION try_create(sql text) IS '
2760
idempotent
2761
';
2762

    
2763

    
2764
--
2765
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2766
--
2767

    
2768
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2769
    LANGUAGE sql STRICT
2770
    AS $_$
2771
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2772
$_$;
2773

    
2774

    
2775
--
2776
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2777
--
2778

    
2779
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
2780
idempotent
2781
';
2782

    
2783

    
2784
--
2785
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2786
--
2787

    
2788
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2789
    LANGUAGE sql IMMUTABLE
2790
    AS $_$
2791
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2792
$_$;
2793

    
2794

    
2795
--
2796
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2797
--
2798

    
2799
COMMENT ON FUNCTION type_qual(value anyelement) IS '
2800
a type''s NOT NULL qualifier
2801
';
2802

    
2803

    
2804
--
2805
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2806
--
2807

    
2808
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2809
    LANGUAGE plpgsql STABLE
2810
    AS $_$
2811
DECLARE
2812
    type regtype;
2813
BEGIN
2814
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2815
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2816
    RETURN type;
2817
END;
2818
$_$;
2819

    
2820

    
2821
--
2822
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2823
--
2824

    
2825
CREATE AGGREGATE all_same(anyelement) (
2826
    SFUNC = all_same_transform,
2827
    STYPE = anyarray,
2828
    FINALFUNC = all_same_final
2829
);
2830

    
2831

    
2832
--
2833
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2834
--
2835

    
2836
COMMENT ON AGGREGATE all_same(anyelement) IS '
2837
includes NULLs in comparison
2838
';
2839

    
2840

    
2841
--
2842
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2843
--
2844

    
2845
CREATE AGGREGATE join_strs(text, text) (
2846
    SFUNC = join_strs_transform,
2847
    STYPE = text
2848
);
2849

    
2850

    
2851
--
2852
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2853
--
2854

    
2855
CREATE OPERATOR -> (
2856
    PROCEDURE = map_get,
2857
    LEFTARG = regclass,
2858
    RIGHTARG = text
2859
);
2860

    
2861

    
2862
--
2863
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2864
--
2865

    
2866
CREATE OPERATOR => (
2867
    PROCEDURE = hstore,
2868
    LEFTARG = text[],
2869
    RIGHTARG = text
2870
);
2871

    
2872

    
2873
--
2874
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2875
--
2876

    
2877
COMMENT ON OPERATOR => (text[], text) IS '
2878
usage: array[''key1'', ...]::text[] => ''value''
2879
';
2880

    
2881

    
2882
--
2883
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2884
--
2885

    
2886
CREATE OPERATOR ?*>= (
2887
    PROCEDURE = is_populated_more_often_than,
2888
    LEFTARG = anyelement,
2889
    RIGHTARG = anyelement
2890
);
2891

    
2892

    
2893
--
2894
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2895
--
2896

    
2897
CREATE OPERATOR ?>= (
2898
    PROCEDURE = is_more_complete_than,
2899
    LEFTARG = anyelement,
2900
    RIGHTARG = anyelement
2901
);
2902

    
2903

    
2904
--
2905
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2906
--
2907

    
2908
CREATE OPERATOR ||% (
2909
    PROCEDURE = concat_esc,
2910
    LEFTARG = text,
2911
    RIGHTARG = text
2912
);
2913

    
2914

    
2915
--
2916
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2917
--
2918

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

    
2923

    
2924
--
2925
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2926
--
2927

    
2928
CREATE TABLE map (
2929
    "from" text NOT NULL,
2930
    "to" text,
2931
    filter text,
2932
    notes text
2933
);
2934

    
2935

    
2936
--
2937
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2938
--
2939

    
2940

    
2941

    
2942
--
2943
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2944
--
2945

    
2946

    
2947

    
2948
--
2949
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2950
--
2951

    
2952
ALTER TABLE ONLY map
2953
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2954

    
2955

    
2956
--
2957
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2958
--
2959

    
2960
ALTER TABLE ONLY map
2961
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2962

    
2963

    
2964
--
2965
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2966
--
2967

    
2968
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2969

    
2970

    
2971
--
2972
-- PostgreSQL database dump complete
2973
--
2974

    
(19-19/29)