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: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
590
--
591

    
592
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
593
    LANGUAGE sql
594
    AS $_$
595
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
596
$_$;
597

    
598

    
599
--
600
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
604
    LANGUAGE sql STRICT
605
    AS $_$
606
SELECT util.set_comment($1, concat(util.comment($1), $2))
607
$_$;
608

    
609

    
610
--
611
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
612
--
613

    
614
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
615
comment: must start and end with a newline
616
';
617

    
618

    
619
--
620
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
621
--
622

    
623
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
624
    LANGUAGE sql IMMUTABLE
625
    AS $_$
626
SELECT pg_catalog.array_fill($1, ARRAY[$2])
627
$_$;
628

    
629

    
630
--
631
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
635
    LANGUAGE sql IMMUTABLE
636
    AS $_$
637
SELECT util.array_length($1, 1)
638
$_$;
639

    
640

    
641
--
642
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
643
--
644

    
645
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
646
    LANGUAGE sql IMMUTABLE
647
    AS $_$
648
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
649
$_$;
650

    
651

    
652
--
653
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
654
--
655

    
656
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
657
returns 0 instead of NULL for empty arrays
658
';
659

    
660

    
661
--
662
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
663
--
664

    
665
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
666
    LANGUAGE sql STABLE STRICT
667
    AS $_$
668
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
669
$_$;
670

    
671

    
672
--
673
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
674
--
675

    
676
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
677
    LANGUAGE plpgsql STRICT
678
    AS $_$
679
BEGIN
680
    -- not yet clustered (ARRAY[] compares NULLs literally)
681
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
682
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
683
    END IF;
684
END;
685
$_$;
686

    
687

    
688
--
689
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
690
--
691

    
692
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
693
idempotent
694
';
695

    
696

    
697
--
698
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
699
--
700

    
701
CREATE FUNCTION col__min(col col_ref) RETURNS integer
702
    LANGUAGE sql STABLE
703
    AS $_$
704
SELECT util.eval2val($$
705
SELECT $$||quote_ident($1.name)||$$
706
FROM $$||$1.table_||$$
707
ORDER BY $$||quote_ident($1.name)||$$ ASC
708
LIMIT 1
709
$$, NULL::integer)
710
$_$;
711

    
712

    
713
--
714
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
715
--
716

    
717
CREATE FUNCTION col_comment(col col_ref) RETURNS text
718
    LANGUAGE plpgsql STABLE STRICT
719
    AS $$
720
DECLARE
721
	comment text;
722
BEGIN
723
	SELECT description
724
	FROM pg_attribute
725
	LEFT JOIN pg_description ON objoid = attrelid
726
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
727
	WHERE attrelid = col.table_ AND attname = col.name
728
	INTO STRICT comment
729
	;
730
	RETURN comment;
731
EXCEPTION
732
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
733
END;
734
$$;
735

    
736

    
737
--
738
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
739
--
740

    
741
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
742
    LANGUAGE plpgsql STABLE STRICT
743
    AS $$
744
DECLARE
745
	default_sql text;
746
BEGIN
747
	SELECT adsrc
748
	FROM pg_attribute
749
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
750
	WHERE attrelid = col.table_ AND attname = col.name
751
	INTO STRICT default_sql
752
	;
753
	RETURN default_sql;
754
EXCEPTION
755
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
756
END;
757
$$;
758

    
759

    
760
--
761
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
762
--
763

    
764
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
765
    LANGUAGE sql STABLE
766
    AS $_$
767
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
768
$_$;
769

    
770

    
771
--
772
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
773
--
774

    
775
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
776
ret_type_null: NULL::ret_type
777
';
778

    
779

    
780
--
781
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
782
--
783

    
784
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
785
    LANGUAGE plpgsql STRICT
786
    AS $$
787
BEGIN
788
    PERFORM util.col_type(col);
789
    RETURN true;
790
EXCEPTION
791
    WHEN undefined_column THEN RETURN false;
792
END;
793
$$;
794

    
795

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

    
800
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
801
    LANGUAGE plpgsql STABLE STRICT
802
    AS $$
803
DECLARE
804
    prefix text := util.name(type)||'.';
805
BEGIN
806
    RETURN QUERY
807
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
808
        FROM util.col_names(type) f (name_);
809
END;
810
$$;
811

    
812

    
813
--
814
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
815
--
816

    
817
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
818
    LANGUAGE sql STABLE STRICT
819
    AS $_$
820
SELECT attname::text
821
FROM pg_attribute
822
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
823
ORDER BY attnum
824
$_$;
825

    
826

    
827
--
828
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
829
--
830

    
831
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
832
    LANGUAGE plpgsql STABLE STRICT
833
    AS $_$
834
BEGIN
835
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
836
END;
837
$_$;
838

    
839

    
840
--
841
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
842
--
843

    
844
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
845
    LANGUAGE plpgsql STABLE STRICT
846
    AS $$
847
DECLARE
848
    type regtype;
849
BEGIN
850
    SELECT atttypid FROM pg_attribute
851
    WHERE attrelid = col.table_ AND attname = col.name
852
    INTO STRICT type
853
    ;
854
    RETURN type;
855
EXCEPTION
856
    WHEN no_data_found THEN
857
        RAISE undefined_column USING MESSAGE =
858
            concat('undefined column: ', col.name);
859
END;
860
$$;
861

    
862

    
863
--
864
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
865
--
866

    
867
CREATE FUNCTION comment(element oid) RETURNS text
868
    LANGUAGE sql STABLE STRICT
869
    AS $_$
870
SELECT description FROM pg_description WHERE objoid = $1
871
$_$;
872

    
873

    
874
--
875
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
876
--
877

    
878
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
879
    LANGUAGE sql IMMUTABLE
880
    AS $_$
881
SELECT util.esc_name__append($2, $1)
882
$_$;
883

    
884

    
885
--
886
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
887
--
888

    
889
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
890
    LANGUAGE sql IMMUTABLE
891
    AS $_$
892
SELECT position($1 in $2) > 0 /*1-based offset*/
893
$_$;
894

    
895

    
896
--
897
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
898
--
899

    
900
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
901
    LANGUAGE sql
902
    AS $_$
903
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
904
$_$;
905

    
906

    
907
--
908
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
909
--
910

    
911
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
912
    LANGUAGE plpgsql STRICT
913
    AS $$
914
BEGIN
915
    PERFORM util.eval(sql);
916
EXCEPTION
917
    WHEN duplicate_table  THEN NULL;
918
    WHEN duplicate_object THEN NULL; -- e.g. constraint
919
    WHEN duplicate_column THEN NULL;
920
    WHEN invalid_table_definition THEN
921
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
922
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
923
        END IF;
924
END;
925
$$;
926

    
927

    
928
--
929
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
930
--
931

    
932
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
933
idempotent
934
';
935

    
936

    
937
--
938
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
939
--
940

    
941
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
942
    LANGUAGE sql IMMUTABLE
943
    AS $$
944
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
945
$$;
946

    
947

    
948
--
949
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
950
--
951

    
952
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
953
    LANGUAGE sql IMMUTABLE
954
    AS $_$
955
/* newline before so the query starts at the beginning of the line.
956
newline after to visually separate queries from one another. */
957
SELECT util.raise_notice($$
958
$$||$1||$$
959
$$)
960
$_$;
961

    
962

    
963
--
964
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
965
--
966

    
967
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
968
    LANGUAGE sql STABLE STRICT
