Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

    
23
COMMENT ON SCHEMA util IS 'IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
24

    
25
NOTE: IMMUTABLE SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding.';
26

    
27

    
28
SET search_path = util, pg_catalog;
29

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

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

    
39

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

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

    
49

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

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

    
61

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

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

    
71

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

    
76
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
77
    LANGUAGE sql IMMUTABLE
78
    AS $_$
79
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
80
$_$;
81

    
82

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

    
87
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
88
    LANGUAGE sql IMMUTABLE
89
    AS $_$
90
SELECT bool_and(value)
91
FROM
92
(VALUES
93
      ($1)
94
    , ($2)
95
    , ($3)
96
    , ($4)
97
    , ($5)
98
)
99
AS v (value)
100
$_$;
101

    
102

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

    
107
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.';
108

    
109

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

    
114
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
115
    LANGUAGE sql IMMUTABLE
116
    AS $_$
117
SELECT avg(value)
118
FROM
119
(VALUES
120
      ($1)
121
    , ($2)
122
    , ($3)
123
    , ($4)
124
    , ($5)
125
)
126
AS v (value)
127
$_$;
128

    
129

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

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

    
148

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

    
153
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
154
    LANGUAGE sql IMMUTABLE
155
    AS $_$
156
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
157
FROM
158
(VALUES
159
      ($1)
160
    , ($2/60)
161
    , ($3/60/60)
162
)
163
AS v (value)
164
$_$;
165

    
166

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

    
171
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
172
    LANGUAGE sql IMMUTABLE
173
    AS $_$
174
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
175
$_$;
176

    
177

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

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

    
188

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

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

    
201

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

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

    
212

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

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

    
223

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

    
228
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
229
    LANGUAGE sql IMMUTABLE
230
    AS $_$
231
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
232
$_$;
233

    
234

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

    
239
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
240
    LANGUAGE sql IMMUTABLE
241
    AS $_$
242
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
243
$_$;
244

    
245

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

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

    
256

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

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

    
267

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

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

    
282

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

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

    
307

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

    
312
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
313
    LANGUAGE sql IMMUTABLE
314
    AS $_$
315
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
316
$_$;
317

    
318

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

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

    
357

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

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

    
368

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

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

    
407

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

    
412
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
413
    LANGUAGE sql IMMUTABLE
414
    AS $_$
415
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
416
$_$;
417

    
418

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

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

    
429

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

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

    
440

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

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

    
451

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

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

    
477

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

    
482
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
483
    LANGUAGE sql IMMUTABLE
484
    AS $_$
485
SELECT bool_or(value)
486
FROM
487
(VALUES
488
      ($1)
489
    , ($2)
490
    , ($3)
491
    , ($4)
492
    , ($5)
493
)
494
AS v (value)
495
$_$;
496

    
497

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

    
502
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.';
503

    
504

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

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

    
515

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

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

    
526

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

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

    
544

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

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

    
551

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

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

    
562

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

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

    
579

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

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

    
590

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

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

    
601

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

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

    
612

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

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

    
619

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

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

    
630

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

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

    
646

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

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

    
653

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

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

    
669

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

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

    
693

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

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

    
716

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

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

    
727

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

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

    
734

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

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

    
750

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

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

    
767

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

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

    
781

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

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

    
794

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

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

    
817

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

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

    
828

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

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

    
839

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

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

    
860

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

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

    
867

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

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

    
883

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

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

    
890

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

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

    
907

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

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

    
917

    
918
--
919
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
920
--
921

    
922
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
923
    LANGUAGE sql STABLE
924
    AS $_$
925
SELECT * FROM util.diff_cols($$SELECT * FROM $$||$1, $$SELECT * FROM $$||$1, $3)
926
$_$;
927

    
928

    
929
--
930
-- 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: -
931
--
932

    
933
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS 'col_type_null (*required*): NULL::col_type
934
usage:
935
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
936
';
937

    
938

    
939
--
940
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
941
--
942

    
943
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
944
    LANGUAGE sql STRICT
945
    AS $_$
946
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
947
$_$;
948

    
949

    
950
--
951
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
952
--
953

    
954
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
955

    
956

    
957
--
958
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
959
--
960

    
961
CREATE FUNCTION drop_column(col col_ref) RETURNS void
962
    LANGUAGE sql STRICT
963
    AS $_$
964
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
965
quote_ident($1.name))
966
$_$;
967

    
968

    
969
--
970
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
971
--
972

    
973
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
974

    
975

    
976
--
977
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
978
--
979

    
980
CREATE FUNCTION drop_table(table_ text) RETURNS void
981
    LANGUAGE sql STRICT
