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: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
886
--
887

    
888
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
889
    LANGUAGE sql STABLE STRICT
890
    AS $_$
891
SELECT util.eval2set($$
892
SELECT col
893
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
894
LEFT JOIN $$||$2||$$ ON "to" = col
895
WHERE "from" IS NULL
896
$$, NULL::text)
897
$_$;
898

    
899

    
900
--
901
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
902
--
903

    
904
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
905
gets table_''s derived columns (all the columns not in the names table)
906
';
907

    
908

    
909
--
910
-- Name: diff_cols(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
911
--
912

    
913
CREATE FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
914
    LANGUAGE sql STABLE
915
    AS $_$
916
SELECT * FROM
917
util.eval2col_pair($$
918
SELECT * FROM
919
(
920
$$||$1||$$
921
) left_ (left_)
922
FULL JOIN
923
(
924
$$||$2||$$
925
) right_ (right_)
926
ON left_ = right_
927
WHERE left_ IS DISTINCT FROM right_
928
ORDER BY left_, right_
929
$$, $3)
930
$_$;
931

    
932

    
933
--
934
-- 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: -
935
--
936

    
937
COMMENT ON FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
938
col_type_null (*required*): NULL::col_type
939
usage:
940
SELECT * FROM util.diff_cols($$VALUES (''1''), (''2''), (''4'')$$, $$VALUES (''1''), (''3''), (''4'')$$, NULL::text)
941

    
942
to run EXPLAIN on the FULL JOIN query:
943
# run this function
944
# look for a NOTICE containing the expanded query that it ran
945
# run EXPLAIN on this expanded query
946
';
947

    
948

    
949
--
950
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
951
--
952

    
953
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
954
    LANGUAGE sql STABLE
955
    AS $_$
956
SELECT * FROM util.diff_cols($$SELECT * FROM $$||$1, $$SELECT * FROM $$||$1, $3)
957
$_$;
958

    
959

    
960
--
961
-- 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: -
962
--
963

    
964
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
965
col_type_null (*required*): NULL::col_type
966
usage:
967
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
968
';
969

    
970

    
971
--
972
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
973
--
974

    
975
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
976
    LANGUAGE sql STRICT
977
    AS $_$
978
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
979
$_$;
980

    
981

    
982
--
983
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
984
--
985

    
986
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
987
idempotent
988
';
989

    
990

    
991
--
992
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
993
--
994

    
995
CREATE FUNCTION drop_column(col col_ref) RETURNS void
996
    LANGUAGE sql STRICT
997
    AS $_$
998
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
999
quote_ident($1.name))
1000
$_$;
1001

    
1002

    
1003
--
1004
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
1005
--
1006

    
1007
COMMENT ON FUNCTION drop_column(col col_ref) IS '
1008
idempotent
1009
';
1010

    
1011

    
1012
--
1013
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
1014
--
1015

    
1016
CREATE FUNCTION drop_table(table_ text) RETURNS void
1017
    LANGUAGE sql STRICT
1018
    AS $_$
1019
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
1020
$_$;
1021

    
1022

    
1023
--
1024
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
1025
--
1026

    
1027
COMMENT ON FUNCTION drop_table(table_ text) IS '
1028
idempotent
1029
';
1030

    
1031

    
1032
--
1033
-- Name: drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1034
--
1035

    
1036
CREATE FUNCTION drop_view(view_ text) RETURNS void
1037
    LANGUAGE sql STRICT
1038
    AS $_$
1039
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1)
1040
$_$;
1041

    
1042

    
1043
--
1044
-- Name: FUNCTION drop_view(view_ text); Type: COMMENT; Schema: util; Owner: -
1045
--
1046

    
1047
COMMENT ON FUNCTION drop_view(view_ text) IS '
1048
idempotent
1049
';
1050

    
1051

    
1052
--
1053
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1054
--
1055

    
1056
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1057
    LANGUAGE sql IMMUTABLE
1058
    AS $_$
1059
SELECT util.array_fill($1, 0)
1060
$_$;
1061

    
1062

    
1063
--
1064
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1065
--
1066

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

    
1071

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

    
1076
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1077
    LANGUAGE sql IMMUTABLE
1078
    AS $_$
1079
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1080
$_$;
1081

    
1082

    
1083
--
1084
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1085
--
1086

    
1087
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1088
    LANGUAGE sql IMMUTABLE
1089
    AS $_$
1090
SELECT regexp_replace($2, '("?)$', $1||'\1')
1091
$_$;
1092

    
1093

    
1094
--
1095
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1096
--
1097

    
1098
CREATE FUNCTION eval(sql text) RETURNS void
1099
    LANGUAGE plpgsql STRICT
1100
    AS $$
1101
BEGIN
1102
    RAISE NOTICE '%', sql;
1103
    EXECUTE sql;
1104
END;
1105
$$;
1106

    
1107

    
1108
--
1109
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1110
--
1111

    
1112
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1113
    LANGUAGE plpgsql
1114
    AS $$
1115
BEGIN
1116
	RAISE NOTICE '%', sql;
1117
	RETURN QUERY EXECUTE sql;