969
    AS $_$
970
SELECT util.eval2set($$
971
SELECT col
972
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
973
LEFT JOIN $$||$2||$$ ON "to" = col
974
WHERE "from" IS NULL
975
$$, NULL::text)
976
$_$;
977

    
978

    
979
--
980
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
981
--
982

    
983
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
984
gets table_''s derived columns (all the columns not in the names table)
985
';
986

    
987

    
988
--
989
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
990
--
991

    
992
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
993
    LANGUAGE sql STABLE
994
    AS $_$
995
SELECT * FROM util.diff($1::text, $2::text, $3,
996
	util.has_single_row($1) AND util.has_single_row($2))
997
$_$;
998

    
999

    
1000
--
1001
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1002
--
1003

    
1004
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1005
col_type_null (*required*): NULL::shared_base_type
1006
usage:
1007
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1008
';
1009

    
1010

    
1011
--
1012
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1013
--
1014

    
1015
CREATE FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1016
    LANGUAGE sql STABLE
1017
    AS $_$
1018
SELECT * FROM
1019
util.eval2col_pair($$
1020
/* need to explicitly cast each side to the return type because this does not
1021
happen automatically even when an implicit cast is available */
1022
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
1023
FROM $$||$1||$$ left_
1024
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
1025
$$||util._if($4, ''::text,
1026
$$ON left_::$$||pg_typeof($3)||$$ = right_::$$||pg_typeof($3)||$$
1027
$$)||
1028
$$WHERE left_::$$||pg_typeof($3)||$$ IS DISTINCT FROM right_::$$||pg_typeof($3)||$$
1029
ORDER BY left_, right_
1030
$$, $3)
1031
$_$;
1032

    
1033

    
1034
--
1035
-- Name: FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1036
--
1037

    
1038
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1039
col_type_null (*required*): NULL::col_type
1040
single_row: whether the tables consist of a single row, which should be
1041
	displayed side-by-side
1042

    
1043
to run EXPLAIN on the FULL JOIN query:
1044
# run this function
1045
# look for a NOTICE containing the expanded query that it ran
1046
# run EXPLAIN on this expanded query
1047
';
1048

    
1049

    
1050
--
1051
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1052
--
1053

    
1054
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1055
    LANGUAGE sql STRICT
1056
    AS $_$
1057
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1058
$_$;
1059

    
1060

    
1061
--
1062
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1063
--
1064

    
1065
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1066
idempotent
1067
';
1068

    
1069

    
1070
--
1071
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1072
--
1073

    
1074
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1075
    LANGUAGE sql STRICT
1076
    AS $_$
1077
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1078
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1079
$_$;
1080

    
1081

    
1082
--
1083
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1084
--
1085

    
1086
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1087
idempotent
1088
';
1089

    
1090

    
1091
--
1092
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1093
--
1094

    
1095
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1096
    LANGUAGE sql
1097
    AS $_$
1098
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1099
included in the debug SQL */
1100
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1101
$_$;
1102

    
1103

    
1104
--
1105
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1106
--
1107

    
1108
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1109
    LANGUAGE sql
1110
    AS $_$
1111
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1112
||util._if($3, $$ CASCADE$$, ''::text))
1113
$_$;
1114

    
1115

    
1116
--
1117
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1118
--
1119

    
1120
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1121
idempotent
1122
';
1123

    
1124

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

    
1129
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1130
    LANGUAGE sql
1131
    AS $_$
1132
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1133
$3)
1134
$_$;
1135

    
1136

    
1137
--
1138
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1139
--
1140

    
1141
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1142
    LANGUAGE sql
1143
    AS $_$
1144
SELECT util.drop_relation(relation, $3)
1145
FROM util.show_relations_like($1, $2) relation
1146
;
1147
SELECT NULL::void; -- don't fold away functions called in previous query
1148
$_$;
1149

    
1150

    
1151
--
1152
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1153
--
1154

    
1155
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1156
    LANGUAGE sql STRICT
1157
    AS $_$
1158
SELECT util.drop_relation('TABLE', $1, $2)
1159
$_$;
1160

    
1161

    
1162
--
1163
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1164
--
1165

    
1166
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1167
idempotent
1168
';
1169

    
1170

    
1171
--
1172
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1173
--
1174

    
1175
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1176
    LANGUAGE sql STRICT
1177
    AS $_$
1178
SELECT util.drop_relation('VIEW', $1, $2)
1179
$_$;
1180

    
1181

    
1182
--
1183
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1184
--
1185

    
1186
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1187
idempotent
1188
';
1189

    
1190

    
1191
--
1192
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1193
--
1194

    
1195
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1196
    LANGUAGE sql IMMUTABLE
1197
    AS $_$
1198
SELECT util.array_fill($1, 0)
1199
$_$;
1200

    
1201

    
1202
--
1203
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1204
--
1205

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

    
1210

    
1211
--
1212
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1213
--
1214

    
1215
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1216
    LANGUAGE sql IMMUTABLE
1217
    AS $_$
1218
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1219
$_$;
1220

    
1221

    
1222
--
1223
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1224
--
1225

    
1226
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1227
    LANGUAGE sql IMMUTABLE
1228
    AS $_$
1229
SELECT regexp_replace($2, '("?)$', $1||'\1')
1230
$_$;
1231

    
1232

    
1233
--
1234
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1235
--
1236

    
1237
CREATE FUNCTION eval(sql text) RETURNS void
1238
    LANGUAGE plpgsql STRICT
1239
    AS $$
1240
BEGIN
1241
	PERFORM util.debug_print_sql(sql);
1242
	EXECUTE sql;
1243
END;
1244
$$;
1245

    
1246

    
1247
--
1248
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1249
--
1250

    
1251
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1252
    LANGUAGE plpgsql
1253
    AS $$
1254
BEGIN
1255
	PERFORM util.debug_print_sql(sql);
1256
	RETURN QUERY EXECUTE sql;
1257
END;
1258
$$;
1259

    
1260

    
1261
--
1262
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1263
--
1264

    
1265
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1266
col_type_null (*required*): NULL::col_type
1267
';
1268

    
1269

    
1270
--
1271
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1272
--
1273

    
1274
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1275
    LANGUAGE plpgsql
1276
    AS $$
1277
BEGIN
1278
	PERFORM util.debug_print_sql(sql);
1279
	RETURN QUERY EXECUTE sql;
1280
END;
1281
$$;
1282

    
1283

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

    
1288
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1289
    LANGUAGE plpgsql
1290
    AS $$
1291
BEGIN
1292
	PERFORM util.debug_print_sql(sql);
1293
	RETURN QUERY EXECUTE sql;
1294
END;
1295
$$;
1296

    
1297

    
1298
--
1299
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1300
--
1301

    
1302
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1303
ret_type_null: NULL::ret_type
1304
';
1305

    
1306

    
1307
--
1308
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1309
--
1310

    
1311
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1312
    LANGUAGE plpgsql
1313
    AS $$
1314
DECLARE
1315
	ret_val ret_type_null%TYPE;
1316
BEGIN
1317
	PERFORM util.debug_print_sql(sql);
1318
	EXECUTE sql INTO STRICT ret_val;