982
    AS $_$
983
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
984
$_$;
985

    
986

    
987
--
988
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
989
--
990

    
991
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
992

    
993

    
994
--
995
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
996
--
997

    
998
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
999
    LANGUAGE sql IMMUTABLE
1000
    AS $_$
1001
SELECT util.array_fill($1, 0)
1002
$_$;
1003

    
1004

    
1005
--
1006
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1007
--
1008

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

    
1011

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

    
1016
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1017
    LANGUAGE sql IMMUTABLE
1018
    AS $_$
1019
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1020
$_$;
1021

    
1022

    
1023
--
1024
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1025
--
1026

    
1027
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1028
    LANGUAGE sql IMMUTABLE
1029
    AS $_$
1030
SELECT regexp_replace($2, '("?)$', $1||'\1')
1031
$_$;
1032

    
1033

    
1034
--
1035
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1036
--
1037

    
1038
CREATE FUNCTION eval(sql text) RETURNS void
1039
    LANGUAGE plpgsql STRICT
1040
    AS $$
1041
BEGIN
1042
    RAISE NOTICE '%', sql;
1043
    EXECUTE sql;
1044
END;
1045
$$;
1046

    
1047

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

    
1052
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1053
    LANGUAGE plpgsql
1054
    AS $$
1055
BEGIN
1056
	RAISE NOTICE '%', sql;
1057
	RETURN QUERY EXECUTE sql;
1058
END;
1059
$$;
1060

    
1061

    
1062
--
1063
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1064
--
1065

    
1066
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS 'col_type_null (*required*): NULL::col_type';
1067

    
1068

    
1069
--
1070
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1071
--
1072

    
1073
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1074
    LANGUAGE plpgsql
1075
    AS $$
1076
BEGIN
1077
	RAISE NOTICE '%', sql;
1078
	RETURN QUERY EXECUTE sql;
1079
END;
1080
$$;
1081

    
1082

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

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

    
1089

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

    
1094
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1095
    LANGUAGE plpgsql
1096
    AS $$
1097
DECLARE
1098
	ret_val ret_type_null%TYPE;
1099
BEGIN
1100
	RAISE NOTICE '%', sql;
1101
	EXECUTE sql INTO STRICT ret_val;
1102
	RETURN ret_val;
1103
END;
1104
$$;
1105

    
1106

    
1107
--
1108
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1109
--
1110

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

    
1113

    
1114
--
1115
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117

    
1118
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1119
    LANGUAGE sql
1120
    AS $_$
1121
SELECT util.eval2val($$SELECT $$||$1, $2)
1122
$_$;
1123

    
1124

    
1125
--
1126
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1127
--
1128

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

    
1131

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

    
1136
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1137
    LANGUAGE sql
1138
    AS $_$
1139
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1140
$_$;
1141

    
1142

    
1143
--
1144
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1145
--
1146

    
1147
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1148
ret_type_null: NULL::ret_type';
1149

    
1150

    
1151
--
1152
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1153
--
1154

    
1155
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1156
    LANGUAGE sql STABLE STRICT
1157
    AS $_$
1158
SELECT col_name
1159
FROM unnest($2) s (col_name)
1160
WHERE util.col_exists(($1, col_name))
1161
$_$;
1162

    
1163

    
1164
--
1165
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1166
--
1167

    
1168
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1169
    LANGUAGE sql
1170
    AS $_$
1171
SELECT util.eval2set($$EXPLAIN $$||$1)
1172
$_$;
1173

    
1174

    
1175
--
1176
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1177
--
1178

    
1179
CREATE FUNCTION explain2notice(sql text) RETURNS void
1180
    LANGUAGE plpgsql
1181
    AS $_$
1182
BEGIN
1183
	RAISE NOTICE '%', $$EXPLAIN:
1184
$$||util.explain2str(sql);
1185
END;
1186
$_$;
1187

    
1188

    
1189
--
1190
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1191
--
1192

    
1193
CREATE FUNCTION explain2str(sql text) RETURNS text
1194
    LANGUAGE sql
1195
    AS $_$
1196
SELECT util.join_strs(explain, $$
1197
$$) FROM util.explain($1)
1198
$_$;
1199

    
1200

    
1201
SET default_tablespace = '';
1202

    
1203
SET default_with_oids = false;
1204

    
1205
--
1206
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1207
--
1208

    
1209
CREATE TABLE explain (
1210
    line text NOT NULL
1211
);
1212

    
1213

    
1214
--
1215
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1216
--
1217

    
1218
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1219
    LANGUAGE sql
1220
    AS $_$