1118
END;
1119
$$;
1120

    
1121

    
1122
--
1123
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1124
--
1125

    
1126
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1127
col_type_null (*required*): NULL::col_type
1128
';
1129

    
1130

    
1131
--
1132
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1133
--
1134

    
1135
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1136
    LANGUAGE plpgsql
1137
    AS $$
1138
BEGIN
1139
	RAISE NOTICE '%', sql;
1140
	RETURN QUERY EXECUTE sql;
1141
END;
1142
$$;
1143

    
1144

    
1145
--
1146
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1147
--
1148

    
1149
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1150
ret_type_null: NULL::ret_type
1151
';
1152

    
1153

    
1154
--
1155
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1156
--
1157

    
1158
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1159
    LANGUAGE plpgsql
1160
    AS $$
1161
DECLARE
1162
	ret_val ret_type_null%TYPE;
1163
BEGIN
1164
	RAISE NOTICE '%', sql;
1165
	EXECUTE sql INTO STRICT ret_val;
1166
	RETURN ret_val;
1167
END;
1168
$$;
1169

    
1170

    
1171
--
1172
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1173
--
1174

    
1175
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1176
ret_type_null: NULL::ret_type
1177
';
1178

    
1179

    
1180
--
1181
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1182
--
1183

    
1184
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1185
    LANGUAGE sql
1186
    AS $_$
1187
SELECT util.eval2val($$SELECT $$||$1, $2)
1188
$_$;
1189

    
1190

    
1191
--
1192
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1193
--
1194

    
1195
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1196
ret_type_null: NULL::ret_type
1197
';
1198

    
1199

    
1200
--
1201
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1202
--
1203

    
1204
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1205
    LANGUAGE sql
1206
    AS $_$
1207
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1208
$_$;
1209

    
1210

    
1211
--
1212
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1213
--
1214

    
1215
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1216
sql: can be NULL, which will be passed through
1217
ret_type_null: NULL::ret_type
1218
';
1219

    
1220

    
1221
--
1222
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1223
--
1224

    
1225
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1226
    LANGUAGE sql STABLE STRICT
1227
    AS $_$
1228
SELECT col_name
1229
FROM unnest($2) s (col_name)
1230
WHERE util.col_exists(($1, col_name))
1231
$_$;
1232

    
1233

    
1234
--
1235
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1236
--
1237

    
1238
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1239
    LANGUAGE sql
1240
    AS $_$
1241
SELECT util.eval2set($$EXPLAIN $$||$1)
1242
$_$;
1243

    
1244

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

    
1249
CREATE FUNCTION explain2notice(sql text) RETURNS void
1250
    LANGUAGE plpgsql
1251
    AS $_$
1252
BEGIN
1253
	RAISE NOTICE '%', $$EXPLAIN:
1254
$$||util.explain2str(sql);
1255
END;
1256
$_$;
1257

    
1258

    
1259
--
1260
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1261
--
1262

    
1263
CREATE FUNCTION explain2str(sql text) RETURNS text
1264
    LANGUAGE sql
1265
    AS $_$
1266
SELECT util.join_strs(explain, $$
1267
$$) FROM util.explain($1)
1268
$_$;
1269

    
1270

    
1271
SET default_tablespace = '';
1272

    
1273
SET default_with_oids = false;
1274

    
1275
--
1276
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1277
--
1278

    
1279
CREATE TABLE explain (
1280
    line text NOT NULL
1281
);
1282

    
1283

    
1284
--
1285
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1286
--
1287

    
1288
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1289
    LANGUAGE sql
1290
    AS $_$
1291
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1292
$$||quote_nullable($1)||$$
1293
)$$)
1294
$_$;
1295

    
1296

    
1297
--
1298
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1299
--
1300

    
1301
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1302
usage:
1303
PERFORM util.explain2table($$
1304
query
1305
$$);
1306
';
1307

    
1308

    
1309
--
1310
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1311
--
1312

    
1313
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1314
    LANGUAGE sql IMMUTABLE
1315
    AS $_$
1316
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1317
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1318
) END
1319
$_$;
1320

    
1321

    
1322
--
1323
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1324
--
1325

    
1326
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1327
ensures that an array will always have proper non-NULL dimensions
1328
';
1329

    
1330

    
1331
--
1332
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1333
--
1334

    
1335
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1336
    LANGUAGE plpgsql
1337
    AS $_$
1338
DECLARE
1339
	PG_EXCEPTION_DETAIL text;
1340
	recreate_users_cmd text = util.save_drop_views(users);
1341
BEGIN
1342
	PERFORM util.eval(cmd);
1343
	PERFORM util.eval(recreate_users_cmd);