1319
	RETURN ret_val;
1320
END;
1321
$$;
1322

    
1323

    
1324
--
1325
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1326
--
1327

    
1328
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1329
ret_type_null: NULL::ret_type
1330
';
1331

    
1332

    
1333
--
1334
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1335
--
1336

    
1337
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1338
    LANGUAGE sql
1339
    AS $_$
1340
SELECT util.eval2val($$SELECT $$||$1, $2)
1341
$_$;
1342

    
1343

    
1344
--
1345
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1346
--
1347

    
1348
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1349
ret_type_null: NULL::ret_type
1350
';
1351

    
1352

    
1353
--
1354
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1355
--
1356

    
1357
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1358
    LANGUAGE sql
1359
    AS $_$
1360
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1361
$_$;
1362

    
1363

    
1364
--
1365
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1366
--
1367

    
1368
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1369
sql: can be NULL, which will be passed through
1370
ret_type_null: NULL::ret_type
1371
';
1372

    
1373

    
1374
--
1375
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1376
--
1377

    
1378
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1379
    LANGUAGE sql STABLE STRICT
1380
    AS $_$
1381
SELECT col_name
1382
FROM unnest($2) s (col_name)
1383
WHERE util.col_exists(($1, col_name))
1384
$_$;
1385

    
1386

    
1387
--
1388
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1389
--
1390

    
1391
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1392
    LANGUAGE sql
1393
    AS $_$
1394
SELECT util.eval2set($$EXPLAIN $$||$1)
1395
$_$;
1396

    
1397

    
1398
--
1399
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1400
--
1401

    
1402
CREATE FUNCTION explain2notice(sql text) RETURNS void
1403
    LANGUAGE plpgsql
1404
    AS $_$
1405
BEGIN
1406
	RAISE NOTICE '%', $$EXPLAIN:
1407
$$||util.explain2str(sql);
1408
END;
1409
$_$;
1410

    
1411

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

    
1416
CREATE FUNCTION explain2str(sql text) RETURNS text
1417
    LANGUAGE sql
1418
    AS $_$
1419
SELECT util.join_strs(explain, $$
1420
$$) FROM util.explain($1)
1421
$_$;
1422

    
1423

    
1424
SET default_tablespace = '';
1425

    
1426
SET default_with_oids = false;
1427

    
1428
--
1429
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1430
--
1431

    
1432
CREATE TABLE explain (
1433
    line text NOT NULL
1434
);
1435

    
1436

    
1437
--
1438
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1439
--
1440

    
1441
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1442
    LANGUAGE sql
1443
    AS $_$
1444
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1445
$$||quote_nullable($1)||$$
1446
)$$)
1447
$_$;
1448

    
1449

    
1450
--
1451
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1452
--
1453

    
1454
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1455
usage:
1456
PERFORM util.explain2table($$
1457
query
1458
$$);
1459
';
1460

    
1461

    
1462
--
1463
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1464
--
1465

    
1466
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1467
    LANGUAGE sql IMMUTABLE
1468
    AS $_$
1469
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1470
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1471
) END
1472
$_$;
1473

    
1474

    
1475
--
1476
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1477
--
1478

    
1479
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1480
ensures that an array will always have proper non-NULL dimensions
1481
';
1482

    
1483

    
1484
--
1485
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1486
--
1487

    
1488
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1489
    LANGUAGE plpgsql
1490
    AS $_$
1491
DECLARE
1492
	PG_EXCEPTION_DETAIL text;
1493
	recreate_users_cmd text = util.save_drop_views(users);
1494
BEGIN
1495
	PERFORM util.eval(cmd);
1496
	PERFORM util.eval(recreate_users_cmd);