1221
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1222
$$||quote_nullable($1)||$$
1223
)$$)
1224
$_$;
1225

    
1226

    
1227
--
1228
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1229
--
1230

    
1231
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS 'usage:
1232
PERFORM util.explain2table($$
1233
query
1234
$$);';
1235

    
1236

    
1237
--
1238
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1239
--
1240

    
1241
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1242
    LANGUAGE sql IMMUTABLE
1243
    AS $_$
1244
-- STRICT handles NULLs, so that the array will always be a value
1245
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1246
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1247
) END
1248
$_$;
1249

    
1250

    
1251
--
1252
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1253
--
1254

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

    
1257

    
1258
--
1259
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1260
--
1261

    
1262
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1263
    LANGUAGE plpgsql
1264
    AS $_$
1265
DECLARE
1266
	PG_EXCEPTION_DETAIL text;
1267
	recreate_users_cmd text = util.save_drop_views(users);
1268
BEGIN
1269
	PERFORM util.eval(cmd);
1270
	PERFORM util.eval(recreate_users_cmd);
1271
EXCEPTION
1272
WHEN dependent_objects_still_exist THEN
1273
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1274
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1275
	users = array(SELECT * FROM util.regexp_matches_group(
1276
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1277
	IF util.is_empty(users) THEN RAISE; END IF;
1278
	PERFORM util.force_recreate(cmd, users);
1279
END;
1280
$_$;
1281

    
1282

    
1283
--
1284
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1285
--
1286

    
1287
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS 'idempotent
1288

    
1289
users: not necessary to provide this because it will be autopopulated';
1290

    
1291

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

    
1296
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1297
    LANGUAGE plpgsql STRICT
1298
    AS $_$
1299
DECLARE
1300
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1301
$$||query;
1302
BEGIN
1303
	EXECUTE mk_view;
1304
EXCEPTION
1305
WHEN invalid_table_definition THEN
1306
	IF SQLERRM = 'cannot drop columns from view'
1307
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1308
	THEN
1309
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1310
		EXECUTE mk_view;
1311
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1312
	END IF;
1313
END;
1314
$_$;
1315

    
1316

    
1317
--
1318
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1319
--
1320

    
1321
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1322

    
1323

    
1324
--
1325
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327

    
1328
CREATE FUNCTION grants_users() RETURNS SETOF text
1329
    LANGUAGE sql IMMUTABLE
1330
    AS $$
1331
VALUES ('bien_read'), ('public_')
1332
$$;
1333

    
1334

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

    
1339
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1340
    LANGUAGE sql IMMUTABLE
1341
    AS $_$
1342
SELECT substring($2 for length($1)) = $1
1343
$_$;
1344

    
1345

    
1346
--
1347
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1348
--
1349

    
1350
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1351
    LANGUAGE sql IMMUTABLE
1352
    AS $_$
1353
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1354
$_$;
1355

    
1356

    
1357
--
1358
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1359
--
1360

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

    
1363

    
1364
--
1365
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1366
--
1367

    
1368
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1369
    LANGUAGE sql STABLE STRICT
1370
    AS $_$
1371
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1372
$_$;
1373

    
1374

    
1375
--
1376
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1377
--
1378

    
1379
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1380
    LANGUAGE sql IMMUTABLE
1381
    AS $_$
1382
SELECT util.array_length($1) = 0
1383
$_$;
1384

    
1385

    
1386
--
1387
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1388
--
1389

    
1390
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1391
    LANGUAGE sql IMMUTABLE
1392
    AS $_$
1393
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1394
$_$;
1395

    
1396

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

    
1401
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1402
    LANGUAGE sql IMMUTABLE
1403
    AS $_$
1404
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1405
$_$;
1406

    
1407

    
1408
--
1409
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1410
--
1411

    
1412
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1413
    LANGUAGE sql IMMUTABLE STRICT
1414
    AS $_$
1415
SELECT $1 || $3 || $2
1416
$_$;
1417

    
1418

    
1419
--
1420
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1421
--
1422

    
1423
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1424
    LANGUAGE sql IMMUTABLE
1425
    AS $_$
1426
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1427
$_$;
1428

    
1429

    
1430
--
1431
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1432
--
1433

    
1434
CREATE FUNCTION map_filter_insert() RETURNS trigger
1435
    LANGUAGE plpgsql
1436
    AS $$
1437
BEGIN
1438
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1439
	RETURN new;
1440
END;
1441
$$;
1442

    
1443

    
1444
--
1445
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1446
--
1447

    
1448
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1449
    LANGUAGE plpgsql STABLE STRICT
1450
    AS $_$
1451
DECLARE
1452
    value text;
1453
BEGIN
1454
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1455
        INTO value USING key;
1456
    RETURN value;
1457
END;
1458
$_$;
1459

    
1460

    
1461
--
1462
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1463
--
1464

    
1465
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1466
    LANGUAGE sql IMMUTABLE
1467
    AS $_$
1468
SELECT util._map(util.nulls_map($1), $2)
1469
$_$;
1470

    
1471

    
1472
--
1473
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1474
--
1475

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

    
1478
[1] inlining of function calls, which is different from constant folding
1479
[2] _map()''s profiling query
1480
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1481
and map_nulls()''s profiling query
1482
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1483
both take ~920 ms.
1484
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.';
1485

    
1486

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

    
1491
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1492
    LANGUAGE plpgsql STABLE STRICT
1493
    AS $_$
1494
BEGIN
1495
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1496
END;
1497
$_$;
1498

    
1499

    
1500
--
1501
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1502
--
1503

    
1504
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1505
    LANGUAGE sql STRICT
1506
    AS $_$
1507
SELECT util.create_if_not_exists($$
1508
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1509
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1510
||quote_literal($2)||$$;
1511
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1512
$$)
1513
$_$;
1514

    
1515

    
1516
--
1517
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1518
--
1519

    
1520
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1521

    
1522

    
1523
--
1524
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1525
--
1526

    
1527
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1528
    LANGUAGE plpgsql STRICT
1529
    AS $_$
1530
DECLARE
1531
    type regtype = util.typeof(expr, col.table_::text::regtype);
1532
    col_name_sql text = quote_ident(col.name);
1533
BEGIN
1534
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1535
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1536
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1537
$$||expr||$$;
1538
$$);
1539
END;
1540
$_$;
1541

    
1542

    
1543
--
1544
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1545
--
1546

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

    
1549

    
1550
--
1551
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1552
--
1553

    
1554
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1555
    LANGUAGE sql STRICT
1556
    AS $_$
1557
SELECT util.create_if_not_exists($$
1558
CREATE TABLE $$||$1||$$
1559
(
1560
    LIKE util.map INCLUDING ALL
1561
);
1562

    
1563
CREATE TRIGGER map_filter_insert
1564
  BEFORE INSERT
1565
  ON $$||$1||$$
1566
  FOR EACH ROW
1567
  EXECUTE PROCEDURE util.map_filter_insert();
1568
$$)
1569
$_$;
1570

    
1571

    
1572
--
1573
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1574
--
1575

    
1576
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1577
    LANGUAGE sql STRICT
1578
    AS $_$
1579
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1580
$_$;
1581

    
1582

    
1583
--
1584
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1585
--
1586

    
1587
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1588

    
1589

    
1590
--
1591
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1592
--
1593

    
1594
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1595
    LANGUAGE plpgsql STRICT
1596
    AS $_$
1597
DECLARE
1598
	view_qual_name text = util.qual_name(view_);
1599
BEGIN
1600
	EXECUTE $$
1601
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1602
  RETURNS SETOF $$||view_||$$ AS
1603
$BODY1$
1604
SELECT * FROM $$||view_qual_name||$$
1605
ORDER BY sort_col
1606
LIMIT $1 OFFSET $2
1607
$BODY1$
1608
  LANGUAGE sql STABLE
1609
  COST 100
1610
  ROWS 1000
1611
$$;
1612
	
1613
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1614
END;
1615
$_$;
1616

    
1617

    
1618
--
1619
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1620
--
1621

    
1622
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1623
    LANGUAGE plpgsql STRICT
1624
    AS $_$
1625
DECLARE
1626
	view_qual_name text = util.qual_name(view_);
1627
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1628
BEGIN
1629
	EXECUTE $$
1630
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1631
  RETURNS integer AS
1632
$BODY1$
1633
SELECT $$||quote_ident(row_num_col)||$$
1634
FROM $$||view_qual_name||$$
1635
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1636
LIMIT 1
1637
$BODY1$
1638
  LANGUAGE sql STABLE
1639
  COST 100;
1640
$$;
1641
	
1642
	EXECUTE $$
1643
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1644
  RETURNS SETOF $$||view_||$$ AS
1645
$BODY1$
1646
SELECT * FROM $$||view_qual_name||$$
1647
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1648
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1649
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1650
ORDER BY $$||quote_ident(row_num_col)||$$
1651
$BODY1$
1652
  LANGUAGE sql STABLE
1653
  COST 100
1654
  ROWS 1000
1655
$$;
1656
	
1657
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1658
END;
1659
$_$;
1660

    
1661

    
1662
--
1663
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1664
--
1665

    
1666
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1667
    LANGUAGE plpgsql STRICT
1668
    AS $_$
1669
DECLARE
1670
	view_qual_name text = util.qual_name(view_);
1671
BEGIN
1672
	EXECUTE $$
1673
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1674
  RETURNS SETOF $$||view_||$$
1675
  SET enable_sort TO 'off'
1676
  AS
1677
$BODY1$
1678
SELECT * FROM $$||view_qual_name||$$($2, $3)
1679
$BODY1$
1680
  LANGUAGE sql STABLE
1681
  COST 100
1682
  ROWS 1000
1683
;
1684
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1685
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1686
If you want to run EXPLAIN and get expanded output, use the regular subset
1687
function instead. (When a config param is set on a function, EXPLAIN produces
1688
just a function scan.)
1689
';
1690
$$;
1691
END;
1692
$_$;
1693

    
1694

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

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

    
1701

    
1702
--
1703
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1704
--
1705

    
1706
CREATE FUNCTION name(type regtype) RETURNS text
1707
    LANGUAGE sql STABLE STRICT
1708
    AS $_$
1709
SELECT typname::text FROM pg_type WHERE oid = $1
1710
$_$;
1711

    
1712

    
1713
--
1714
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1715
--
1716

    
1717
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1718
    LANGUAGE sql IMMUTABLE
1719
    AS $_$
1720
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1721
$_$;
1722

    
1723

    
1724
--
1725
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1726
--
1727

    
1728
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1729
    LANGUAGE sql IMMUTABLE
1730
    AS $_$
1731
SELECT $1 IS NOT NULL
1732
$_$;
1733

    
1734

    
1735
--
1736
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1737
--
1738

    
1739
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1740
    LANGUAGE sql IMMUTABLE
1741
    AS $_$
1742
SELECT util.hstore($1, NULL) || '*=>*'
1743
$_$;
1744

    
1745

    
1746
--
1747
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1748
--
1749

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

    
1752

    
1753
--
1754
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1755
--
1756

    
1757
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1758
    LANGUAGE sql IMMUTABLE
1759
    AS $_$
1760
SELECT $2 + COALESCE($1, 0)
1761
$_$;
1762

    
1763

    
1764
--
1765
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767

    
1768
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1769
    LANGUAGE sql STABLE
1770
    AS $_$
1771
SELECT util.type_qual_name($1::text::regtype)
1772
$_$;
1773

    
1774

    
1775
--
1776
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1777
--
1778

    
1779
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1780
    LANGUAGE plpgsql IMMUTABLE STRICT
1781
    AS $$
1782
BEGIN
1783
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1784
END;
1785
$$;
1786

    
1787

    
1788
--
1789
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
1790
--
1791

    
1792
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
1793
    LANGUAGE sql IMMUTABLE
1794
    AS $_$
1795
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
1796
$_$;
1797

    
1798

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

    
1803
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1804
    LANGUAGE sql STRICT
1805
    AS $_$
1806
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1807
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1808
FROM util.col_names($1::text::regtype) f (name);
1809
SELECT NULL::void; -- don't fold away functions called in previous query
1810
$_$;
1811

    
1812

    
1813
--
1814
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1815
--
1816

    
1817
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1818

    
1819

    
1820
--
1821
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1822
--
1823

    
1824
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1825
    LANGUAGE sql STRICT
1826
    AS $_$
1827
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1828
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1829
SELECT util.set_col_names($1, $2);
1830
$_$;
1831

    
1832

    
1833
--
1834
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1835
--
1836

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

    
1840

    
1841
--
1842
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1843
--
1844

    
1845
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1846
    LANGUAGE sql STRICT
1847
    AS $_$
1848
SELECT util.drop_table($1);
1849
SELECT util.mk_map_table($1);
1850
$_$;
1851

    
1852

    
1853
--
1854
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
1858
    LANGUAGE plpgsql STRICT
1859
    AS $_$
1860
DECLARE
1861
	result text = NULL;
1862
BEGIN
1863
	BEGIN
1864
		result = util.show_create_view(view_);
1865
		PERFORM util.eval($$DROP VIEW $$||view_);
1866
	EXCEPTION
1867
		WHEN undefined_table THEN NULL;
1868
	END;
1869
	RETURN result;
1870
END;
1871
$_$;
1872

    
1873

    
1874
--
1875
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
1876
--
1877

    
1878
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
1879
    LANGUAGE sql
1880
    AS $_$
1881
SELECT concat(util.save_drop_view(unnest)) FROM unnest($1)
1882
$_$;
1883

    
1884

    
1885
--
1886
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1887
--
1888

    
1889
CREATE FUNCTION schema(type regtype) RETURNS text
1890
    LANGUAGE sql STABLE
1891
    AS $_$
1892
SELECT nspname::text
1893
FROM pg_type
1894
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1895
WHERE pg_type.oid = $1
1896
$_$;
1897

    
1898

    
1899
--
1900
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1901
--
1902

    
1903
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1904
    LANGUAGE sql STABLE
1905
    AS $_$
1906
SELECT util.schema(pg_typeof($1))
1907
$_$;
1908

    
1909

    
1910
--
1911
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
1912
--
1913

    
1914
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
1915
    LANGUAGE sql STABLE
1916
    AS $_$
1917
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
1918
$_$;
1919

    
1920

    
1921
--
1922
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
1923
--
1924

    
1925
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS 'a schema bundle is a group of schemas with a common prefix';
1926

    
1927

    
1928
--
1929
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
1930
--
1931

    
1932
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
1933
    LANGUAGE sql
1934
    AS $_$
1935
SELECT util.schema_rename(old_schema,
1936
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
1937
FROM util.schema_bundle_get_schemas($1) f (old_schema);
1938
SELECT NULL::void; -- don't fold away functions called in previous query
1939
$_$;
1940

    
1941

    
1942
--
1943
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
1944
--
1945

    
1946
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
1947
    LANGUAGE plpgsql
1948
    AS $$
1949
BEGIN
1950
	-- don't schema_bundle_rm() the schema_bundle to keep!
1951
	IF replace = with_ THEN RETURN; END IF;
1952
	
1953
	PERFORM util.schema_bundle_rm(replace);
1954
	PERFORM util.schema_bundle_rename(with_, replace);
1955
END;
1956
$$;
1957

    
1958

    
1959
--
1960
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
1961
--
1962

    
1963
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
1964
    LANGUAGE sql
1965
    AS $_$
1966
SELECT util.schema_rm(schema)
1967
FROM util.schema_bundle_get_schemas($1) f (schema);
1968
SELECT NULL::void; -- don't fold away functions called in previous query
1969
$_$;
1970

    
1971

    
1972
--
1973
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1974
--
1975

    
1976
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1977
    LANGUAGE sql STABLE
1978
    AS $_$
1979
SELECT quote_ident(util.schema($1))
1980
$_$;
1981

    
1982

    
1983
--
1984
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
1985
--
1986

    
1987
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
1988
    LANGUAGE sql
1989
    AS $_$
1990
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
1991
$_$;
1992

    
1993

    
1994
--
1995
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
1996
--
1997

    
1998
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
1999
    LANGUAGE plpgsql
2000
    AS $$
2001
BEGIN
2002
	-- don't schema_rm() the schema to keep!
2003
	IF replace = with_ THEN RETURN; END IF;
2004
	
2005
	PERFORM util.schema_rm(replace);
2006
	PERFORM util.schema_rename(with_, replace);
2007
END;
2008
$$;
2009

    
2010

    
2011
--
2012
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2013
--
2014

    
2015
CREATE FUNCTION schema_rm(schema text) RETURNS void
2016
    LANGUAGE sql
2017
    AS $_$
2018
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2019
$_$;
2020

    
2021

    
2022
--
2023
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2024
--
2025

    
2026
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2027
    LANGUAGE sql STRICT
2028
    AS $_$
2029
SELECT util.eval(
2030
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2031
$_$;
2032

    
2033

    
2034
--
2035
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2036
--
2037

    
2038
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2039
    LANGUAGE plpgsql STRICT
2040
    AS $_$
2041
DECLARE
2042
    old text[] = ARRAY(SELECT util.col_names(table_));
2043
    new text[] = ARRAY(SELECT util.map_values(names));
2044
BEGIN
2045
    old = old[1:array_length(new, 1)]; -- truncate to same length
2046
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2047
||$$ TO $$||quote_ident(value))
2048
    FROM each(hstore(old, new))
2049
    WHERE value != key -- not same name
2050
    ;
2051
END;
2052
$_$;
2053

    
2054

    
2055
--
2056
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2057
--
2058

    
2059
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
2060

    
2061

    
2062
--
2063
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2064
--
2065

    
2066
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2067
    LANGUAGE plpgsql STRICT
2068
    AS $_$
2069
DECLARE
2070
	row_ util.map;
2071
BEGIN
2072
	-- rename any metadata cols rather than re-adding them with new names
2073
	BEGIN
2074
		PERFORM util.set_col_names(table_, names);
2075
	EXCEPTION
2076
		WHEN array_subscript_error THEN -- selective suppress
2077
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2078
				-- metadata cols not yet added
2079
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2080
			END IF;
2081
	END;
2082
	
2083
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2084
	LOOP
2085
		PERFORM util.mk_const_col((table_, row_."to"),
2086
			substring(row_."from" from 2));
2087
	END LOOP;
2088
	
2089
	PERFORM util.set_col_names(table_, names);
2090
END;
2091
$_$;
2092

    
2093

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

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

    
2101

    
2102
--
2103
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2104
--
2105

    
2106
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2107
    LANGUAGE plpgsql STRICT
2108
    AS $_$
2109
DECLARE
2110
    sql text = $$ALTER TABLE $$||table_||$$
2111
$$||NULLIF(array_to_string(ARRAY(
2112
    SELECT
2113
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2114
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2115
    FROM
2116
    (
2117
        SELECT
2118
          quote_ident(col_name) AS col_name_sql
2119
        , util.col_type((table_, col_name)) AS curr_type
2120
        , type AS target_type
2121
        FROM unnest(col_casts)
2122
    ) s
2123
    WHERE curr_type != target_type
2124
), '
2125
, '), '');
2126
BEGIN
2127
    RAISE NOTICE '%', sql;
2128
    EXECUTE COALESCE(sql, '');
2129
END;
2130
$_$;
2131

    
2132

    
2133
--
2134
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2135
--
2136

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

    
2139

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

    
2144
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2145
    LANGUAGE sql STABLE
2146
    AS $_$
2147
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2148
$$||util.show_grants_for($1)
2149
$_$;
2150

    
2151

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

    
2156
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2157
    LANGUAGE sql STABLE
2158
    AS $_$
2159
SELECT concat(cmd)
2160
FROM
2161
(
2162
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2163
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2164
$$ ELSE '' END) AS cmd
2165
	FROM util.grants_users() f (user_)
2166
) s
2167
$_$;
2168

    
2169

    
2170
--
2171
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2172
--
2173

    
2174
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2175
    LANGUAGE plpgsql STABLE STRICT
2176
    AS $_$
2177
DECLARE
2178
    hstore hstore;
2179
BEGIN
2180
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2181
        table_||$$))$$ INTO STRICT hstore;
2182
    RETURN hstore;
2183
END;
2184
$_$;
2185

    
2186

    
2187
--
2188
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2189
--
2190

    
2191
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2192
    LANGUAGE sql STABLE STRICT
2193
    AS $_$
2194
SELECT COUNT(*) > 0 FROM pg_constraint
2195
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2196
$_$;
2197

    
2198

    
2199
--
2200
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2201
--
2202

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

    
2205

    
2206
--
2207
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2208
--
2209

    
2210
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2211
    LANGUAGE sql STRICT
2212
    AS $_$
2213
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2214
||quote_ident($2)||$$ CHECK (true)$$)
2215
$_$;
2216

    
2217

    
2218
--
2219
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2220
--
2221

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

    
2225

    
2226
--
2227
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2228
--
2229

    
2230
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2231
    LANGUAGE sql STABLE STRICT