1344
EXCEPTION
1345
WHEN dependent_objects_still_exist THEN
1346
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1347
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1348
	users = array(SELECT * FROM util.regexp_matches_group(
1349
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1350
	IF util.is_empty(users) THEN RAISE; END IF;
1351
	PERFORM util.force_recreate(cmd, users);
1352
END;
1353
$_$;
1354

    
1355

    
1356
--
1357
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1358
--
1359

    
1360
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1361
idempotent
1362

    
1363
users: not necessary to provide this because it will be autopopulated
1364
';
1365

    
1366

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

    
1371
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1372
    LANGUAGE plpgsql STRICT
1373
    AS $_$
1374
DECLARE
1375
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1376
$$||query;
1377
BEGIN
1378
	EXECUTE mk_view;
1379
EXCEPTION
1380
WHEN invalid_table_definition THEN
1381
	IF SQLERRM = 'cannot drop columns from view'
1382
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1383
	THEN
1384
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1385
		EXECUTE mk_view;
1386
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1387
	END IF;
1388
END;
1389
$_$;
1390

    
1391

    
1392
--
1393
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1394
--
1395

    
1396
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1397
idempotent
1398
';
1399

    
1400

    
1401
--
1402
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1403
--
1404

    
1405
CREATE FUNCTION grants_users() RETURNS SETOF text
1406
    LANGUAGE sql IMMUTABLE
1407
    AS $$
1408
VALUES ('bien_read'), ('public_')
1409
$$;
1410

    
1411

    
1412
--
1413
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1414
--
1415

    
1416
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1417
    LANGUAGE sql IMMUTABLE
1418
    AS $_$
1419
SELECT substring($2 for length($1)) = $1
1420
$_$;
1421

    
1422

    
1423
--
1424
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1425
--
1426

    
1427
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1428
    LANGUAGE sql IMMUTABLE
1429
    AS $_$
1430
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1431
$_$;
1432

    
1433

    
1434
--
1435
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1436
--
1437

    
1438
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1439
avoids repeating the same value for each key
1440
';
1441

    
1442

    
1443
--
1444
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1445
--
1446

    
1447
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1448
    LANGUAGE sql IMMUTABLE
1449
    AS $_$
1450
SELECT COALESCE($1, $2)
1451
$_$;
1452

    
1453

    
1454
--
1455
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1456
--
1457

    
1458
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1459
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1460
';
1461

    
1462

    
1463
--
1464
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1465
--
1466

    
1467
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1468
    LANGUAGE sql STABLE STRICT
1469
    AS $_$
1470
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1471
$_$;
1472

    
1473

    
1474
--
1475
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1476
--
1477

    
1478
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1479
    LANGUAGE sql IMMUTABLE
1480
    AS $_$
1481
SELECT util.array_length($1) = 0
1482
$_$;
1483

    
1484

    
1485
--
1486
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1487
--
1488

    
1489
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1490
    LANGUAGE sql IMMUTABLE
1491
    AS $_$
1492
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1493
$_$;
1494

    
1495

    
1496
--
1497
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1498
--
1499

    
1500
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1501
    LANGUAGE sql IMMUTABLE
1502
    AS $_$
1503
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1504
$_$;
1505

    
1506

    
1507
--
1508
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1509
--
1510

    
1511
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1512
    LANGUAGE sql IMMUTABLE STRICT
1513
    AS $_$
1514
SELECT $1 || $3 || $2
1515
$_$;
1516

    
1517

    
1518
--
1519
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1520
--
1521

    
1522
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1523
    LANGUAGE sql IMMUTABLE
1524
    AS $_$
1525
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1526
$_$;
1527

    
1528

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

    
1533
CREATE FUNCTION map_filter_insert() RETURNS trigger
1534
    LANGUAGE plpgsql
1535
    AS $$
1536
BEGIN
1537
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1538
	RETURN new;
1539
END;
1540
$$;
1541

    
1542

    
1543
--
1544
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1545
--
1546

    
1547
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1548
    LANGUAGE plpgsql STABLE STRICT
1549
    AS $_$
1550
DECLARE
1551
    value text;
1552
BEGIN
1553
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1554
        INTO value USING key;
1555
    RETURN value;
1556
END;
1557
$_$;
1558

    
1559

    
1560
--
1561
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1562
--
1563

    
1564
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1565
    LANGUAGE sql IMMUTABLE
1566
    AS $_$
1567
SELECT util._map(util.nulls_map($1), $2)
1568
$_$;
1569

    
1570

    
1571
--
1572
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1573
--
1574

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

    
1578
[1] inlining of function calls, which is different from constant folding
1579
[2] _map()''s profiling query
1580
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1581
and map_nulls()''s profiling query
1582
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1583
both take ~920 ms.
1584
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.
1585
';
1586

    
1587

    
1588
--
1589
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1590
--
1591

    
1592
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1593
    LANGUAGE plpgsql STABLE STRICT
1594
    AS $_$
1595
BEGIN
1596
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1597
END;
1598
$_$;
1599

    
1600

    
1601
--
1602
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1603
--
1604

    
1605
CREATE FUNCTION materialize_query(table_ text, sql text) RETURNS void
1606
    LANGUAGE sql
1607
    AS $_$
1608
SELECT util.create_if_not_exists($$CREATE TABLE $$||quote_ident($1)||$$ AS
1609
$$||$2)
1610
$_$;
1611

    
1612

    
1613
--
1614
-- Name: FUNCTION materialize_query(table_ text, sql text); Type: COMMENT; Schema: util; Owner: -
1615
--
1616

    
1617
COMMENT ON FUNCTION materialize_query(table_ text, sql text) IS '
1618
idempotent
1619
';
1620

    
1621

    
1622
--
1623
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1624
--
1625

    
1626
CREATE FUNCTION materialize_view(table_ text, view_ regclass) RETURNS void
1627
    LANGUAGE sql
1628
    AS $_$
1629
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1630
$_$;
1631

    
1632

    
1633
--
1634
-- Name: FUNCTION materialize_view(table_ text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1635
--
1636

    
1637
COMMENT ON FUNCTION materialize_view(table_ text, view_ regclass) IS '
1638
idempotent
1639
';
1640

    
1641

    
1642
--
1643
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1644
--
1645

    
1646
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1647
    LANGUAGE sql STRICT
1648
    AS $_$
1649
SELECT util.create_if_not_exists($$
1650
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1651
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1652
||quote_literal($2)||$$;
1653
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1654
constant
1655
';
1656
$$)
1657
$_$;
1658

    
1659

    
1660
--
1661
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1662
--
1663

    
1664
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1665
idempotent
1666
';
1667

    
1668

    
1669
--
1670
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1671
--
1672

    
1673
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1674
    LANGUAGE plpgsql STRICT
1675
    AS $_$
1676
DECLARE
1677
    type regtype = util.typeof(expr, col.table_::text::regtype);
1678
    col_name_sql text = quote_ident(col.name);
1679
BEGIN
1680
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1681
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1682
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1683
$$||expr||$$;
1684
$$);
1685
END;
1686
$_$;
1687

    
1688

    
1689
--
1690
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1691
--
1692

    
1693
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1694
idempotent
1695
';
1696

    
1697

    
1698
--
1699
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1700
--
1701

    
1702
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1703
    LANGUAGE sql STRICT
1704
    AS $_$
1705
SELECT util.create_if_not_exists($$
1706
CREATE TABLE $$||$1||$$
1707
(
1708
    LIKE util.map INCLUDING ALL
1709
);
1710

    
1711
CREATE TRIGGER map_filter_insert
1712
  BEFORE INSERT
1713
  ON $$||$1||$$
1714
  FOR EACH ROW
1715
  EXECUTE PROCEDURE util.map_filter_insert();
1716
$$)
1717
$_$;
1718

    
1719

    
1720
--
1721
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1722
--
1723

    
1724
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1725
    LANGUAGE sql IMMUTABLE
1726
    AS $_$
1727
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1728
$_$;
1729

    
1730

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

    
1735
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1736
    LANGUAGE sql STRICT
1737
    AS $_$
1738
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1739
$_$;
1740

    
1741

    
1742
--
1743
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1744
--
1745

    
1746
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1747
idempotent
1748
';
1749

    
1750

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

    
1755
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1756
    LANGUAGE plpgsql STRICT
1757
    AS $_$
1758
DECLARE
1759
	view_qual_name text = util.qual_name(view_);
1760
BEGIN
1761
	EXECUTE $$
1762
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1763
  RETURNS SETOF $$||view_||$$ AS
1764
$BODY1$
1765
SELECT * FROM $$||view_qual_name||$$
1766
ORDER BY sort_col
1767
LIMIT $1 OFFSET $2
1768
$BODY1$
1769
  LANGUAGE sql STABLE
1770
  COST 100
1771
  ROWS 1000
1772
$$;
1773
	
1774
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1775
END;
1776
$_$;
1777

    
1778

    
1779
--
1780
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1781
--
1782

    
1783
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1784
    LANGUAGE plpgsql STRICT
1785
    AS $_$
1786
DECLARE
1787
	view_qual_name text = util.qual_name(view_);
1788
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1789
BEGIN
1790
	EXECUTE $$
1791
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1792
  RETURNS integer AS
1793
$BODY1$
1794
SELECT $$||quote_ident(row_num_col)||$$
1795
FROM $$||view_qual_name||$$
1796
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1797
LIMIT 1
1798
$BODY1$
1799
  LANGUAGE sql STABLE
1800
  COST 100;
1801
$$;
1802
	
1803
	EXECUTE $$
1804
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1805
  RETURNS SETOF $$||view_||$$ AS
1806
$BODY1$
1807
SELECT * FROM $$||view_qual_name||$$
1808
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1809
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1810
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1811
ORDER BY $$||quote_ident(row_num_col)||$$
1812
$BODY1$
1813
  LANGUAGE sql STABLE
1814
  COST 100
1815
  ROWS 1000
1816
$$;
1817
	
1818
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1819
END;
1820
$_$;
1821

    
1822

    
1823
--
1824
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1825
--
1826

    
1827
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1828
    LANGUAGE plpgsql STRICT
1829
    AS $_$
1830
DECLARE
1831
	view_qual_name text = util.qual_name(view_);
1832
BEGIN
1833
	EXECUTE $$
1834
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1835
  RETURNS SETOF $$||view_||$$
1836
  SET enable_sort TO 'off'
1837
  AS
1838
$BODY1$
1839
SELECT * FROM $$||view_qual_name||$$($2, $3)
1840
$BODY1$
1841
  LANGUAGE sql STABLE
1842
  COST 100
1843
  ROWS 1000
1844
;
1845
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1846
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1847
If you want to run EXPLAIN and get expanded output, use the regular subset
1848
function instead. (When a config param is set on a function, EXPLAIN produces
1849
just a function scan.)
1850
';
1851
$$;
1852
END;
1853
$_$;
1854

    
1855

    
1856
--
1857
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1858
--
1859

    
1860
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
1861
creates subset function which turns off enable_sort
1862
';
1863

    
1864

    
1865
--
1866
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
1867
--
1868

    
1869
CREATE FUNCTION name(table_ regclass) RETURNS text
1870
    LANGUAGE sql STABLE
1871
    AS $_$
1872
SELECT relname::text FROM pg_class WHERE oid = $1
1873
$_$;
1874

    
1875

    
1876
--
1877
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1878
--
1879

    
1880
CREATE FUNCTION name(type regtype) RETURNS text
1881
    LANGUAGE sql STABLE STRICT
1882
    AS $_$
1883
SELECT typname::text FROM pg_type WHERE oid = $1
1884
$_$;
1885

    
1886

    
1887
--
1888
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1889
--
1890

    
1891
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1892
    LANGUAGE sql IMMUTABLE
1893
    AS $_$
1894
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1895
$_$;
1896

    
1897

    
1898
--
1899
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1900
--
1901

    
1902
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1903
    LANGUAGE sql IMMUTABLE
1904
    AS $_$
1905
SELECT $1 IS NOT NULL
1906
$_$;
1907

    
1908

    
1909
--
1910
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1911
--
1912

    
1913
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1914
    LANGUAGE sql IMMUTABLE
1915
    AS $_$
1916
SELECT util.hstore($1, NULL) || '*=>*'
1917
$_$;
1918

    
1919

    
1920
--
1921
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1922
--
1923

    
1924
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
1925
for use with _map()
1926
';
1927

    
1928

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

    
1933
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1934
    LANGUAGE sql IMMUTABLE
1935
    AS $_$
1936
SELECT $2 + COALESCE($1, 0)
1937
$_$;
1938

    
1939

    
1940
--
1941
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1942
--
1943

    
1944
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1945
    LANGUAGE sql STABLE
1946
    AS $_$
1947
SELECT util.type_qual_name($1::text::regtype)
1948
$_$;
1949

    
1950

    
1951
--
1952
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
1953
--
1954

    
1955
CREATE FUNCTION raise_notice(msg text) RETURNS void
1956
    LANGUAGE plpgsql IMMUTABLE STRICT
1957
    AS $$
1958
BEGIN
1959
	RAISE NOTICE '%', msg;
1960
END;
1961
$$;
1962

    
1963

    
1964
--
1965
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1966
--
1967

    
1968
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1969
    LANGUAGE plpgsql IMMUTABLE STRICT
1970
    AS $$
1971
BEGIN
1972
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1973
END;
1974
$$;
1975

    
1976

    
1977
--
1978
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
1979
--
1980

    
1981
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
1982
    LANGUAGE sql IMMUTABLE
1983
    AS $_$
1984
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
1985
$_$;
1986

    
1987

    
1988
--
1989
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1990
--
1991

    
1992
CREATE FUNCTION rematerialize_view(table_ text, view_ regclass) RETURNS void
1993
    LANGUAGE sql
1994
    AS $_$
1995
SELECT util.drop_table($1);
1996
SELECT util.materialize_view($1, $2);
1997
$_$;
1998

    
1999

    
2000
--
2001
-- Name: FUNCTION rematerialize_view(table_ text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2002
--
2003

    
2004
COMMENT ON FUNCTION rematerialize_view(table_ text, view_ regclass) IS '
2005
idempotent, but repeats action each time
2006
';
2007

    
2008

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

    
2013
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2014
    LANGUAGE sql STRICT
2015
    AS $_$
2016
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2017
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2018
FROM util.col_names($1::text::regtype) f (name);
2019
SELECT NULL::void; -- don't fold away functions called in previous query
2020
$_$;
2021

    
2022

    
2023
--
2024
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2025
--
2026

    
2027
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2028
idempotent
2029
';
2030

    
2031

    
2032
--
2033
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2034
--
2035

    
2036
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2037
    LANGUAGE sql STRICT
2038
    AS $_$
2039
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2040
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2041
SELECT util.set_col_names($1, $2);
2042
$_$;
2043

    
2044

    
2045
--
2046
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2047
--
2048

    
2049
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2050
idempotent.
2051
alters the names table, so it will need to be repopulated after running this function.
2052
';
2053

    
2054

    
2055
--
2056
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2057
--
2058

    
2059
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2060
    LANGUAGE sql STRICT
2061
    AS $_$
2062
SELECT util.drop_table($1);
2063
SELECT util.mk_map_table($1);
2064
$_$;
2065

    
2066

    
2067
--
2068
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2069
--
2070

    
2071
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2072
    LANGUAGE plpgsql STRICT
2073
    AS $_$
2074
DECLARE
2075
	result text = NULL;
2076
BEGIN
2077
	BEGIN
2078
		result = util.show_create_view(view_);
2079
		PERFORM util.eval($$DROP VIEW $$||view_);
2080
	EXCEPTION
2081
		WHEN undefined_table THEN NULL;
2082
	END;
2083
	RETURN result;
2084
END;
2085
$_$;
2086

    
2087

    
2088
--
2089
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2090
--
2091

    
2092
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2093
    LANGUAGE sql
2094
    AS $_$
2095
SELECT concat(util.save_drop_view(unnest)) FROM unnest($1)
2096
$_$;
2097

    
2098

    
2099
--
2100
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2101
--
2102

    
2103
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2104
    LANGUAGE sql STABLE
2105
    AS $_$
2106
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2107
$_$;
2108

    
2109

    
2110
--
2111
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2112
--
2113

    
2114
CREATE FUNCTION schema(table_ regclass) RETURNS text
2115
    LANGUAGE sql STABLE
2116
    AS $_$
2117
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2118
$_$;
2119

    
2120

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

    
2125
CREATE FUNCTION schema(type regtype) RETURNS text
2126
    LANGUAGE sql STABLE
2127
    AS $_$
2128
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2129
$_$;
2130

    
2131

    
2132
--
2133
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2134
--
2135

    
2136
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2137
    LANGUAGE sql STABLE
2138
    AS $_$
2139
SELECT util.schema(pg_typeof($1))
2140
$_$;
2141

    
2142

    
2143
--
2144
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2145
--
2146

    
2147
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2148
    LANGUAGE sql STABLE
2149
    AS $_$
2150
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2151
$_$;
2152

    
2153

    
2154
--
2155
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2156
--
2157

    
2158
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2159
a schema bundle is a group of schemas with a common prefix
2160
';
2161

    
2162

    
2163
--
2164
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2165
--
2166

    
2167
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2168
    LANGUAGE sql
2169
    AS $_$
2170
SELECT util.schema_rename(old_schema,
2171
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2172
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2173
SELECT NULL::void; -- don't fold away functions called in previous query
2174
$_$;
2175

    
2176

    
2177
--
2178
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2179
--
2180

    
2181
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2182
    LANGUAGE plpgsql
2183
    AS $$
2184
BEGIN
2185
	-- don't schema_bundle_rm() the schema_bundle to keep!
2186
	IF replace = with_ THEN RETURN; END IF;
2187
	
2188
	PERFORM util.schema_bundle_rm(replace);
2189
	PERFORM util.schema_bundle_rename(with_, replace);
2190
END;
2191
$$;
2192

    
2193

    
2194
--
2195
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2196
--
2197

    
2198
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2199
    LANGUAGE sql
2200
    AS $_$
2201
SELECT util.schema_rm(schema)
2202
FROM util.schema_bundle_get_schemas($1) f (schema);
2203
SELECT NULL::void; -- don't fold away functions called in previous query
2204
$_$;
2205

    
2206

    
2207
--
2208
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2209
--
2210

    
2211
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2212
    LANGUAGE sql STABLE
2213
    AS $_$
2214
SELECT quote_ident(util.schema($1))
2215
$_$;
2216

    
2217

    
2218
--
2219
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2220
--
2221

    
2222
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2223
    LANGUAGE sql
2224
    AS $_$
2225
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2226
$_$;
2227

    
2228

    
2229
--
2230
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2231
--
2232

    
2233
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2234
    LANGUAGE plpgsql
2235
    AS $$
2236
BEGIN
2237
	-- don't schema_rm() the schema to keep!
2238
	IF replace = with_ THEN RETURN; END IF;
2239
	
2240
	PERFORM util.schema_rm(replace);
2241
	PERFORM util.schema_rename(with_, replace);
2242
END;
2243
$$;
2244

    
2245

    
2246
--
2247
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2248
--
2249

    
2250
CREATE FUNCTION schema_rm(schema text) RETURNS void
2251
    LANGUAGE sql
2252
    AS $_$
2253
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2254
$_$;
2255

    
2256

    
2257
--
2258
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2259
--
2260

    
2261
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2262
    LANGUAGE sql STRICT
2263
    AS $_$
2264
SELECT util.eval(
2265
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2266
$_$;
2267

    
2268

    
2269
--
2270
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2271
--
2272

    
2273
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2274
    LANGUAGE plpgsql STRICT
2275
    AS $_$
2276
DECLARE
2277
    old text[] = ARRAY(SELECT util.col_names(table_));
2278
    new text[] = ARRAY(SELECT util.map_values(names));
2279
BEGIN
2280
    old = old[1:array_length(new, 1)]; -- truncate to same length
2281
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2282
||$$ TO $$||quote_ident(value))
2283
    FROM each(hstore(old, new))
2284
    WHERE value != key -- not same name
2285
    ;
2286
END;
2287
$_$;
2288

    
2289

    
2290
--
2291
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2292
--
2293

    
2294
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2295
idempotent
2296
';
2297

    
2298

    
2299
--
2300
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2301
--
2302

    
2303
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2304
    LANGUAGE plpgsql STRICT
2305
    AS $_$
2306
DECLARE
2307
	row_ util.map;
2308
BEGIN
2309
	-- rename any metadata cols rather than re-adding them with new names
2310
	BEGIN
2311
		PERFORM util.set_col_names(table_, names);
2312
	EXCEPTION
2313
		WHEN array_subscript_error THEN -- selective suppress
2314
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2315
				-- metadata cols not yet added
2316
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2317
			END IF;
2318
	END;
2319
	
2320
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2321
	LOOP
2322
		PERFORM util.mk_const_col((table_, row_."to"),
2323
			substring(row_."from" from 2));
2324
	END LOOP;
2325
	
2326
	PERFORM util.set_col_names(table_, names);
2327
END;
2328
$_$;
2329

    
2330

    
2331
--
2332
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2333
--
2334

    
2335
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2336
idempotent.
2337
the metadata mappings must be *last* in the names table.
2338
';
2339

    
2340

    
2341
--
2342
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2343
--
2344

    
2345
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2346
    LANGUAGE plpgsql STRICT
2347
    AS $_$
2348
DECLARE
2349
    sql text = $$ALTER TABLE $$||table_||$$
2350
$$||NULLIF(array_to_string(ARRAY(
2351
    SELECT
2352
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2353
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2354
    FROM
2355
    (
2356
        SELECT
2357
          quote_ident(col_name) AS col_name_sql
2358
        , util.col_type((table_, col_name)) AS curr_type
2359
        , type AS target_type
2360
        FROM unnest(col_casts)
2361
    ) s
2362
    WHERE curr_type != target_type
2363
), '
2364
, '), '');
2365
BEGIN
2366
    RAISE NOTICE '%', sql;
2367
    EXECUTE COALESCE(sql, '');
2368
END;
2369
$_$;
2370

    
2371

    
2372
--
2373
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2374
--
2375

    
2376
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2377
idempotent
2378
';
2379

    
2380

    
2381
--
2382
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2383
--
2384

    
2385
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2386
    LANGUAGE sql STABLE
2387
    AS $_$
2388
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2389
$$||util.show_grants_for($1)
2390
$_$;
2391

    
2392

    
2393
--
2394
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2395
--
2396

    
2397
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2398
    LANGUAGE sql STABLE
2399
    AS $_$
2400
SELECT concat(cmd)
2401
FROM
2402
(
2403
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2404
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2405
$$ ELSE '' END) AS cmd
2406
	FROM util.grants_users() f (user_)
2407
) s
2408
$_$;
2409

    
2410

    
2411
--
2412
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2413
--
2414

    
2415
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2416
    LANGUAGE plpgsql STABLE STRICT
2417
    AS $_$
2418
DECLARE
2419
    hstore hstore;
2420
BEGIN
2421
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2422
        table_||$$))$$ INTO STRICT hstore;
2423
    RETURN hstore;
2424
END;
2425
$_$;
2426

    
2427

    
2428
--
2429
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2430
--
2431

    
2432
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2433
    LANGUAGE sql STABLE STRICT
2434
    AS $_$
2435
SELECT COUNT(*) > 0 FROM pg_constraint
2436
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2437
$_$;
2438

    
2439

    
2440
--
2441
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2442
--
2443

    
2444
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2445
gets whether a status flag is set by the presence of a table constraint
2446
';
2447

    
2448

    
2449
--
2450
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2451
--
2452

    
2453
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2454
    LANGUAGE sql STRICT
2455
    AS $_$
2456
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2457
||quote_ident($2)||$$ CHECK (true)$$)
2458
$_$;
2459

    
2460

    
2461
--
2462
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2463
--
2464

    
2465
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2466
stores a status flag by the presence of a table constraint.
2467
idempotent.
2468
';
2469

    
2470

    
2471
--
2472
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2473
--
2474

    
2475
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2476
    LANGUAGE sql STABLE STRICT
2477
    AS $_$
2478
SELECT util.table_flag__get($1, 'nulls_mapped')
2479
$_$;
2480

    
2481

    
2482
--
2483
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2484
--
2485

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

    
2490

    
2491
--
2492
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2493
--
2494

    
2495
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2496
    LANGUAGE sql STRICT
2497
    AS $_$
2498
SELECT util.table_flag__set($1, 'nulls_mapped')
2499
$_$;
2500

    
2501

    
2502
--
2503
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2504
--
2505

    
2506
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2507
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2508
idempotent.
2509
';
2510

    
2511

    
2512
--
2513
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2514
--
2515

    
2516
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2517
    LANGUAGE plpgsql STRICT
2518
    AS $_$
2519
DECLARE
2520
    row record;
2521
BEGIN
2522
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2523
    LOOP
2524
        IF row.global_name != row.name THEN
2525
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2526
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2527
        END IF;
2528
    END LOOP;
2529
END;
2530
$_$;
2531

    
2532

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

    
2537
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2538
idempotent
2539
';
2540

    
2541

    
2542
--
2543
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2544
--
2545

    
2546
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2547
    LANGUAGE sql STRICT
2548
    AS $_$
2549
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2550
SELECT NULL::void; -- don't fold away functions called in previous query
2551
$_$;
2552

    
2553

    
2554
--
2555
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2556
--
2557

    
2558
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2559
trims table_ to include only columns in the original data.
2560
idempotent.
2561
';
2562

    
2563

    
2564
--
2565
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2566
--
2567

    
2568
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2569
    LANGUAGE plpgsql STRICT
2570
    AS $_$
2571
BEGIN
2572
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2573
END;
2574
$_$;
2575

    
2576

    
2577
--
2578
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2579
--
2580

    
2581
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2582
idempotent
2583
';
2584

    
2585

    
2586
--
2587
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2588
--
2589

    
2590
CREATE FUNCTION try_create(sql text) RETURNS void
2591
    LANGUAGE plpgsql STRICT
2592
    AS $$
2593
BEGIN
2594
    PERFORM util.eval(sql);
2595
EXCEPTION
2596
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2597
    WHEN undefined_column THEN NULL;
2598
    WHEN duplicate_column THEN NULL;
2599
END;
2600
$$;
2601

    
2602

    
2603
--
2604
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2605
--
2606

    
2607
COMMENT ON FUNCTION try_create(sql text) IS '
2608
idempotent
2609
';
2610

    
2611

    
2612
--
2613
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2614
--
2615

    
2616
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2617
    LANGUAGE sql STRICT
2618
    AS $_$
2619
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2620
$_$;
2621

    
2622

    
2623
--
2624
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2625
--
2626

    
2627
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
2628
idempotent
2629
';
2630

    
2631

    
2632
--
2633
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2634
--
2635

    
2636
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2637
    LANGUAGE sql IMMUTABLE
2638
    AS $_$
2639
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2640
$_$;
2641

    
2642

    
2643
--
2644
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2645
--
2646

    
2647
COMMENT ON FUNCTION type_qual(value anyelement) IS '
2648
a type''s NOT NULL qualifier
2649
';
2650

    
2651

    
2652
--
2653
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2654
--
2655

    
2656
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2657
    LANGUAGE sql STABLE STRICT
2658
    SET search_path TO pg_temp
2659
    AS $_$
2660
SELECT $1::text
2661
$_$;
2662

    
2663

    
2664
--
2665
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2666
--
2667

    
2668
COMMENT ON FUNCTION type_qual_name(type regtype) IS '
2669
a type''s schema-qualified name
2670
';
2671

    
2672

    
2673
--
2674
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2675
--
2676

    
2677
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2678
    LANGUAGE plpgsql STABLE
2679
    AS $_$
2680
DECLARE
2681
    type regtype;
2682
BEGIN
2683
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2684
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2685
    RETURN type;
2686
END;
2687
$_$;
2688

    
2689

    
2690
--
2691
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2692
--
2693

    
2694
CREATE AGGREGATE all_same(anyelement) (
2695
    SFUNC = all_same_transform,
2696
    STYPE = anyarray,
2697
    FINALFUNC = all_same_final
2698
);
2699

    
2700

    
2701
--
2702
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2703
--
2704

    
2705
COMMENT ON AGGREGATE all_same(anyelement) IS '
2706
includes NULLs in comparison
2707
';
2708

    
2709

    
2710
--
2711
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2712
--
2713

    
2714
CREATE AGGREGATE join_strs(text, text) (
2715
    SFUNC = join_strs_transform,
2716
    STYPE = text
2717
);
2718

    
2719

    
2720
--
2721
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2722
--
2723

    
2724
CREATE OPERATOR -> (
2725
    PROCEDURE = map_get,
2726
    LEFTARG = regclass,
2727
    RIGHTARG = text
2728
);
2729

    
2730

    
2731
--
2732
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2733
--
2734

    
2735
CREATE OPERATOR => (
2736
    PROCEDURE = hstore,
2737
    LEFTARG = text[],
2738
    RIGHTARG = text
2739
);
2740

    
2741

    
2742
--
2743
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2744
--
2745

    
2746
COMMENT ON OPERATOR => (text[], text) IS '
2747
usage: array[''key1'', ...]::text[] => ''value''
2748
';
2749

    
2750

    
2751
--
2752
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2753
--
2754

    
2755
CREATE OPERATOR ?*>= (
2756
    PROCEDURE = is_populated_more_often_than,
2757
    LEFTARG = anyelement,
2758
    RIGHTARG = anyelement
2759
);
2760

    
2761

    
2762
--
2763
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2764
--
2765

    
2766
CREATE OPERATOR ?>= (
2767
    PROCEDURE = is_more_complete_than,
2768
    LEFTARG = anyelement,
2769
    RIGHTARG = anyelement
2770
);
2771

    
2772

    
2773
--
2774
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2775
--
2776

    
2777
CREATE OPERATOR ||% (
2778
    PROCEDURE = concat_esc,
2779
    LEFTARG = text,
2780
    RIGHTARG = text
2781
);
2782

    
2783

    
2784
--
2785
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2786
--
2787

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

    
2792

    
2793
--
2794
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2795
--
2796

    
2797
CREATE TABLE map (
2798
    "from" text NOT NULL,
2799
    "to" text,
2800
    filter text,
2801
    notes text
2802
);
2803

    
2804

    
2805
--
2806
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2807
--
2808

    
2809

    
2810

    
2811
--
2812
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2813
--
2814

    
2815

    
2816

    
2817
--
2818
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2819
--
2820

    
2821
ALTER TABLE ONLY map
2822
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2823

    
2824

    
2825
--
2826
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2827
--
2828

    
2829
ALTER TABLE ONLY map
2830
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2831

    
2832

    
2833
--
2834
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2835
--
2836

    
2837
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2838

    
2839

    
2840
--
2841
-- PostgreSQL database dump complete
2842
--
2843

    
(19-19/29)