1497
EXCEPTION
1498
WHEN dependent_objects_still_exist THEN
1499
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1500
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1501
	users = array(SELECT * FROM util.regexp_matches_group(
1502
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1503
	IF util.is_empty(users) THEN RAISE; END IF;
1504
	PERFORM util.force_recreate(cmd, users);
1505
END;
1506
$_$;
1507

    
1508

    
1509
--
1510
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1511
--
1512

    
1513
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1514
idempotent
1515

    
1516
users: not necessary to provide this because it will be autopopulated
1517
';
1518

    
1519

    
1520
--
1521
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1522
--
1523

    
1524
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1525
    LANGUAGE plpgsql STRICT
1526
    AS $_$
1527
DECLARE
1528
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1529
$$||query;
1530
BEGIN
1531
	EXECUTE mk_view;
1532
EXCEPTION
1533
WHEN invalid_table_definition THEN
1534
	IF SQLERRM = 'cannot drop columns from view'
1535
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1536
	THEN
1537
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1538
		EXECUTE mk_view;
1539
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1540
	END IF;
1541
END;
1542
$_$;
1543

    
1544

    
1545
--
1546
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1547
--
1548

    
1549
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1550
idempotent
1551
';
1552

    
1553

    
1554
--
1555
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1556
--
1557

    
1558
CREATE FUNCTION grants_users() RETURNS SETOF text
1559
    LANGUAGE sql IMMUTABLE
1560
    AS $$
1561
VALUES ('bien_read'), ('public_')
1562
$$;
1563

    
1564

    
1565
--
1566
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1567
--
1568

    
1569
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1570
    LANGUAGE sql IMMUTABLE
1571
    AS $_$
1572
SELECT substring($2 for length($1)) = $1
1573
$_$;
1574

    
1575

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

    
1580
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1581
    LANGUAGE sql STABLE
1582
    AS $_$
1583
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1584
$_$;
1585

    
1586

    
1587
--
1588
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1589
--
1590

    
1591
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1592
    LANGUAGE sql IMMUTABLE
1593
    AS $_$
1594
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1595
$_$;
1596

    
1597

    
1598
--
1599
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1600
--
1601

    
1602
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1603
avoids repeating the same value for each key
1604
';
1605

    
1606

    
1607
--
1608
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1609
--
1610

    
1611
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1612
    LANGUAGE sql IMMUTABLE
1613
    AS $_$
1614
SELECT COALESCE($1, $2)
1615
$_$;
1616

    
1617

    
1618
--
1619
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1620
--
1621

    
1622
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1623
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1624
';
1625

    
1626

    
1627
--
1628
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1629
--
1630

    
1631
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1632
    LANGUAGE sql
1633
    AS $_$
1634
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1635
$_$;
1636

    
1637

    
1638
--
1639
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1640
--
1641

    
1642
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1643
    LANGUAGE sql STABLE STRICT
1644
    AS $_$
1645
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1646
$_$;
1647

    
1648

    
1649
--
1650
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1651
--
1652

    
1653
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1654
    LANGUAGE sql IMMUTABLE
1655
    AS $_$
1656
SELECT util.array_length($1) = 0
1657
$_$;
1658

    
1659

    
1660
--
1661
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1662
--
1663

    
1664
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1665
    LANGUAGE sql IMMUTABLE
1666
    AS $_$
1667
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1668
$_$;
1669

    
1670

    
1671
--
1672
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1673
--
1674

    
1675
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1676
    LANGUAGE sql IMMUTABLE
1677
    AS $_$
1678
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1679
$_$;
1680

    
1681

    
1682
--
1683
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1684
--
1685

    
1686
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1687
    LANGUAGE sql STABLE
1688
    AS $_$
1689
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1690
$_$;
1691

    
1692

    
1693
--
1694
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1695
--
1696

    
1697
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1698
    LANGUAGE sql STABLE
1699
    AS $_$
1700
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1701
$_$;
1702

    
1703

    
1704
--
1705
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1706
--
1707

    
1708
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1709
    LANGUAGE sql IMMUTABLE STRICT
1710
    AS $_$
1711
SELECT $1 || $3 || $2
1712
$_$;
1713

    
1714

    
1715
--
1716
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1717
--
1718

    
1719
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1720
    LANGUAGE sql IMMUTABLE
1721
    AS $_$
1722
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1723
$_$;
1724

    
1725

    
1726
--
1727
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1728
--
1729

    
1730
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1731
    LANGUAGE sql IMMUTABLE
1732
    AS $_$
1733
SELECT ltrim($1, $$
1734
$$)
1735
$_$;
1736

    
1737

    
1738
--
1739
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1740
--
1741

    
1742
CREATE FUNCTION map_filter_insert() RETURNS trigger
1743
    LANGUAGE plpgsql
1744
    AS $$
1745
BEGIN
1746
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1747
	RETURN new;
1748
END;
1749
$$;
1750

    
1751

    
1752
--
1753
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1754
--
1755

    
1756
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1757
    LANGUAGE plpgsql STABLE STRICT
1758
    AS $_$
1759
DECLARE
1760
    value text;
1761
BEGIN
1762
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1763
        INTO value USING key;
1764
    RETURN value;
1765
END;
1766
$_$;
1767

    
1768

    
1769
--
1770
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1771
--
1772

    
1773
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1774
    LANGUAGE sql IMMUTABLE
1775
    AS $_$
1776
SELECT util._map(util.nulls_map($1), $2)
1777
$_$;
1778

    
1779

    
1780
--
1781
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1782
--
1783

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

    
1787
[1] inlining of function calls, which is different from constant folding
1788
[2] _map()''s profiling query
1789
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1790
and map_nulls()''s profiling query
1791
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1792
both take ~920 ms.
1793
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.
1794
';
1795

    
1796

    
1797
--
1798
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1799
--
1800

    
1801
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1802
    LANGUAGE plpgsql STABLE STRICT
1803
    AS $_$
1804
BEGIN
1805
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1806
END;
1807
$_$;
1808

    
1809

    
1810
--
1811
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1812
--
1813

    
1814
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1815
    LANGUAGE sql
1816
    AS $_$
1817
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1818
$$||util.ltrim_nl($2));
1819
-- make sure the created table has the correct estimated row count
1820
SELECT util.analyze_($1);
1821
$_$;
1822

    
1823

    
1824
--
1825
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1826
--
1827

    
1828
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1829
idempotent
1830
';
1831

    
1832

    
1833
--
1834
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1835
--
1836

    
1837
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1838
    LANGUAGE sql
1839
    AS $_$
1840
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1841
$_$;
1842

    
1843

    
1844
--
1845
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1846
--
1847

    
1848
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1849
idempotent
1850
';
1851

    
1852

    
1853
--
1854
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1858
    LANGUAGE sql STRICT
1859
    AS $_$
1860
SELECT util.create_if_not_exists($$
1861
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1862
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1863
||quote_literal($2)||$$;
1864
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1865
constant
1866
';
1867
$$)
1868
$_$;
1869

    
1870

    
1871
--
1872
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1873
--
1874

    
1875
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1876
idempotent
1877
';
1878

    
1879

    
1880
--
1881
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1882
--
1883

    
1884
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1885
    LANGUAGE plpgsql STRICT
1886
    AS $_$
1887
DECLARE
1888
    type regtype = util.typeof(expr, col.table_::text::regtype);
1889
    col_name_sql text = quote_ident(col.name);
1890
BEGIN
1891
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1892
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1893
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1894
$$||expr||$$;
1895
$$);
1896
END;
1897
$_$;
1898

    
1899

    
1900
--
1901
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1902
--
1903

    
1904
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1905
idempotent
1906
';
1907

    
1908

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

    
1913
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1914
    LANGUAGE sql STRICT
1915
    AS $_$
1916
SELECT util.create_if_not_exists($$
1917
CREATE TABLE $$||$1||$$
1918
(
1919
    LIKE util.map INCLUDING ALL
1920
);
1921

    
1922
CREATE TRIGGER map_filter_insert
1923
  BEFORE INSERT
1924
  ON $$||$1||$$
1925
  FOR EACH ROW
1926
  EXECUTE PROCEDURE util.map_filter_insert();
1927
$$)
1928
$_$;
1929

    
1930

    
1931
--
1932
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1933
--
1934

    
1935
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1936
    LANGUAGE sql IMMUTABLE
1937
    AS $_$
1938
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1939
$_$;
1940

    
1941

    
1942
--
1943
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1944
--
1945

    
1946
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1947
    LANGUAGE sql IMMUTABLE
1948
    AS $_$
1949
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1950
$_$;
1951

    
1952

    
1953
--
1954
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1955
--
1956

    
1957
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1958
usage:
1959
for *1* schema arg:
1960
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1961
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1962
';
1963

    
1964

    
1965
--
1966
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1967
--
1968

    
1969
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1970
    LANGUAGE sql IMMUTABLE
1971
    AS $_$
1972
SELECT $$SET LOCAL search_path TO $$||$1
1973
$_$;
1974

    
1975

    
1976
--
1977
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1978
--
1979

    
1980
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1981
    LANGUAGE sql STRICT
1982
    AS $_$
1983
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1984
$_$;
1985

    
1986

    
1987
--
1988
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1989
--
1990

    
1991
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1992
idempotent
1993
';
1994

    
1995

    
1996
--
1997
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1998
--
1999

    
2000
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2001
    LANGUAGE plpgsql STRICT
2002
    AS $_$
2003
DECLARE
2004
	view_qual_name text = util.qual_name(view_);
2005
BEGIN
2006
	EXECUTE $$
2007
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2008
  RETURNS SETOF $$||view_||$$ AS
2009
$BODY1$
2010
SELECT * FROM $$||view_qual_name||$$
2011
ORDER BY sort_col
2012
LIMIT $1 OFFSET $2
2013
$BODY1$
2014
  LANGUAGE sql STABLE
2015
  COST 100
2016
  ROWS 1000
2017
$$;
2018
	
2019
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2020
END;
2021
$_$;
2022

    
2023

    
2024
--
2025
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2026
--
2027

    
2028
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2029
    LANGUAGE plpgsql STRICT
2030
    AS $_$
2031
DECLARE
2032
	view_qual_name text = util.qual_name(view_);
2033
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2034
BEGIN
2035
	EXECUTE $$
2036
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2037
  RETURNS integer AS
2038
$BODY1$
2039
SELECT $$||quote_ident(row_num_col)||$$
2040
FROM $$||view_qual_name||$$
2041
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2042
LIMIT 1
2043
$BODY1$
2044
  LANGUAGE sql STABLE
2045
  COST 100;
2046
$$;
2047
	
2048
	EXECUTE $$
2049
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2050
  RETURNS SETOF $$||view_||$$ AS