2232
    AS $_$
2233
SELECT util.table_flag__get($1, 'nulls_mapped')
2234
$_$;
2235

    
2236

    
2237
--
2238
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2239
--
2240

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

    
2243

    
2244
--
2245
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2246
--
2247

    
2248
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2249
    LANGUAGE sql STRICT
2250
    AS $_$
2251
SELECT util.table_flag__set($1, 'nulls_mapped')
2252
$_$;
2253

    
2254

    
2255
--
2256
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2257
--
2258

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

    
2262

    
2263
--
2264
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2265
--
2266

    
2267
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
2268
    LANGUAGE sql STABLE STRICT
2269
    AS $_$
2270
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
2271
$_$;
2272

    
2273

    
2274
--
2275
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2276
--
2277

    
2278
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2279
    LANGUAGE plpgsql STRICT
2280
    AS $_$
2281
DECLARE
2282
    row record;
2283
BEGIN
2284
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2285
    LOOP
2286
        IF row.global_name != row.name THEN
2287
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2288
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2289
        END IF;
2290
    END LOOP;
2291
END;
2292
$_$;
2293

    
2294

    
2295
--
2296
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2297
--
2298

    
2299
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
2300

    
2301

    
2302
--
2303
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2304
--
2305

    
2306
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2307
    LANGUAGE sql STRICT
2308
    AS $_$
2309
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2310
SELECT NULL::void; -- don't fold away functions called in previous query
2311
$_$;
2312

    
2313

    
2314
--
2315
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2316
--
2317

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

    
2321

    
2322
--
2323
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2324
--
2325

    
2326
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2327
    LANGUAGE plpgsql STRICT
2328
    AS $_$
2329
BEGIN
2330
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2331
END;
2332
$_$;
2333

    
2334

    
2335
--
2336
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2337
--
2338

    
2339
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
2340

    
2341

    
2342
--
2343
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2344
--
2345

    
2346
CREATE FUNCTION try_create(sql text) RETURNS void
2347
    LANGUAGE plpgsql STRICT
2348
    AS $$
2349
BEGIN
2350
    PERFORM util.eval(sql);
2351
EXCEPTION
2352
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2353
    WHEN undefined_column THEN NULL;
2354
    WHEN duplicate_column THEN NULL;
2355
END;
2356
$$;
2357

    
2358

    
2359
--
2360
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2361
--
2362

    
2363
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
2364

    
2365

    
2366
--
2367
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2368
--
2369

    
2370
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2371
    LANGUAGE sql STRICT
2372
    AS $_$
2373
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2374
$_$;
2375

    
2376

    
2377
--
2378
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2379
--
2380

    
2381
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
2382

    
2383

    
2384
--
2385
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2386
--
2387

    
2388
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2389
    LANGUAGE sql IMMUTABLE