2051
$BODY1$
2052
SELECT * FROM $$||view_qual_name||$$
2053
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2054
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2055
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2056
ORDER BY $$||quote_ident(row_num_col)||$$
2057
$BODY1$
2058
  LANGUAGE sql STABLE
2059
  COST 100
2060
  ROWS 1000
2061
$$;
2062
	
2063
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2064
END;
2065
$_$;
2066

    
2067

    
2068
--
2069
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2070
--
2071

    
2072
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2073
    LANGUAGE plpgsql STRICT
2074
    AS $_$
2075
DECLARE
2076
	view_qual_name text = util.qual_name(view_);
2077
BEGIN
2078
	EXECUTE $$
2079
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2080
  RETURNS SETOF $$||view_||$$
2081
  SET enable_sort TO 'off'
2082
  AS
2083
$BODY1$
2084
SELECT * FROM $$||view_qual_name||$$($2, $3)
2085
$BODY1$
2086
  LANGUAGE sql STABLE
2087
  COST 100
2088
  ROWS 1000
2089
;
2090
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2091
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2092
If you want to run EXPLAIN and get expanded output, use the regular subset
2093
function instead. (When a config param is set on a function, EXPLAIN produces
2094
just a function scan.)
2095
';
2096
$$;
2097
END;
2098
$_$;
2099

    
2100

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

    
2105
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2106
creates subset function which turns off enable_sort
2107
';
2108

    
2109

    
2110
--
2111
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2112
--
2113

    
2114
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2115
    LANGUAGE sql IMMUTABLE
2116
    AS $_$
2117
SELECT util.mk_set_search_path(util.schema_esc($1))
2118
$_$;
2119

    
2120

    
2121
--
2122
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2123
--
2124

    
2125
CREATE FUNCTION name(table_ regclass) RETURNS text
2126
    LANGUAGE sql STABLE
2127
    AS $_$
2128
SELECT relname::text FROM pg_class WHERE oid = $1
2129
$_$;
2130

    
2131

    
2132
--
2133
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2134
--
2135

    
2136
CREATE FUNCTION name(type regtype) RETURNS text
2137
    LANGUAGE sql STABLE STRICT
2138
    AS $_$
2139
SELECT typname::text FROM pg_type WHERE oid = $1
2140
$_$;
2141

    
2142

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

    
2147
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2148
    LANGUAGE sql IMMUTABLE
2149
    AS $_$
2150
SELECT octet_length($1) >= util.namedatalen() - $2
2151
$_$;
2152

    
2153

    
2154
--
2155
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2156
--
2157

    
2158
CREATE FUNCTION namedatalen() RETURNS integer
2159
    LANGUAGE sql IMMUTABLE
2160
    AS $$
2161
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2162
$$;
2163

    
2164

    
2165
--
2166
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2167
--
2168

    
2169
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2170
    LANGUAGE sql IMMUTABLE
2171
    AS $_$
2172
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2173
$_$;
2174

    
2175

    
2176
--
2177
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2178
--
2179

    
2180
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2181
    LANGUAGE sql IMMUTABLE
2182
    AS $_$
2183
SELECT $1 IS NOT NULL
2184
$_$;
2185

    
2186

    
2187
--
2188
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2189
--
2190

    
2191
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2192
    LANGUAGE sql IMMUTABLE
2193
    AS $_$
2194
SELECT util.hstore($1, NULL) || '*=>*'
2195
$_$;
2196

    
2197

    
2198
--
2199
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2200
--
2201

    
2202
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2203
for use with _map()
2204
';
2205

    
2206

    
2207
--
2208
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2209
--
2210

    
2211
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2212
    LANGUAGE sql IMMUTABLE
2213
    AS $_$
2214
SELECT $2 + COALESCE($1, 0)
2215
$_$;
2216

    
2217

    
2218
--
2219
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2220
--
2221

    
2222
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2223
    LANGUAGE sql IMMUTABLE
2224
    AS $_$
2225
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2226
$_$;
2227

    
2228

    
2229
--
2230
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2231
--
2232

    
2233
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2234
    LANGUAGE sql STABLE STRICT
2235
    SET search_path TO pg_temp
2236
    AS $_$
2237
SELECT $1::text
2238
$_$;
2239

    
2240

    
2241
--
2242
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2243
--
2244

    
2245
CREATE FUNCTION qual_name(type regtype) RETURNS text
2246
    LANGUAGE sql STABLE STRICT
2247
    SET search_path TO pg_temp
2248
    AS $_$
2249
SELECT $1::text
2250
$_$;
2251

    
2252

    
2253
--
2254
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2255
--
2256

    
2257
COMMENT ON FUNCTION qual_name(type regtype) IS '
2258
a type''s schema-qualified name
2259
';
2260

    
2261

    
2262
--
2263
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2264
--
2265

    
2266
CREATE FUNCTION qual_name(type unknown) RETURNS text
2267
    LANGUAGE sql STABLE STRICT
2268
    AS $_$
2269
SELECT util.qual_name($1::text::regtype)
2270
$_$;
2271

    
2272

    
2273
--
2274
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2278
    LANGUAGE sql IMMUTABLE
2279
    AS $_$
2280
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2281
$_$;
2282

    
2283

    
2284
--
2285
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2286
--
2287

    
2288
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2289
    LANGUAGE sql IMMUTABLE
2290
    AS $_$
2291
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2292
$_$;
2293

    
2294

    
2295
--
2296
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2297
--
2298

    
2299
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2300
    LANGUAGE sql IMMUTABLE
2301
    AS $_$
2302
SELECT quote_nullable($1)||$$::$$||pg_typeof($1)
2303
$_$;
2304

    
2305

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

    
2310
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2311
    LANGUAGE sql IMMUTABLE STRICT
2312
    AS $_$
2313
SELECT util.raise_notice('ERROR:  '||$1)
2314
$_$;
2315

    
2316

    
2317
--
2318
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2319
--
2320

    
2321
CREATE FUNCTION raise_notice(msg text) RETURNS void
2322
    LANGUAGE plpgsql IMMUTABLE STRICT
2323
    AS $$
2324
BEGIN
2325
	RAISE NOTICE '%', msg;
2326
END;
2327
$$;
2328

    
2329

    
2330
--
2331
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2332
--
2333

    
2334
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2335
    LANGUAGE plpgsql IMMUTABLE STRICT
2336
    AS $$
2337
BEGIN
2338
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2339
END;
2340
$$;
2341

    
2342

    
2343
--
2344
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2345
--
2346

    
2347
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2348
    LANGUAGE sql IMMUTABLE
2349
    AS $_$
2350
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2351
$_$;
2352

    
2353

    
2354
--
2355
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2356
--
2357

    
2358
CREATE FUNCTION regexp_quote(str text) RETURNS text
2359
    LANGUAGE sql IMMUTABLE
2360
    AS $_$
2361
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2362
$_$;
2363

    
2364

    
2365
--
2366
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2367
--
2368

    
2369
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2370
    LANGUAGE sql IMMUTABLE
2371
    AS $_$