2390
    AS $_$
2391
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2392
$_$;
2393

    
2394

    
2395
--
2396
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2397
--
2398

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

    
2401

    
2402
--
2403
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2404
--
2405

    
2406
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2407
    LANGUAGE sql STABLE STRICT
2408
    SET search_path TO pg_temp
2409
    AS $_$
2410
SELECT $1::text
2411
$_$;
2412

    
2413

    
2414
--
2415
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2416
--
2417

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

    
2420

    
2421
--
2422
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2423
--
2424

    
2425
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2426
    LANGUAGE plpgsql STABLE
2427
    AS $_$
2428
DECLARE
2429
    type regtype;
2430
BEGIN
2431
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2432
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2433
    RETURN type;
2434
END;
2435
$_$;
2436

    
2437

    
2438
--
2439
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2440
--
2441

    
2442
CREATE AGGREGATE all_same(anyelement) (
2443
    SFUNC = all_same_transform,
2444
    STYPE = anyarray,
2445
    FINALFUNC = all_same_final
2446
);
2447

    
2448

    
2449
--
2450
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2451
--
2452

    
2453
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2454

    
2455

    
2456
--
2457
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2458
--
2459

    
2460
CREATE AGGREGATE join_strs(text, text) (
2461
    SFUNC = join_strs_transform,
2462
    STYPE = text
2463
);
2464

    
2465

    
2466
--
2467
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2468
--
2469

    
2470
CREATE OPERATOR -> (
2471
    PROCEDURE = map_get,
2472
    LEFTARG = regclass,
2473
    RIGHTARG = text
2474
);
2475

    
2476

    
2477
--
2478
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2479
--
2480

    
2481
CREATE OPERATOR => (
2482
    PROCEDURE = hstore,
2483
    LEFTARG = text[],
2484
    RIGHTARG = text
2485
);
2486

    
2487

    
2488
--
2489
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2490
--
2491

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

    
2494

    
2495
--
2496
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2497
--
2498

    
2499
CREATE OPERATOR ?*>= (
2500
    PROCEDURE = is_populated_more_often_than,
2501
    LEFTARG = anyelement,
2502
    RIGHTARG = anyelement
2503
);
2504

    
2505

    
2506
--
2507
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2508
--
2509

    
2510
CREATE OPERATOR ?>= (
2511
    PROCEDURE = is_more_complete_than,
2512
    LEFTARG = anyelement,
2513
    RIGHTARG = anyelement
2514
);
2515

    
2516

    
2517
--
2518
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2519
--
2520

    
2521
CREATE OPERATOR ||% (
2522
    PROCEDURE = concat_esc,
2523
    LEFTARG = text,
2524
    RIGHTARG = text
2525
);
2526

    
2527

    
2528
--
2529
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2530
--
2531

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

    
2534

    
2535
--
2536
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2537
--
2538

    
2539
CREATE TABLE map (
2540
    "from" text NOT NULL,
2541
    "to" text,
2542
    filter text,
2543
    notes text
2544
);
2545

    
2546

    
2547
--
2548
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2549
--
2550

    
2551

    
2552

    
2553
--
2554
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2555
--
2556

    
2557

    
2558

    
2559
--
2560
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2561
--
2562

    
2563
ALTER TABLE ONLY map
2564
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2565

    
2566

    
2567
--
2568
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2569
--
2570

    
2571
ALTER TABLE ONLY map
2572
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2573

    
2574

    
2575
--
2576
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2577
--
2578

    
2579
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2580

    
2581

    
2582
--
2583
-- PostgreSQL database dump complete
2584
--
2585

    
(19-19/29)