2372
SELECT (CASE WHEN right($1, 1) = ')'
2373
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2374
$_$;
2375

    
2376

    
2377
--
2378
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2379
--
2380

    
2381
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2382
    LANGUAGE sql STABLE
2383
    AS $_$
2384
SELECT util.relation_type(util.relation_type_char($1))
2385
$_$;
2386

    
2387

    
2388
--
2389
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2390
--
2391

    
2392
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2393
    LANGUAGE sql IMMUTABLE
2394
    AS $_$
2395
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2396
$_$;
2397

    
2398

    
2399
--
2400
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2401
--
2402

    
2403
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2404
    LANGUAGE sql STABLE
2405
    AS $_$
2406
SELECT relkind FROM pg_class WHERE oid = $1
2407
$_$;
2408

    
2409

    
2410
--
2411
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2412
--
2413

    
2414
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2415
    LANGUAGE sql
2416
    AS $_$
2417
/* can't have in_table/out_table inherit from *each other*, because inheritance
2418
also causes the rows of the parent table to be included in the child table.
2419
instead, they need to inherit from a common, empty table. */
2420
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2421
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2422
SELECT util.inherit($2, $4);
2423
SELECT util.inherit($3, $4);
2424

    
2425
SELECT util.rematerialize_query($1, $$
2426
SELECT * FROM util.diff(
2427
  $$||util.quote_typed($2)||$$
2428
, $$||util.quote_typed($3)||$$
2429
, NULL::$$||$4||$$)
2430
$$);
2431

    
2432
/* the table unfortunately cannot be *materialized* in human-readable form,
2433
because this would create column name collisions between the two sides */
2434
SELECT util.append_comment($1, '
2435
to view this table in human-readable form (with each side''s tuple column
2436
expanded to its component fields):
2437
SELECT (left_).*, (right_).* FROM '||$1||';
2438
');
2439
$_$;
2440

    
2441

    
2442
--
2443
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2444
--
2445

    
2446
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2447
type_table (*required*): table to create as the shared base type
2448
';
2449

    
2450

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

    
2455
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2456
    LANGUAGE sql
2457
    AS $_$
2458
SELECT util.drop_table($1);
2459
SELECT util.materialize_query($1, $2);
2460
$_$;
2461

    
2462

    
2463
--
2464
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2465
--
2466

    
2467
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2468
idempotent, but repeats action each time
2469
';
2470

    
2471

    
2472
--
2473
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2474
--
2475

    
2476
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2477
    LANGUAGE sql
2478
    AS $_$
2479
SELECT util.drop_table($1);
2480
SELECT util.materialize_view($1, $2);
2481
$_$;
2482

    
2483

    
2484
--
2485
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2486
--
2487

    
2488
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2489
idempotent, but repeats action each time
2490
';
2491

    
2492

    
2493
--
2494
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2495
--
2496

    
2497
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2498
    LANGUAGE sql STRICT
2499
    AS $_$
2500
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2501
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2502
FROM util.col_names($1::text::regtype) f (name);
2503
SELECT NULL::void; -- don't fold away functions called in previous query
2504
$_$;
2505

    
2506

    
2507
--
2508
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2509
--
2510

    
2511
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2512
idempotent
2513
';
2514

    
2515

    
2516
--
2517
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2518
--
2519

    
2520
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2521
    LANGUAGE sql
2522
    AS $_$
2523
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2524
included in the debug SQL */
2525
SELECT util.rename_relation(util.qual_name($1), $2)
2526
$_$;
2527

    
2528

    
2529
--
2530
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2531
--
2532

    
2533
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2534
    LANGUAGE sql
2535
    AS $_$
2536
/* 'ALTER TABLE can be used with views too'
2537
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2538
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2539
||quote_ident($2))
2540
$_$;
2541

    
2542

    
2543
--
2544
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2545
--
2546

    
2547
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2548
idempotent
2549
';
2550

    
2551

    
2552
--
2553
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2554
--
2555

    
2556
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2557
    LANGUAGE sql IMMUTABLE
2558
    AS $_$
2559
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2560
$_$;
2561

    
2562

    
2563
--
2564
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2565
--
2566

    
2567
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2568
max_prefix_len: when str may have been truncated (eg. as a table name) due to the prepending of a prefix, support prefixes up to this length 
2569
';
2570

    
2571

    
2572
--
2573
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2574
--
2575

    
2576
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2577
    LANGUAGE sql STRICT
2578
    AS $_$
2579
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2580
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2581
SELECT util.set_col_names($1, $2);
2582
$_$;
2583

    
2584

    
2585
--
2586
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2587
--
2588

    
2589
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2590
idempotent.
2591
alters the names table, so it will need to be repopulated after running this function.
2592
';
2593

    
2594

    
2595
--
2596
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2597
--
2598

    
2599
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2600
    LANGUAGE sql STRICT
2601
    AS $_$
2602
SELECT util.drop_table($1);
2603
SELECT util.mk_map_table($1);
2604
$_$;
2605

    
2606

    
2607
--
2608
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2609
--
2610

    
2611
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2612
    LANGUAGE sql IMMUTABLE
2613
    AS $_$
2614
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2615
$_$;
2616

    
2617

    
2618
--
2619
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2620
--
2621

    
2622
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2623
    LANGUAGE plpgsql STRICT
2624
    AS $_$
2625
DECLARE
2626
	result text = NULL;
2627
BEGIN
2628
	BEGIN
2629
		result = util.show_create_view(view_);
2630
		PERFORM util.eval($$DROP VIEW $$||view_);
2631
	EXCEPTION
2632
		WHEN undefined_table THEN NULL;
2633
	END;
2634
	RETURN result;
2635
END;
2636
$_$;
2637

    
2638

    
2639
--
2640
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2641
--
2642

    
2643
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2644
    LANGUAGE sql
2645
    AS $_$
2646
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2647
$_$;
2648

    
2649

    
2650
--
2651
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2652
--
2653

    
2654
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2655
    LANGUAGE sql STABLE
2656
    AS $_$
2657
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2658
$_$;
2659

    
2660

    
2661
--
2662
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2663
--
2664

    
2665
CREATE FUNCTION schema(table_ regclass) RETURNS text
2666
    LANGUAGE sql STABLE
2667
    AS $_$
2668
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2669
$_$;
2670

    
2671

    
2672
--
2673
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2674
--
2675

    
2676
CREATE FUNCTION schema(type regtype) RETURNS text
2677
    LANGUAGE sql STABLE
2678
    AS $_$
2679
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2680
$_$;
2681

    
2682

    
2683
--
2684
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2685
--
2686

    
2687
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2688
    LANGUAGE sql STABLE
2689
    AS $_$
2690
SELECT util.schema(pg_typeof($1))
2691
$_$;
2692

    
2693

    
2694
--
2695
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2696
--
2697

    
2698
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2699
    LANGUAGE sql STABLE
2700
    AS $_$
2701
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2702
$_$;
2703

    
2704

    
2705
--
2706
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2707
--
2708

    
2709
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2710
a schema bundle is a group of schemas with a common prefix
2711
';
2712

    
2713

    
2714
--
2715
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2716
--
2717

    
2718
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2719
    LANGUAGE sql
2720
    AS $_$
2721
SELECT util.schema_rename(old_schema,
2722
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2723
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2724
SELECT NULL::void; -- don't fold away functions called in previous query
2725
$_$;
2726

    
2727

    
2728
--
2729
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2730
--
2731

    
2732
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2733
    LANGUAGE plpgsql
2734
    AS $$
2735
BEGIN
2736
	-- don't schema_bundle_rm() the schema_bundle to keep!
2737
	IF replace = with_ THEN RETURN; END IF;
2738
	
2739
	PERFORM util.schema_bundle_rm(replace);
2740
	PERFORM util.schema_bundle_rename(with_, replace);
2741
END;
2742
$$;
2743

    
2744

    
2745
--
2746
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2747
--
2748

    
2749
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2750
    LANGUAGE sql
2751
    AS $_$
2752
SELECT util.schema_rm(schema)
2753
FROM util.schema_bundle_get_schemas($1) f (schema);
2754
SELECT NULL::void; -- don't fold away functions called in previous query
2755
$_$;
2756

    
2757

    
2758
--
2759
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2760
--
2761

    
2762
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2763
    LANGUAGE sql STABLE
2764
    AS $_$
2765
SELECT quote_ident(util.schema($1))
2766
$_$;
2767

    
2768

    
2769
--
2770
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2774
    LANGUAGE sql IMMUTABLE
2775
    AS $_$
2776
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2777
$_$;
2778

    
2779

    
2780
--
2781
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2782
--
2783

    
2784
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2785
    LANGUAGE sql STABLE
2786
    AS $_$
2787
SELECT oid FROM pg_namespace WHERE nspname = $1
2788
$_$;
2789

    
2790

    
2791
--
2792
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2793
--
2794

    
2795
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2796
    LANGUAGE sql
2797
    AS $_$
2798
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2799
$_$;
2800

    
2801

    
2802
--
2803
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2804
--
2805

    
2806
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2807
    LANGUAGE plpgsql
2808
    AS $$
2809
BEGIN
2810
	-- don't schema_rm() the schema to keep!
2811
	IF replace = with_ THEN RETURN; END IF;
2812
	
2813
	PERFORM util.schema_rm(replace);
2814
	PERFORM util.schema_rename(with_, replace);
2815
END;
2816
$$;
2817

    
2818

    
2819
--
2820
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2821
--
2822

    
2823
CREATE FUNCTION schema_rm(schema text) RETURNS void
2824
    LANGUAGE sql
2825
    AS $_$
2826
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2827
$_$;
2828

    
2829

    
2830
--
2831
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2832
--
2833

    
2834
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2835
    LANGUAGE sql STRICT
2836
    AS $_$
2837
SELECT util.eval(
2838
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2839
$_$;
2840

    
2841

    
2842
--
2843
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2844
--
2845

    
2846
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2847
    LANGUAGE plpgsql STRICT
2848
    AS $_$
2849
DECLARE
2850
    old text[] = ARRAY(SELECT util.col_names(table_));
2851
    new text[] = ARRAY(SELECT util.map_values(names));
2852
BEGIN
2853
    old = old[1:array_length(new, 1)]; -- truncate to same length
2854
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2855
||$$ TO $$||quote_ident(value))
2856
    FROM each(hstore(old, new))
2857
    WHERE value != key -- not same name
2858
    ;
2859
END;
2860
$_$;
2861

    
2862

    
2863
--
2864
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2865
--
2866

    
2867
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2868
idempotent
2869
';
2870

    
2871

    
2872
--
2873
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2874
--
2875

    
2876
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2877
    LANGUAGE plpgsql STRICT
2878
    AS $_$
2879
DECLARE
2880
	row_ util.map;
2881
BEGIN
2882
	-- rename any metadata cols rather than re-adding them with new names
2883
	BEGIN
2884
		PERFORM util.set_col_names(table_, names);
2885
	EXCEPTION
2886
		WHEN array_subscript_error THEN -- selective suppress
2887
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2888
				-- metadata cols not yet added
2889
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2890
			END IF;
2891
	END;
2892
	
2893
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2894
	LOOP
2895
		PERFORM util.mk_const_col((table_, row_."to"),
2896
			substring(row_."from" from 2));
2897
	END LOOP;
2898
	
2899
	PERFORM util.set_col_names(table_, names);
2900
END;
2901
$_$;
2902

    
2903

    
2904
--
2905
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2906
--
2907

    
2908
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2909
idempotent.
2910
the metadata mappings must be *last* in the names table.
2911
';
2912

    
2913

    
2914
--
2915
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2916
--
2917

    
2918
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2919
    LANGUAGE plpgsql STRICT
2920
    AS $_$
2921
DECLARE
2922
    sql text = $$ALTER TABLE $$||table_||$$
2923
$$||NULLIF(array_to_string(ARRAY(
2924
    SELECT
2925
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2926
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2927
    FROM
2928
    (
2929
        SELECT
2930
          quote_ident(col_name) AS col_name_sql
2931
        , util.col_type((table_, col_name)) AS curr_type
2932
        , type AS target_type
2933
        FROM unnest(col_casts)
2934
    ) s
2935
    WHERE curr_type != target_type
2936
), '
2937
, '), '');
2938
BEGIN
2939
    PERFORM util.debug_print_sql(sql);
2940
    EXECUTE COALESCE(sql, '');
2941
END;
2942
$_$;
2943

    
2944

    
2945
--
2946
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2947
--
2948

    
2949
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2950
idempotent
2951
';
2952

    
2953

    
2954
--
2955
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2956
--
2957

    
2958
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2959
    LANGUAGE sql STRICT
2960
    AS $_$
2961
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2962
$_$;
2963

    
2964

    
2965
--
2966
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2967
--
2968

    
2969
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2970
    LANGUAGE sql STABLE
2971
    AS $_$
2972
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2973
$$||util.show_grants_for($1)
2974
$_$;
2975

    
2976

    
2977
--
2978
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2979
--
2980

    
2981
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2982
    LANGUAGE sql STABLE
2983
    AS $_$
2984
SELECT string_agg(cmd, '')
2985
FROM
2986
(
2987
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2988
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2989
$$ ELSE '' END) AS cmd
2990
	FROM util.grants_users() f (user_)
2991
) s
2992
$_$;
2993

    
2994

    
2995
--
2996
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2997
--
2998

    
2999
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3000
    LANGUAGE sql STABLE
3001
    AS $_$
3002
SELECT oid FROM pg_class
3003
WHERE relkind = ANY($3) AND relname ~ $1
3004
AND util.schema_matches(util.schema(relnamespace), $2)
3005
ORDER BY relname
3006
$_$;
3007

    
3008

    
3009
--
3010
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3011
--
3012

    
3013
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3014
    LANGUAGE sql STABLE
3015
    AS $_$
3016
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3017
$_$;
3018

    
3019

    
3020
--
3021
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3022
--
3023

    
3024
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3025
    LANGUAGE sql IMMUTABLE
3026
    AS $_$
3027
SELECT '^'||util.regexp_quote($1)||'$'
3028
$_$;
3029

    
3030

    
3031
--
3032
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3033
--
3034

    
3035
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3036
    LANGUAGE plpgsql STABLE STRICT
3037
    AS $_$
3038
DECLARE
3039
    hstore hstore;
3040
BEGIN
3041
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3042
        table_||$$))$$ INTO STRICT hstore;
3043
    RETURN hstore;
3044
END;
3045
$_$;
3046

    
3047

    
3048
--
3049
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3050
--
3051

    
3052
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3053
    LANGUAGE sql STABLE STRICT
3054
    AS $_$
3055
SELECT COUNT(*) > 0 FROM pg_constraint
3056
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3057
$_$;
3058

    
3059

    
3060
--
3061
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3062
--
3063

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

    
3068

    
3069
--
3070
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3071
--
3072

    
3073
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3074
    LANGUAGE sql STRICT
3075
    AS $_$
3076
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3077
||quote_ident($2)||$$ CHECK (true)$$)
3078
$_$;
3079

    
3080

    
3081
--
3082
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3083
--
3084

    
3085
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3086
stores a status flag by the presence of a table constraint.
3087
idempotent.
3088
';
3089

    
3090

    
3091
--
3092
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3093
--
3094

    
3095
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3096
    LANGUAGE sql STABLE STRICT
3097
    AS $_$
3098
SELECT util.table_flag__get($1, 'nulls_mapped')
3099
$_$;
3100

    
3101

    
3102
--
3103
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3104
--
3105

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

    
3110

    
3111
--
3112
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3113
--
3114

    
3115
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3116
    LANGUAGE sql STRICT
3117
    AS $_$
3118
SELECT util.table_flag__set($1, 'nulls_mapped')
3119
$_$;
3120

    
3121

    
3122
--
3123
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3124
--
3125

    
3126
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3127
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3128
idempotent.
3129
';
3130

    
3131

    
3132
--
3133
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3134
--
3135

    
3136
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3137
    LANGUAGE plpgsql STRICT
3138
    AS $_$
3139
DECLARE
3140
    row record;
3141
BEGIN
3142
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3143
    LOOP
3144
        IF row.global_name != row.name THEN
3145
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3146
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3147
        END IF;
3148
    END LOOP;
3149
END;
3150
$_$;
3151

    
3152

    
3153
--
3154
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3155
--
3156

    
3157
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3158
idempotent
3159
';
3160

    
3161

    
3162
--
3163
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3164
--
3165

    
3166
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3167
    LANGUAGE sql STRICT
3168
    AS $_$
3169
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3170
SELECT NULL::void; -- don't fold away functions called in previous query
3171
$_$;
3172

    
3173

    
3174
--
3175
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3176
--
3177

    
3178
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3179
trims table_ to include only columns in the original data.
3180
idempotent.
3181
';
3182

    
3183

    
3184
--
3185
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3186
--
3187

    
3188
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3189
    LANGUAGE plpgsql STRICT
3190
    AS $_$
3191
BEGIN
3192
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3193
END;
3194
$_$;
3195

    
3196

    
3197
--
3198
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3199
--
3200

    
3201
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3202
idempotent
3203
';
3204

    
3205

    
3206
--
3207
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3208
--
3209

    
3210
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3211
    LANGUAGE sql IMMUTABLE
3212
    AS $_$
3213
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3214
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3215
$_$;
3216

    
3217

    
3218
--
3219
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3220
--
3221

    
3222
CREATE FUNCTION try_create(sql text) RETURNS void
3223
    LANGUAGE plpgsql STRICT
3224
    AS $$
3225
BEGIN
3226
    PERFORM util.eval(sql);
3227
EXCEPTION
3228
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3229
    WHEN undefined_column THEN NULL;
3230
    WHEN duplicate_column THEN NULL;
3231
END;
3232
$$;
3233

    
3234

    
3235
--
3236
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3237
--
3238

    
3239
COMMENT ON FUNCTION try_create(sql text) IS '
3240
idempotent
3241
';
3242

    
3243

    
3244
--
3245
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3246
--
3247

    
3248
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3249
    LANGUAGE sql STRICT
3250
    AS $_$
3251
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3252
$_$;
3253

    
3254

    
3255
--
3256
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3257
--
3258

    
3259
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3260
idempotent
3261
';
3262

    
3263

    
3264
--
3265
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3266
--
3267

    
3268
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3269
    LANGUAGE sql IMMUTABLE
3270
    AS $_$
3271
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3272
$_$;
3273

    
3274

    
3275
--
3276
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3277
--
3278

    
3279
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3280
a type''s NOT NULL qualifier
3281
';
3282

    
3283

    
3284
--
3285
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3286
--
3287

    
3288
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3289
    LANGUAGE plpgsql STABLE
3290
    AS $_$
3291
DECLARE
3292
    type regtype;
3293
BEGIN
3294
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3295
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3296
    RETURN type;
3297
END;
3298
$_$;
3299

    
3300

    
3301
--
3302
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3303
--
3304

    
3305
CREATE AGGREGATE all_same(anyelement) (
3306
    SFUNC = all_same_transform,
3307
    STYPE = anyarray,
3308
    FINALFUNC = all_same_final
3309
);
3310

    
3311

    
3312
--
3313
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3314
--
3315

    
3316
COMMENT ON AGGREGATE all_same(anyelement) IS '
3317
includes NULLs in comparison
3318
';
3319

    
3320

    
3321
--
3322
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3323
--
3324

    
3325
CREATE AGGREGATE join_strs(text, text) (
3326
    SFUNC = join_strs_transform,
3327
    STYPE = text
3328
);
3329

    
3330

    
3331
--
3332
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3333
--
3334

    
3335
CREATE OPERATOR -> (
3336
    PROCEDURE = map_get,
3337
    LEFTARG = regclass,
3338
    RIGHTARG = text
3339
);
3340

    
3341

    
3342
--
3343
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3344
--
3345

    
3346
CREATE OPERATOR => (
3347
    PROCEDURE = hstore,
3348
    LEFTARG = text[],
3349
    RIGHTARG = text
3350
);
3351

    
3352

    
3353
--
3354
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3355
--
3356

    
3357
COMMENT ON OPERATOR => (text[], text) IS '
3358
usage: array[''key1'', ...]::text[] => ''value''
3359
';
3360

    
3361

    
3362
--
3363
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3364
--
3365

    
3366
CREATE OPERATOR ?*>= (
3367
    PROCEDURE = is_populated_more_often_than,
3368
    LEFTARG = anyelement,
3369
    RIGHTARG = anyelement
3370
);
3371

    
3372

    
3373
--
3374
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3375
--
3376

    
3377
CREATE OPERATOR ?>= (
3378
    PROCEDURE = is_more_complete_than,
3379
    LEFTARG = anyelement,
3380
    RIGHTARG = anyelement
3381
);
3382

    
3383

    
3384
--
3385
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3386
--
3387

    
3388
CREATE OPERATOR ||% (
3389
    PROCEDURE = concat_esc,
3390
    LEFTARG = text,
3391
    RIGHTARG = text
3392
);
3393

    
3394

    
3395
--
3396
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3397
--
3398

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

    
3403

    
3404
--
3405
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3406
--
3407

    
3408
CREATE TABLE map (
3409
    "from" text NOT NULL,
3410
    "to" text,
3411
    filter text,
3412
    notes text
3413
);
3414

    
3415

    
3416
--
3417
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3418
--
3419

    
3420

    
3421

    
3422
--
3423
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3424
--
3425

    
3426

    
3427

    
3428
--
3429
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3430
--
3431

    
3432
ALTER TABLE ONLY map
3433
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3434

    
3435

    
3436
--
3437
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3438
--
3439

    
3440
ALTER TABLE ONLY map
3441
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3442

    
3443

    
3444
--
3445
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3446
--
3447

    
3448
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3449

    
3450

    
3451
--
3452
-- PostgreSQL database dump complete
3453
--
3454

    
(19-19/29)