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: 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. avoiding use of STRICT also makes functions *much* easier to troubleshoot, because they won''t mysteriously do nothing if called with only NULL arguments, even when you have added debug-print statements.
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: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

    
78
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
79
    LANGUAGE sql STABLE
80
    AS $_$
81
SELECT keys($1) = keys($2)
82
$_$;
83

    
84

    
85
--
86
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
87
--
88

    
89
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
90
needs to be declared STABLE instead of IMMUTABLE because it depends on the search_path (as described at http://vegpath.org/links/#PostgreSQL:%20Documentation:%209.3:%20Function%20Volatility%20Categories%20**)
91
';
92

    
93

    
94
--
95
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
96
--
97

    
98
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
99
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102
$_$;
103

    
104

    
105
--
106
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
107
--
108

    
109
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
110
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117
    , ($3)
118
    , ($4)
119
    , ($5)
120
)
121
AS v (value)
122
$_$;
123

    
124

    
125
--
126
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
127
--
128

    
129
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
130
_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.
131
';
132

    
133

    
134
--
135
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
136
--
137

    
138
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
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152

    
153

    
154
--
155
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
156
--
157

    
158
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
159
    LANGUAGE sql IMMUTABLE
160
    AS $_$
161
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)
162
FROM 
163
(
164
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
165
    UNION ALL
166
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
167
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
168
)
169
matches (g)
170
$_$;
171

    
172

    
173
--
174
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
175
--
176

    
177
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
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181
FROM
182
(VALUES
183
      ($1)
184
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189

    
190

    
191
--
192
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
193
--
194

    
195
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
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199
$_$;
200

    
201

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

    
206
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
207
    LANGUAGE sql IMMUTABLE
208
    AS $_$
209
SELECT $1 = $2
210
$_$;
211

    
212

    
213
--
214
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
215
--
216

    
217
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
218
    LANGUAGE sql IMMUTABLE
219
    AS $_$
220
-- Fix dates after threshold date
221
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
222
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
223
$_$;
224

    
225

    
226
--
227
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
228
--
229

    
230
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
231
    LANGUAGE sql IMMUTABLE
232
    AS $_$
233
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
234
$_$;
235

    
236

    
237
--
238
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
239
--
240

    
241
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
242
    LANGUAGE sql IMMUTABLE
243
    AS $_$
244
SELECT util._if($1 != '', $2, $3)
245
$_$;
246

    
247

    
248
--
249
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
250
--
251

    
252
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
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256
$_$;
257

    
258

    
259
--
260
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
261
--
262

    
263
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
264
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267
$_$;
268

    
269

    
270
--
271
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
272
--
273

    
274
CREATE FUNCTION _label(label text, value text) RETURNS text
275
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277
SELECT coalesce($1 || ': ', '') || $2
278
$_$;
279

    
280

    
281
--
282
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
283
--
284

    
285
CREATE FUNCTION _lowercase(value text) RETURNS text
286
    LANGUAGE sql IMMUTABLE
287
    AS $_$
288
SELECT lower($1)
289
$_$;
290

    
291

    
292
--
293
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
294
--
295

    
296
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
297
    LANGUAGE plpgsql IMMUTABLE STRICT
298
    AS $$
299
DECLARE
300
    result value%TYPE := util._map(map, value::text)::unknown;
301
BEGIN
302
    RETURN result;
303
END;
304
$$;
305

    
306

    
307
--
308
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
309
--
310

    
311
CREATE FUNCTION _map(map hstore, value text) RETURNS text
312
    LANGUAGE plpgsql IMMUTABLE STRICT
313
    AS $$
314
DECLARE
315
    match text := map -> value;
316
BEGIN
317
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
318
        match := map -> '*'; -- use default entry
319
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
320
        END IF;
321
    END IF;
322
    
323
    -- Interpret result
324
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
325
    ELSIF match = '*' THEN RETURN value;
326
    ELSE RETURN match;
327
    END IF;
328
END;
329
$$;
330

    
331

    
332
--
333
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
334
--
335

    
336
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
337
    LANGUAGE sql IMMUTABLE
338
    AS $_$
339
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
340
$_$;
341

    
342

    
343
--
344
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
345
--
346

    
347
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
348
    LANGUAGE sql IMMUTABLE
349
    AS $_$
350
SELECT util.join_strs(value, '; ')
351
FROM
352
(
353
    SELECT *
354
    FROM
355
    (
356
        SELECT
357
        DISTINCT ON (value)
358
        *
359
        FROM
360
        (VALUES
361
              (1, $1)
362
            , (2, $2)
363
            , (3, $3)
364
            , (4, $4)
365
            , (5, $5)
366
            , (6, $6)
367
            , (7, $7)
368
            , (8, $8)
369
            , (9, $9)
370
            , (10, $10)
371
        )
372
        AS v (sort_order, value)
373
        WHERE value IS NOT NULL
374
    )
375
    AS v
376
    ORDER BY sort_order
377
)
378
AS v
379
$_$;
380

    
381

    
382
--
383
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
384
--
385

    
386
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
387
    LANGUAGE sql IMMUTABLE
388
    AS $_$
389
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
390
$_$;
391

    
392

    
393
--
394
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
395
--
396

    
397
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
398
    LANGUAGE sql IMMUTABLE
399
    AS $_$
400
SELECT util.join_strs(value, ' ')
401
FROM
402
(
403
    SELECT *
404
    FROM
405
    (
406
        SELECT
407
        DISTINCT ON (value)
408
        *
409
        FROM
410
        (VALUES
411
              (1, $1)
412
            , (2, $2)
413
            , (3, $3)
414
            , (4, $4)
415
            , (5, $5)
416
            , (6, $6)
417
            , (7, $7)
418
            , (8, $8)
419
            , (9, $9)
420
            , (10, $10)
421
        )
422
        AS v (sort_order, value)
423
        WHERE value IS NOT NULL
424
    )
425
    AS v
426
    ORDER BY sort_order
427
)
428
AS v
429
$_$;
430

    
431

    
432
--
433
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
434
--
435

    
436
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
437
    LANGUAGE sql IMMUTABLE
438
    AS $_$
439
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
440
$_$;
441

    
442

    
443
--
444
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
445
--
446

    
447
CREATE FUNCTION _not(value boolean) RETURNS boolean
448
    LANGUAGE sql IMMUTABLE
449
    AS $_$
450
SELECT NOT $1
451
$_$;
452

    
453

    
454
--
455
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
456
--
457

    
458
CREATE FUNCTION _now() RETURNS timestamp with time zone
459
    LANGUAGE sql STABLE
460
    AS $$
461
SELECT now()
462
$$;
463

    
464

    
465
--
466
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
467
--
468

    
469
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
470
    LANGUAGE sql IMMUTABLE
471
    AS $_$
472
SELECT util."_nullIf"($1, $2, $3::util.datatype)
473
$_$;
474

    
475

    
476
--
477
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
478
--
479

    
480
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
481
    LANGUAGE plpgsql IMMUTABLE
482
    AS $$
483
DECLARE
484
    type util.datatype NOT NULL := type; -- add NOT NULL
485
BEGIN
486
    IF type = 'str' THEN RETURN nullif(value::text, "null");
487
    -- Invalid value is ignored, but invalid null value generates error
488
    ELSIF type = 'float' THEN
489
        DECLARE
490
            -- Outside the try block so that invalid null value generates error
491
            "null" double precision := "null"::double precision;
492
        BEGIN
493
            RETURN nullif(value::double precision, "null");
494
        EXCEPTION
495
            WHEN data_exception THEN RETURN value; -- ignore invalid value
496
        END;
497
    END IF;
498
END;
499
$$;
500

    
501

    
502
--
503
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
504
--
505

    
506
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
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT bool_or(value)
510
FROM
511
(VALUES
512
      ($1)
513
    , ($2)
514
    , ($3)
515
    , ($4)
516
    , ($5)
517
)
518
AS v (value)
519
$_$;
520

    
521

    
522
--
523
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
524
--
525

    
526
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
527
_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.
528
';
529

    
530

    
531
--
532
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
533
--
534

    
535
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
536
    LANGUAGE sql IMMUTABLE
537
    AS $_$
538
SELECT $2 - $1
539
$_$;
540

    
541

    
542
--
543
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
544
--
545

    
546
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
547
    LANGUAGE sql IMMUTABLE
548
    AS $_$
549
SELECT regexp_split_to_table($1, $2)
550
$_$;
551

    
552

    
553
--
554
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
555
--
556

    
557
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
558
    LANGUAGE sql STABLE
559
    AS $_$
560
SELECT util.derived_cols($1, $2)
561
UNION
562
SELECT util.eval2set($$
563
SELECT col
564
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
565
JOIN $$||$2||$$ ON "to" = col
566
WHERE "from" LIKE ':%'
567
$$, NULL::text)
568
$_$;
569

    
570

    
571
--
572
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
573
--
574

    
575
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
576
gets table_''s added columns (all the columns not in the original data)
577
';
578

    
579

    
580
--
581
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
582
--
583

    
584
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
585
    LANGUAGE sql IMMUTABLE
586
    AS $_$
587
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
588
$_$;
589

    
590

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

    
595
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
596
    LANGUAGE plpgsql IMMUTABLE
597
    AS $$
598
DECLARE
599
	value_cmp         state%TYPE = ARRAY[value];
600
	state             state%TYPE = COALESCE(state, value_cmp);
601
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
602
BEGIN
603
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
604
END;
605
$$;
606

    
607

    
608
--
609
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
610
--
611

    
612
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
613
    LANGUAGE sql
614
    AS $_$
615
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
616
$_$;
617

    
618

    
619
--
620
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
621
--
622

    
623
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
624
    LANGUAGE sql
625
    AS $_$
626
SELECT util.set_comment($1, concat(util.comment($1), $2))
627
$_$;
628

    
629

    
630
--
631
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
632
--
633

    
634
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
635
comment: must start and end with a newline
636
';
637

    
638

    
639
--
640
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
641
--
642

    
643
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
644
    LANGUAGE sql IMMUTABLE
645
    AS $_$
646
SELECT pg_catalog.array_fill($1, ARRAY[$2])
647
$_$;
648

    
649

    
650
--
651
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
652
--
653

    
654
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
655
    LANGUAGE sql IMMUTABLE
656
    AS $_$
657
SELECT util.array_length($1, 1)
658
$_$;
659

    
660

    
661
--
662
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
663
--
664

    
665
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
666
    LANGUAGE sql IMMUTABLE
667
    AS $_$
668
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
669
$_$;
670

    
671

    
672
--
673
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
674
--
675

    
676
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
677
returns 0 instead of NULL for empty arrays
678
';
679

    
680

    
681
--
682
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
683
--
684

    
685
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
686
    LANGUAGE sql STABLE
687
    AS $_$
688
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
689
$_$;
690

    
691

    
692
--
693
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
694
--
695

    
696
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
697
    LANGUAGE plpgsql STRICT
698
    AS $_$
699
BEGIN
700
    -- not yet clustered (ARRAY[] compares NULLs literally)
701
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
702
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
703
    END IF;
704
END;
705
$_$;
706

    
707

    
708
--
709
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
710
--
711

    
712
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
713
idempotent
714
';
715

    
716

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

    
721
CREATE FUNCTION col__min(col col_ref) RETURNS integer
722
    LANGUAGE sql STABLE
723
    AS $_$
724
SELECT util.eval2val($$
725
SELECT $$||quote_ident($1.name)||$$
726
FROM $$||$1.table_||$$
727
ORDER BY $$||quote_ident($1.name)||$$ ASC
728
LIMIT 1
729
$$, NULL::integer)
730
$_$;
731

    
732

    
733
--
734
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
735
--
736

    
737
CREATE FUNCTION col_comment(col col_ref) RETURNS text
738
    LANGUAGE plpgsql STABLE STRICT
739
    AS $$
740
DECLARE
741
	comment text;
742
BEGIN
743
	SELECT description
744
	FROM pg_attribute
745
	LEFT JOIN pg_description ON objoid = attrelid
746
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
747
	WHERE attrelid = col.table_ AND attname = col.name
748
	INTO STRICT comment
749
	;
750
	RETURN comment;
751
EXCEPTION
752
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
753
END;
754
$$;
755

    
756

    
757
--
758
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
759
--
760

    
761
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
762
    LANGUAGE plpgsql STABLE STRICT
763
    AS $$
764
DECLARE
765
	default_sql text;
766
BEGIN
767
	SELECT adsrc
768
	FROM pg_attribute
769
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
770
	WHERE attrelid = col.table_ AND attname = col.name
771
	INTO STRICT default_sql
772
	;
773
	RETURN default_sql;
774
EXCEPTION
775
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
776
END;
777
$$;
778

    
779

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

    
784
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
785
    LANGUAGE sql STABLE
786
    AS $_$
787
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
788
$_$;
789

    
790

    
791
--
792
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
793
--
794

    
795
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
796
ret_type_null: NULL::ret_type
797
';
798

    
799

    
800
--
801
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
802
--
803

    
804
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
805
    LANGUAGE plpgsql STRICT
806
    AS $$
807
BEGIN
808
    PERFORM util.col_type(col);
809
    RETURN true;
810
EXCEPTION
811
    WHEN undefined_column THEN RETURN false;
812
END;
813
$$;
814

    
815

    
816
--
817
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
818
--
819

    
820
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
821
    LANGUAGE plpgsql STABLE STRICT
822
    AS $$
823
DECLARE
824
    prefix text := util.name(type)||'.';
825
BEGIN
826
    RETURN QUERY
827
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
828
        FROM util.col_names(type) f (name_);
829
END;
830
$$;
831

    
832

    
833
--
834
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
835
--
836

    
837
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
838
    LANGUAGE sql STABLE
839
    AS $_$
840
SELECT attname::text
841
FROM pg_attribute
842
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
843
ORDER BY attnum
844
$_$;
845

    
846

    
847
--
848
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
849
--
850

    
851
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
852
    LANGUAGE plpgsql STABLE STRICT
853
    AS $_$
854
BEGIN
855
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
856
END;
857
$_$;
858

    
859

    
860
--
861
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
862
--
863

    
864
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
865
    LANGUAGE plpgsql STABLE STRICT
866
    AS $$
867
DECLARE
868
    type regtype;
869
BEGIN
870
    SELECT atttypid FROM pg_attribute
871
    WHERE attrelid = col.table_ AND attname = col.name
872
    INTO STRICT type
873
    ;
874
    RETURN type;
875
EXCEPTION
876
    WHEN no_data_found THEN
877
        RAISE undefined_column USING MESSAGE =
878
            concat('undefined column: ', col.name);
879
END;
880
$$;
881

    
882

    
883
--
884
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
885
--
886

    
887
CREATE FUNCTION comment(element oid) RETURNS text
888
    LANGUAGE sql STABLE
889
    AS $_$
890
SELECT description FROM pg_description WHERE objoid = $1
891
$_$;
892

    
893

    
894
--
895
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
899
    LANGUAGE sql IMMUTABLE
900
    AS $_$
901
SELECT util.esc_name__append($2, $1)
902
$_$;
903

    
904

    
905
--
906
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
907
--
908

    
909
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
910
    LANGUAGE sql IMMUTABLE
911
    AS $_$
912
SELECT position($1 in $2) > 0 /*1-based offset*/
913
$_$;
914

    
915

    
916
--
917
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
918
--
919

    
920
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
921
    LANGUAGE sql
922
    AS $_$
923
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
924
$_$;
925

    
926

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

    
931
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
932
    LANGUAGE plpgsql STRICT
933
    AS $$
934
BEGIN
935
    PERFORM util.eval(sql);
936
EXCEPTION
937
    WHEN duplicate_table  THEN NULL;
938
    WHEN duplicate_object THEN NULL; -- e.g. constraint
939
    WHEN duplicate_column THEN NULL;
940
    WHEN invalid_table_definition THEN
941
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
942
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
943
        END IF;
944
END;
945
$$;
946

    
947

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

    
952
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
953
idempotent
954
';
955

    
956

    
957
--
958
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
959
--
960

    
961
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
962
    LANGUAGE sql IMMUTABLE
963
    AS $$
964
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
965
$$;
966

    
967

    
968
--
969
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
970
--
971

    
972
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
973
    LANGUAGE sql IMMUTABLE
974
    AS $_$
975
SELECT util.raise_notice('returns: '
976
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
977
SELECT $1;
978
$_$;
979

    
980

    
981
--
982
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
983
--
984

    
985
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
986
    LANGUAGE sql IMMUTABLE
987
    AS $_$
988
/* newline before so the query starts at the beginning of the line.
989
newline after to visually separate queries from one another. */
990
SELECT util.raise_notice($$
991
$$||$1||$$
992
$$)
993
$_$;
994

    
995

    
996
--
997
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
998
--
999

    
1000
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1001
    LANGUAGE sql STABLE
1002
    AS $_$
1003
SELECT util.eval2set($$
1004
SELECT col
1005
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1006
LEFT JOIN $$||$2||$$ ON "to" = col
1007
WHERE "from" IS NULL
1008
$$, NULL::text)
1009
$_$;
1010

    
1011

    
1012
--
1013
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1014
--
1015

    
1016
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1017
gets table_''s derived columns (all the columns not in the names table)
1018
';
1019

    
1020

    
1021
--
1022
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1023
--
1024

    
1025
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1026
    LANGUAGE sql
1027
    AS $_$
1028
SELECT * FROM util.diff($1::text, $2::text, $3,
1029
	single_row := util.has_single_row($1) AND util.has_single_row($2),
1030
	search_path := util.schema($3))
1031
$_$;
1032

    
1033

    
1034
--
1035
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1036
--
1037

    
1038
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1039
col_type_null (*required*): NULL::shared_base_type
1040
usage:
1041
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1042
';
1043

    
1044

    
1045
--
1046
-- Name: diff(text, text, anyelement, boolean, text); Type: FUNCTION; Schema: util; Owner: -
1047
--
1048

    
1049
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, search_path text DEFAULT NULL::text, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1050
    LANGUAGE plpgsql
1051
    SET search_path TO pg_temp
1052
    AS $_$
1053
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1054
changes of search_path (schema elements are bound at inline time rather than
1055
runtime) */
1056
/* function option search_path is needed to limit the effects of
1057
`SET LOCAL search_path` (mk_set_search_path()) to the current function */
1058
BEGIN
1059
	EXECUTE util.mk_set_search_path(concat_ws(', ', search_path, 'util'));
1060
		-- need util.%== as default/fallback
1061
	
1062
	RETURN QUERY
1063
		SELECT * FROM
1064
		util.eval2col_pair($$
1065
/* need to explicitly cast each side to the return type because this does not
1066
happen automatically even when an implicit cast is available */
1067
SELECT left_::$$||util.typeof($3)||$$, right_::$$||util.typeof($3)||$$
1068
FROM $$||$1||$$ left_
1069
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
1070
$$||util._if($4, ''::text,
1071
$$ON left_::$$||util.typeof($3)||$$ %== right_::$$||util.typeof($3)||$$
1072
$$)||
1073
$$WHERE left_::$$||util.typeof($3)||$$ IS DISTINCT FROM right_::$$||util.typeof($3)||$$
1074
ORDER BY left_, right_
1075
$$, $3)
1076
	;
1077
END;
1078
$_$;
1079

    
1080

    
1081
--
1082
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1083
--
1084

    
1085
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement) IS '
1086
col_type_null (*required*): NULL::col_type
1087
single_row: whether the tables consist of a single row, which should be
1088
	displayed side-by-side
1089

    
1090
to run EXPLAIN on the FULL JOIN query:
1091
# run this function
1092
# look for a NOTICE containing the expanded query that it ran
1093
# run EXPLAIN on this expanded query
1094
';
1095

    
1096

    
1097
--
1098
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1099
--
1100

    
1101
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1102
    LANGUAGE sql
1103
    AS $_$
1104
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1105
$_$;
1106

    
1107

    
1108
--
1109
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1110
--
1111

    
1112
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1113
idempotent
1114
';
1115

    
1116

    
1117
--
1118
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1119
--
1120

    
1121
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1122
    LANGUAGE sql
1123
    AS $_$
1124
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1125
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1126
$_$;
1127

    
1128

    
1129
--
1130
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1131
--
1132

    
1133
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1134
idempotent
1135
';
1136

    
1137

    
1138
--
1139
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1140
--
1141

    
1142
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1143
    LANGUAGE sql
1144
    AS $_$
1145
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1146
included in the debug SQL */
1147
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1148
$_$;
1149

    
1150

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

    
1155
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1156
    LANGUAGE sql
1157
    AS $_$
1158
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1159
||util._if($3, $$ CASCADE$$, ''::text))
1160
$_$;
1161

    
1162

    
1163
--
1164
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1165
--
1166

    
1167
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1168
idempotent
1169
';
1170

    
1171

    
1172
--
1173
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1174
--
1175

    
1176
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1177
    LANGUAGE sql
1178
    AS $_$
1179
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1180
$3)
1181
$_$;
1182

    
1183

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

    
1188
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1189
    LANGUAGE sql
1190
    AS $_$
1191
SELECT util.drop_relation(relation, $3)
1192
FROM util.show_relations_like($1, $2) relation
1193
;
1194
SELECT NULL::void; -- don't fold away functions called in previous query
1195
$_$;
1196

    
1197

    
1198
--
1199
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1200
--
1201

    
1202
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1203
    LANGUAGE sql
1204
    AS $_$
1205
SELECT util.drop_relation('TABLE', $1, $2)
1206
$_$;
1207

    
1208

    
1209
--
1210
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1211
--
1212

    
1213
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1214
idempotent
1215
';
1216

    
1217

    
1218
--
1219
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1220
--
1221

    
1222
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1223
    LANGUAGE sql
1224
    AS $_$
1225
SELECT util.drop_relation('VIEW', $1, $2)
1226
$_$;
1227

    
1228

    
1229
--
1230
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1231
--
1232

    
1233
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1234
idempotent
1235
';
1236

    
1237

    
1238
--
1239
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1240
--
1241

    
1242
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1243
    LANGUAGE sql IMMUTABLE
1244
    AS $_$
1245
SELECT util.array_fill($1, 0)
1246
$_$;
1247

    
1248

    
1249
--
1250
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1251
--
1252

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

    
1257

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

    
1262
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1263
    LANGUAGE sql IMMUTABLE
1264
    AS $_$
1265
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1266
$_$;
1267

    
1268

    
1269
--
1270
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1271
--
1272

    
1273
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1274
    LANGUAGE sql IMMUTABLE
1275
    AS $_$
1276
SELECT regexp_replace($2, '("?)$', $1||'\1')
1277
$_$;
1278

    
1279

    
1280
--
1281
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1282
--
1283

    
1284
CREATE FUNCTION eval(sql text) RETURNS void
1285
    LANGUAGE plpgsql STRICT
1286
    AS $$
1287
BEGIN
1288
	PERFORM util.debug_print_sql(sql);
1289
	EXECUTE sql;
1290
END;
1291
$$;
1292

    
1293

    
1294
--
1295
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1296
--
1297

    
1298
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1299
    LANGUAGE plpgsql
1300
    AS $$
1301
BEGIN
1302
	PERFORM util.debug_print_sql(sql);
1303
	RETURN QUERY EXECUTE sql;
1304
END;
1305
$$;
1306

    
1307

    
1308
--
1309
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1310
--
1311

    
1312
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1313
col_type_null (*required*): NULL::col_type
1314
';
1315

    
1316

    
1317
--
1318
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1319
--
1320

    
1321
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1322
    LANGUAGE plpgsql
1323
    AS $$
1324
BEGIN
1325
	PERFORM util.debug_print_sql(sql);
1326
	RETURN QUERY EXECUTE sql;
1327
END;
1328
$$;
1329

    
1330

    
1331
--
1332
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1333
--
1334

    
1335
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1336
    LANGUAGE plpgsql
1337
    AS $$
1338
BEGIN
1339
	PERFORM util.debug_print_sql(sql);
1340
	RETURN QUERY EXECUTE sql;
1341
END;
1342
$$;
1343

    
1344

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

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

    
1353

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

    
1358
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1359
    LANGUAGE plpgsql
1360
    AS $$
1361
DECLARE
1362
	ret_val ret_type_null%TYPE;
1363
BEGIN
1364
	PERFORM util.debug_print_sql(sql);
1365
	EXECUTE sql INTO STRICT ret_val;
1366
	RETURN ret_val;
1367
END;
1368
$$;
1369

    
1370

    
1371
--
1372
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1373
--
1374

    
1375
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1376
ret_type_null: NULL::ret_type
1377
';
1378

    
1379

    
1380
--
1381
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1382
--
1383

    
1384
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1385
    LANGUAGE sql
1386
    AS $_$
1387
SELECT util.eval2val($$SELECT $$||$1, $2)
1388
$_$;
1389

    
1390

    
1391
--
1392
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1393
--
1394

    
1395
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1396
ret_type_null: NULL::ret_type
1397
';
1398

    
1399

    
1400
--
1401
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1402
--
1403

    
1404
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1405
    LANGUAGE sql
1406
    AS $_$
1407
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1408
$_$;
1409

    
1410

    
1411
--
1412
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1413
--
1414

    
1415
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1416
sql: can be NULL, which will be passed through
1417
ret_type_null: NULL::ret_type
1418
';
1419

    
1420

    
1421
--
1422
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1423
--
1424

    
1425
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1426
    LANGUAGE sql STABLE
1427
    AS $_$
1428
SELECT col_name
1429
FROM unnest($2) s (col_name)
1430
WHERE util.col_exists(($1, col_name))
1431
$_$;
1432

    
1433

    
1434
--
1435
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1436
--
1437

    
1438
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1439
    LANGUAGE sql
1440
    AS $_$
1441
SELECT util.eval2set($$EXPLAIN $$||$1)
1442
$_$;
1443

    
1444

    
1445
--
1446
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1447
--
1448

    
1449
CREATE FUNCTION explain2notice(sql text) RETURNS void
1450
    LANGUAGE plpgsql
1451
    AS $_$
1452
BEGIN
1453
	RAISE NOTICE '%', $$EXPLAIN:
1454
$$||util.explain2str(sql);
1455
END;
1456
$_$;
1457

    
1458

    
1459
--
1460
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1461
--
1462

    
1463
CREATE FUNCTION explain2str(sql text) RETURNS text
1464
    LANGUAGE sql
1465
    AS $_$
1466
SELECT util.join_strs(explain, $$
1467
$$) FROM util.explain($1)
1468
$_$;
1469

    
1470

    
1471
SET default_tablespace = '';
1472

    
1473
SET default_with_oids = false;
1474

    
1475
--
1476
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1477
--
1478

    
1479
CREATE TABLE explain (
1480
    line text NOT NULL
1481
);
1482

    
1483

    
1484
--
1485
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1486
--
1487

    
1488
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1489
    LANGUAGE sql
1490
    AS $_$
1491
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1492
$$||quote_nullable($1)||$$
1493
)$$)
1494
$_$;
1495

    
1496

    
1497
--
1498
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1499
--
1500

    
1501
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1502
usage:
1503
PERFORM util.explain2table($$
1504
query
1505
$$);
1506
';
1507

    
1508

    
1509
--
1510
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1511
--
1512

    
1513
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1514
    LANGUAGE sql IMMUTABLE
1515
    AS $_$
1516
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1517
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1518
) END
1519
$_$;
1520

    
1521

    
1522
--
1523
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1524
--
1525

    
1526
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1527
ensures that an array will always have proper non-NULL dimensions
1528
';
1529

    
1530

    
1531
--
1532
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1533
--
1534

    
1535
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1536
    LANGUAGE plpgsql
1537
    AS $_$
1538
DECLARE
1539
	PG_EXCEPTION_DETAIL text;
1540
	recreate_users_cmd text = util.save_drop_views(users);
1541
BEGIN
1542
	PERFORM util.eval(cmd);
1543
	PERFORM util.eval(recreate_users_cmd);
1544
EXCEPTION
1545
WHEN dependent_objects_still_exist THEN
1546
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1547
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1548
	users = array(SELECT * FROM util.regexp_matches_group(
1549
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1550
	IF util.is_empty(users) THEN RAISE; END IF;
1551
	PERFORM util.force_recreate(cmd, users);
1552
END;
1553
$_$;
1554

    
1555

    
1556
--
1557
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1558
--
1559

    
1560
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1561
idempotent
1562

    
1563
users: not necessary to provide this because it will be autopopulated
1564
';
1565

    
1566

    
1567
--
1568
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1569
--
1570

    
1571
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1572
    LANGUAGE plpgsql STRICT
1573
    AS $_$
1574
DECLARE
1575
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1576
$$||query;
1577
BEGIN
1578
	EXECUTE mk_view;
1579
EXCEPTION
1580
WHEN invalid_table_definition THEN
1581
	IF SQLERRM = 'cannot drop columns from view'
1582
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1583
	THEN
1584
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1585
		EXECUTE mk_view;
1586
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1587
	END IF;
1588
END;
1589
$_$;
1590

    
1591

    
1592
--
1593
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1594
--
1595

    
1596
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1597
idempotent
1598
';
1599

    
1600

    
1601
--
1602
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1603
--
1604

    
1605
CREATE FUNCTION grants_users() RETURNS SETOF text
1606
    LANGUAGE sql IMMUTABLE
1607
    AS $$
1608
VALUES ('bien_read'), ('public_')
1609
$$;
1610

    
1611

    
1612
--
1613
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1614
--
1615

    
1616
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1617
    LANGUAGE sql IMMUTABLE
1618
    AS $_$
1619
SELECT substring($2 for length($1)) = $1
1620
$_$;
1621

    
1622

    
1623
--
1624
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1625
--
1626

    
1627
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1628
    LANGUAGE sql STABLE
1629
    AS $_$
1630
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1631
$_$;
1632

    
1633

    
1634
--
1635
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1636
--
1637

    
1638
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1639
    LANGUAGE sql IMMUTABLE
1640
    AS $_$
1641
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1642
$_$;
1643

    
1644

    
1645
--
1646
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1647
--
1648

    
1649
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1650
avoids repeating the same value for each key
1651
';
1652

    
1653

    
1654
--
1655
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1656
--
1657

    
1658
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1659
    LANGUAGE sql IMMUTABLE
1660
    AS $_$
1661
SELECT COALESCE($1, $2)
1662
$_$;
1663

    
1664

    
1665
--
1666
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1667
--
1668

    
1669
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1670
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1671
';
1672

    
1673

    
1674
--
1675
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1676
--
1677

    
1678
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1679
    LANGUAGE sql
1680
    AS $_$
1681
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1682
$_$;
1683

    
1684

    
1685
--
1686
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1687
--
1688

    
1689
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1690
    LANGUAGE sql STABLE
1691
    AS $_$
1692
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1693
$_$;
1694

    
1695

    
1696
--
1697
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1698
--
1699

    
1700
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1701
    LANGUAGE sql IMMUTABLE
1702
    AS $_$
1703
SELECT util.array_length($1) = 0
1704
$_$;
1705

    
1706

    
1707
--
1708
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1709
--
1710

    
1711
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1712
    LANGUAGE sql IMMUTABLE
1713
    AS $_$
1714
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1715
$_$;
1716

    
1717

    
1718
--
1719
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1720
--
1721

    
1722
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1723
    LANGUAGE sql IMMUTABLE
1724
    AS $_$
1725
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1726
$_$;
1727

    
1728

    
1729
--
1730
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1731
--
1732

    
1733
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1734
    LANGUAGE sql STABLE
1735
    AS $_$
1736
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1737
$_$;
1738

    
1739

    
1740
--
1741
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1742
--
1743

    
1744
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1745
    LANGUAGE sql STABLE
1746
    AS $_$
1747
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1748
$_$;
1749

    
1750

    
1751
--
1752
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1753
--
1754

    
1755
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1756
    LANGUAGE sql IMMUTABLE STRICT
1757
    AS $_$
1758
SELECT $1 || $3 || $2
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1764
--
1765

    
1766
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1767
must be declared STRICT to use the special handling of STRICT aggregating functions
1768
';
1769

    
1770

    
1771
--
1772
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1773
--
1774

    
1775
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1776
    LANGUAGE sql IMMUTABLE
1777
    AS $_$
1778
SELECT $1 -- compare on the entire value
1779
$_$;
1780

    
1781

    
1782
--
1783
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1784
--
1785

    
1786
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1787
    LANGUAGE sql IMMUTABLE
1788
    AS $_$
1789
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1790
$_$;
1791

    
1792

    
1793
--
1794
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1795
--
1796

    
1797
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1798
    LANGUAGE sql IMMUTABLE
1799
    AS $_$
1800
SELECT ltrim($1, $$
1801
$$)
1802
$_$;
1803

    
1804

    
1805
--
1806
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1807
--
1808

    
1809
CREATE FUNCTION map_filter_insert() RETURNS trigger
1810
    LANGUAGE plpgsql
1811
    AS $$
1812
BEGIN
1813
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1814
	RETURN new;
1815
END;
1816
$$;
1817

    
1818

    
1819
--
1820
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1821
--
1822

    
1823
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1824
    LANGUAGE plpgsql STABLE STRICT
1825
    AS $_$
1826
DECLARE
1827
    value text;
1828
BEGIN
1829
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1830
        INTO value USING key;
1831
    RETURN value;
1832
END;
1833
$_$;
1834

    
1835

    
1836
--
1837
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1838
--
1839

    
1840
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1841
    LANGUAGE sql IMMUTABLE
1842
    AS $_$
1843
SELECT util._map(util.nulls_map($1), $2)
1844
$_$;
1845

    
1846

    
1847
--
1848
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1849
--
1850

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

    
1854
[1] inlining of function calls, which is different from constant folding
1855
[2] _map()''s profiling query
1856
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1857
and map_nulls()''s profiling query
1858
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1859
both take ~920 ms.
1860
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.
1861
';
1862

    
1863

    
1864
--
1865
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1866
--
1867

    
1868
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1869
    LANGUAGE plpgsql STABLE STRICT
1870
    AS $_$
1871
BEGIN
1872
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1873
END;
1874
$_$;
1875

    
1876

    
1877
--
1878
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1879
--
1880

    
1881
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1882
    LANGUAGE sql
1883
    AS $_$
1884
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1885
$$||util.ltrim_nl($2));
1886
-- make sure the created table has the correct estimated row count
1887
SELECT util.analyze_($1);
1888
$_$;
1889

    
1890

    
1891
--
1892
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1893
--
1894

    
1895
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1896
idempotent
1897
';
1898

    
1899

    
1900
--
1901
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1902
--
1903

    
1904
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1905
    LANGUAGE sql
1906
    AS $_$
1907
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1908
$_$;
1909

    
1910

    
1911
--
1912
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1913
--
1914

    
1915
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1916
idempotent
1917
';
1918

    
1919

    
1920
--
1921
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1922
--
1923

    
1924
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1925
    LANGUAGE sql
1926
    AS $_$
1927
SELECT util.create_if_not_exists($$
1928
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1929
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1930
||quote_literal($2)||$$;
1931
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1932
constant
1933
';
1934
$$)
1935
$_$;
1936

    
1937

    
1938
--
1939
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1940
--
1941

    
1942
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1943
idempotent
1944
';
1945

    
1946

    
1947
--
1948
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1949
--
1950

    
1951
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1952
    LANGUAGE plpgsql STRICT
1953
    AS $_$
1954
DECLARE
1955
    type regtype = util.typeof(expr, col.table_::text::regtype);
1956
    col_name_sql text = quote_ident(col.name);
1957
BEGIN
1958
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1959
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1960
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1961
$$||expr||$$;
1962
$$);
1963
END;
1964
$_$;
1965

    
1966

    
1967
--
1968
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1969
--
1970

    
1971
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1972
idempotent
1973
';
1974

    
1975

    
1976
--
1977
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1978
--
1979

    
1980
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1981
    LANGUAGE sql
1982
    AS $_$
1983
SELECT util.create_if_not_exists($$
1984
CREATE TABLE $$||$1||$$
1985
(
1986
    LIKE util.map INCLUDING ALL
1987
);
1988

    
1989
CREATE TRIGGER map_filter_insert
1990
  BEFORE INSERT
1991
  ON $$||$1||$$
1992
  FOR EACH ROW
1993
  EXECUTE PROCEDURE util.map_filter_insert();
1994
$$)
1995
$_$;
1996

    
1997

    
1998
--
1999
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2000
--
2001

    
2002
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2003
    LANGUAGE sql IMMUTABLE
2004
    AS $_$
2005
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2006
$_$;
2007

    
2008

    
2009
--
2010
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2011
--
2012

    
2013
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2014
    LANGUAGE sql IMMUTABLE
2015
    AS $_$
2016
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2017
$_$;
2018

    
2019

    
2020
--
2021
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2022
--
2023

    
2024
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2025
usage:
2026
for *1* schema arg:
2027
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2028
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2029
';
2030

    
2031

    
2032
--
2033
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
2034
--
2035

    
2036
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
2037
    LANGUAGE sql IMMUTABLE
2038
    AS $_$
2039
/* debug_print_return_value() needed because this function is used with EXECUTE
2040
rather than util.eval() (in order to affect the calling function), so the
2041
search_path would not otherwise be printed */
2042
SELECT util.debug_print_return_value($$SET LOCAL search_path TO $$||$1)
2043
$_$;
2044

    
2045

    
2046
--
2047
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2048
--
2049

    
2050
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2051
    LANGUAGE sql
2052
    AS $_$
2053
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2054
$_$;
2055

    
2056

    
2057
--
2058
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2059
--
2060

    
2061
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2062
idempotent
2063
';
2064

    
2065

    
2066
--
2067
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2068
--
2069

    
2070
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2071
    LANGUAGE plpgsql STRICT
2072
    AS $_$
2073
DECLARE
2074
	view_qual_name text = util.qual_name(view_);
2075
BEGIN
2076
	EXECUTE $$
2077
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2078
  RETURNS SETOF $$||view_||$$ AS
2079
$BODY1$
2080
SELECT * FROM $$||view_qual_name||$$
2081
ORDER BY sort_col
2082
LIMIT $1 OFFSET $2
2083
$BODY1$
2084
  LANGUAGE sql STABLE
2085
  COST 100
2086
  ROWS 1000
2087
$$;
2088
	
2089
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2090
END;
2091
$_$;
2092

    
2093

    
2094
--
2095
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2096
--
2097

    
2098
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2099
    LANGUAGE plpgsql STRICT
2100
    AS $_$
2101
DECLARE
2102
	view_qual_name text = util.qual_name(view_);
2103
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2104
BEGIN
2105
	EXECUTE $$
2106
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2107
  RETURNS integer AS
2108
$BODY1$
2109
SELECT $$||quote_ident(row_num_col)||$$
2110
FROM $$||view_qual_name||$$
2111
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2112
LIMIT 1
2113
$BODY1$
2114
  LANGUAGE sql STABLE
2115
  COST 100;
2116
$$;
2117
	
2118
	EXECUTE $$
2119
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2120
  RETURNS SETOF $$||view_||$$ AS
2121
$BODY1$
2122
SELECT * FROM $$||view_qual_name||$$
2123
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2124
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2125
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2126
ORDER BY $$||quote_ident(row_num_col)||$$
2127
$BODY1$
2128
  LANGUAGE sql STABLE
2129
  COST 100
2130
  ROWS 1000
2131
$$;
2132
	
2133
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2134
END;
2135
$_$;
2136

    
2137

    
2138
--
2139
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2140
--
2141

    
2142
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2143
    LANGUAGE plpgsql STRICT
2144
    AS $_$
2145
DECLARE
2146
	view_qual_name text = util.qual_name(view_);
2147
BEGIN
2148
	EXECUTE $$
2149
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2150
  RETURNS SETOF $$||view_||$$
2151
  SET enable_sort TO 'off'
2152
  AS
2153
$BODY1$
2154
SELECT * FROM $$||view_qual_name||$$($2, $3)
2155
$BODY1$
2156
  LANGUAGE sql STABLE
2157
  COST 100
2158
  ROWS 1000
2159
;
2160
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2161
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2162
If you want to run EXPLAIN and get expanded output, use the regular subset
2163
function instead. (When a config param is set on a function, EXPLAIN produces
2164
just a function scan.)
2165
';
2166
$$;
2167
END;
2168
$_$;
2169

    
2170

    
2171
--
2172
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2173
--
2174

    
2175
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2176
creates subset function which turns off enable_sort
2177
';
2178

    
2179

    
2180
--
2181
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2182
--
2183

    
2184
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2185
    LANGUAGE sql IMMUTABLE
2186
    AS $_$
2187
SELECT util.mk_set_search_path(util.schema_esc($1))
2188
$_$;
2189

    
2190

    
2191
--
2192
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2193
--
2194

    
2195
CREATE FUNCTION name(table_ regclass) RETURNS text
2196
    LANGUAGE sql STABLE
2197
    AS $_$
2198
SELECT relname::text FROM pg_class WHERE oid = $1
2199
$_$;
2200

    
2201

    
2202
--
2203
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2204
--
2205

    
2206
CREATE FUNCTION name(type regtype) RETURNS text
2207
    LANGUAGE sql STABLE
2208
    AS $_$
2209
SELECT typname::text FROM pg_type WHERE oid = $1
2210
$_$;
2211

    
2212

    
2213
--
2214
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2215
--
2216

    
2217
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2218
    LANGUAGE sql IMMUTABLE
2219
    AS $_$
2220
SELECT octet_length($1) >= util.namedatalen() - $2
2221
$_$;
2222

    
2223

    
2224
--
2225
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2226
--
2227

    
2228
CREATE FUNCTION namedatalen() RETURNS integer
2229
    LANGUAGE sql IMMUTABLE
2230
    AS $$
2231
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2232
$$;
2233

    
2234

    
2235
--
2236
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2237
--
2238

    
2239
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2240
    LANGUAGE sql IMMUTABLE
2241
    AS $_$
2242
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2243
$_$;
2244

    
2245

    
2246
--
2247
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2248
--
2249

    
2250
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2251
    LANGUAGE sql IMMUTABLE
2252
    AS $_$
2253
SELECT $1 IS NOT NULL
2254
$_$;
2255

    
2256

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

    
2261
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2262
    LANGUAGE sql IMMUTABLE
2263
    AS $_$
2264
SELECT util.hstore($1, NULL) || '*=>*'
2265
$_$;
2266

    
2267

    
2268
--
2269
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2270
--
2271

    
2272
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2273
for use with _map()
2274
';
2275

    
2276

    
2277
--
2278
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2279
--
2280

    
2281
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2282
    LANGUAGE sql IMMUTABLE
2283
    AS $_$
2284
SELECT $2 + COALESCE($1, 0)
2285
$_$;
2286

    
2287

    
2288
--
2289
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2290
--
2291

    
2292
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2293
    LANGUAGE sql IMMUTABLE
2294
    AS $_$
2295
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2296
$_$;
2297

    
2298

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

    
2303
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2304
    LANGUAGE sql STABLE
2305
    SET search_path TO pg_temp
2306
    AS $_$
2307
SELECT $1::text
2308
$_$;
2309

    
2310

    
2311
--
2312
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2313
--
2314

    
2315
CREATE FUNCTION qual_name(type regtype) RETURNS text
2316
    LANGUAGE sql STABLE
2317
    SET search_path TO pg_temp
2318
    AS $_$
2319
SELECT $1::text
2320
$_$;
2321

    
2322

    
2323
--
2324
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2325
--
2326

    
2327
COMMENT ON FUNCTION qual_name(type regtype) IS '
2328
a type''s schema-qualified name
2329
';
2330

    
2331

    
2332
--
2333
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2334
--
2335

    
2336
CREATE FUNCTION qual_name(type unknown) RETURNS text
2337
    LANGUAGE sql STABLE
2338
    AS $_$
2339
SELECT util.qual_name($1::text::regtype)
2340
$_$;
2341

    
2342

    
2343
--
2344
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2345
--
2346

    
2347
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2348
    LANGUAGE sql IMMUTABLE
2349
    AS $_$
2350
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2351
$_$;
2352

    
2353

    
2354
--
2355
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2356
--
2357

    
2358
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2359
    LANGUAGE sql IMMUTABLE
2360
    AS $_$
2361
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2362
$_$;
2363

    
2364

    
2365
--
2366
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2367
--
2368

    
2369
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2370
    LANGUAGE sql IMMUTABLE
2371
    AS $_$
2372
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2373
$_$;
2374

    
2375

    
2376
--
2377
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2378
--
2379

    
2380
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2381
    LANGUAGE sql IMMUTABLE
2382
    AS $_$
2383
SELECT util.raise_notice('ERROR:  '||$1)
2384
$_$;
2385

    
2386

    
2387
--
2388
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2389
--
2390

    
2391
CREATE FUNCTION raise_notice(msg text) RETURNS void
2392
    LANGUAGE plpgsql IMMUTABLE STRICT
2393
    AS $$
2394
BEGIN
2395
	RAISE NOTICE '%', msg;
2396
END;
2397
$$;
2398

    
2399

    
2400
--
2401
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2402
--
2403

    
2404
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2405
    LANGUAGE plpgsql IMMUTABLE STRICT
2406
    AS $$
2407
BEGIN
2408
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2409
END;
2410
$$;
2411

    
2412

    
2413
--
2414
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2415
--
2416

    
2417
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2418
    LANGUAGE sql IMMUTABLE
2419
    AS $_$
2420
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2421
$_$;
2422

    
2423

    
2424
--
2425
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2426
--
2427

    
2428
CREATE FUNCTION regexp_quote(str text) RETURNS text
2429
    LANGUAGE sql IMMUTABLE
2430
    AS $_$
2431
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2432
$_$;
2433

    
2434

    
2435
--
2436
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2437
--
2438

    
2439
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2440
    LANGUAGE sql IMMUTABLE
2441
    AS $_$
2442
SELECT (CASE WHEN right($1, 1) = ')'
2443
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2444
$_$;
2445

    
2446

    
2447
--
2448
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2449
--
2450

    
2451
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2452
    LANGUAGE sql STABLE
2453
    AS $_$
2454
SELECT util.relation_type(util.relation_type_char($1))
2455
$_$;
2456

    
2457

    
2458
--
2459
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2460
--
2461

    
2462
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2463
    LANGUAGE sql IMMUTABLE
2464
    AS $_$
2465
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2466
$_$;
2467

    
2468

    
2469
--
2470
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2471
--
2472

    
2473
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2474
    LANGUAGE sql STABLE
2475
    AS $_$
2476
SELECT relkind FROM pg_class WHERE oid = $1
2477
$_$;
2478

    
2479

    
2480
--
2481
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2482
--
2483

    
2484
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2485
    LANGUAGE sql
2486
    AS $_$
2487
/* can't have in_table/out_table inherit from *each other*, because inheritance
2488
also causes the rows of the parent table to be included in the child table.
2489
instead, they need to inherit from a common, empty table. */
2490
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2491
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2492
SELECT util.inherit($2, $4);
2493
SELECT util.inherit($3, $4);
2494

    
2495
SELECT util.rematerialize_query($1, $$
2496
SELECT * FROM util.diff(
2497
  $$||util.quote_typed($2)||$$
2498
, $$||util.quote_typed($3)||$$
2499
, NULL::$$||$4||$$)
2500
$$);
2501

    
2502
/* the table unfortunately cannot be *materialized* in human-readable form,
2503
because this would create column name collisions between the two sides */
2504
SELECT util.append_comment($1, '
2505
to view this table in human-readable form (with each side''s tuple column
2506
expanded to its component fields):
2507
SELECT (left_).*, (right_).* FROM '||$1||';
2508
');
2509
$_$;
2510

    
2511

    
2512
--
2513
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2514
--
2515

    
2516
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2517
type_table (*required*): table to create as the shared base type
2518
';
2519

    
2520

    
2521
--
2522
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2523
--
2524

    
2525
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2526
    LANGUAGE sql
2527
    AS $_$
2528
SELECT util.drop_table($1);
2529
SELECT util.materialize_query($1, $2);
2530
$_$;
2531

    
2532

    
2533
--
2534
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2535
--
2536

    
2537
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2538
idempotent, but repeats action each time
2539
';
2540

    
2541

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

    
2546
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2547
    LANGUAGE sql
2548
    AS $_$
2549
SELECT util.drop_table($1);
2550
SELECT util.materialize_view($1, $2);
2551
$_$;
2552

    
2553

    
2554
--
2555
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2556
--
2557

    
2558
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2559
idempotent, but repeats action each time
2560
';
2561

    
2562

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

    
2567
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2568
    LANGUAGE sql
2569
    AS $_$
2570
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2571
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2572
FROM util.col_names($1::text::regtype) f (name);
2573
SELECT NULL::void; -- don't fold away functions called in previous query
2574
$_$;
2575

    
2576

    
2577
--
2578
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2579
--
2580

    
2581
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2582
idempotent
2583
';
2584

    
2585

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

    
2590
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2591
    LANGUAGE sql
2592
    AS $_$
2593
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2594
included in the debug SQL */
2595
SELECT util.rename_relation(util.qual_name($1), $2)
2596
$_$;
2597

    
2598

    
2599
--
2600
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2601
--
2602

    
2603
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2604
    LANGUAGE sql
2605
    AS $_$
2606
/* 'ALTER TABLE can be used with views too'
2607
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2608
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2609
||quote_ident($2))
2610
$_$;
2611

    
2612

    
2613
--
2614
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2615
--
2616

    
2617
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2618
idempotent
2619
';
2620

    
2621

    
2622
--
2623
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2624
--
2625

    
2626
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2627
    LANGUAGE sql IMMUTABLE
2628
    AS $_$
2629
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2630
$_$;
2631

    
2632

    
2633
--
2634
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2635
--
2636

    
2637
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2638
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 
2639
';
2640

    
2641

    
2642
--
2643
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2644
--
2645

    
2646
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2647
    LANGUAGE sql
2648
    AS $_$
2649
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2650
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2651
SELECT util.set_col_names($1, $2);
2652
$_$;
2653

    
2654

    
2655
--
2656
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2657
--
2658

    
2659
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2660
idempotent.
2661
alters the names table, so it will need to be repopulated after running this function.
2662
';
2663

    
2664

    
2665
--
2666
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2667
--
2668

    
2669
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2670
    LANGUAGE sql
2671
    AS $_$
2672
SELECT util.drop_table($1);
2673
SELECT util.mk_map_table($1);
2674
$_$;
2675

    
2676

    
2677
--
2678
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2679
--
2680

    
2681
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2682
    LANGUAGE sql IMMUTABLE
2683
    AS $_$
2684
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2685
$_$;
2686

    
2687

    
2688
--
2689
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2690
--
2691

    
2692
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2693
    LANGUAGE plpgsql STRICT
2694
    AS $_$
2695
DECLARE
2696
	result text = NULL;
2697
BEGIN
2698
	BEGIN
2699
		result = util.show_create_view(view_);
2700
		PERFORM util.eval($$DROP VIEW $$||view_);
2701
	EXCEPTION
2702
		WHEN undefined_table THEN NULL;
2703
	END;
2704
	RETURN result;
2705
END;
2706
$_$;
2707

    
2708

    
2709
--
2710
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2711
--
2712

    
2713
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2714
    LANGUAGE sql
2715
    AS $_$
2716
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2717
$_$;
2718

    
2719

    
2720
--
2721
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2722
--
2723

    
2724
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2725
    LANGUAGE sql STABLE
2726
    AS $_$
2727
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2728
$_$;
2729

    
2730

    
2731
--
2732
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2733
--
2734

    
2735
CREATE FUNCTION schema(table_ regclass) RETURNS text
2736
    LANGUAGE sql STABLE
2737
    AS $_$
2738
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2739
$_$;
2740

    
2741

    
2742
--
2743
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2744
--
2745

    
2746
CREATE FUNCTION schema(type regtype) RETURNS text
2747
    LANGUAGE sql STABLE
2748
    AS $_$
2749
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2750
$_$;
2751

    
2752

    
2753
--
2754
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2755
--
2756

    
2757
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2758
    LANGUAGE sql STABLE
2759
    AS $_$
2760
SELECT util.schema(pg_typeof($1))
2761
$_$;
2762

    
2763

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

    
2768
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2769
    LANGUAGE sql STABLE
2770
    AS $_$
2771
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2772
$_$;
2773

    
2774

    
2775
--
2776
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2777
--
2778

    
2779
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2780
a schema bundle is a group of schemas with a common prefix
2781
';
2782

    
2783

    
2784
--
2785
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2786
--
2787

    
2788
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2789
    LANGUAGE sql
2790
    AS $_$
2791
SELECT util.schema_rename(old_schema,
2792
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2793
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2794
SELECT NULL::void; -- don't fold away functions called in previous query
2795
$_$;
2796

    
2797

    
2798
--
2799
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2800
--
2801

    
2802
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2803
    LANGUAGE plpgsql
2804
    AS $$
2805
BEGIN
2806
	-- don't schema_bundle_rm() the schema_bundle to keep!
2807
	IF replace = with_ THEN RETURN; END IF;
2808
	
2809
	PERFORM util.schema_bundle_rm(replace);
2810
	PERFORM util.schema_bundle_rename(with_, replace);
2811
END;
2812
$$;
2813

    
2814

    
2815
--
2816
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2817
--
2818

    
2819
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2820
    LANGUAGE sql
2821
    AS $_$
2822
SELECT util.schema_rm(schema)
2823
FROM util.schema_bundle_get_schemas($1) f (schema);
2824
SELECT NULL::void; -- don't fold away functions called in previous query
2825
$_$;
2826

    
2827

    
2828
--
2829
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2830
--
2831

    
2832
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2833
    LANGUAGE sql STABLE
2834
    AS $_$
2835
SELECT quote_ident(util.schema($1))
2836
$_$;
2837

    
2838

    
2839
--
2840
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2841
--
2842

    
2843
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2844
    LANGUAGE sql IMMUTABLE
2845
    AS $_$
2846
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2847
$_$;
2848

    
2849

    
2850
--
2851
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2852
--
2853

    
2854
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2855
    LANGUAGE sql STABLE
2856
    AS $_$
2857
SELECT oid FROM pg_namespace WHERE nspname = $1
2858
$_$;
2859

    
2860

    
2861
--
2862
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2863
--
2864

    
2865
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2866
    LANGUAGE sql
2867
    AS $_$
2868
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2869
$_$;
2870

    
2871

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

    
2876
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2877
    LANGUAGE plpgsql
2878
    AS $$
2879
BEGIN
2880
	-- don't schema_rm() the schema to keep!
2881
	IF replace = with_ THEN RETURN; END IF;
2882
	
2883
	PERFORM util.schema_rm(replace);
2884
	PERFORM util.schema_rename(with_, replace);
2885
END;
2886
$$;
2887

    
2888

    
2889
--
2890
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2891
--
2892

    
2893
CREATE FUNCTION schema_rm(schema text) RETURNS void
2894
    LANGUAGE sql
2895
    AS $_$
2896
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2897
$_$;
2898

    
2899

    
2900
--
2901
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2902
--
2903

    
2904
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2905
    LANGUAGE sql
2906
    AS $_$
2907
SELECT util.eval(
2908
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2909
$_$;
2910

    
2911

    
2912
--
2913
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2914
--
2915

    
2916
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2917
    LANGUAGE plpgsql STRICT
2918
    AS $_$
2919
DECLARE
2920
    old text[] = ARRAY(SELECT util.col_names(table_));
2921
    new text[] = ARRAY(SELECT util.map_values(names));
2922
BEGIN
2923
    old = old[1:array_length(new, 1)]; -- truncate to same length
2924
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2925
||$$ TO $$||quote_ident(value))
2926
    FROM each(hstore(old, new))
2927
    WHERE value != key -- not same name
2928
    ;
2929
END;
2930
$_$;
2931

    
2932

    
2933
--
2934
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2935
--
2936

    
2937
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2938
idempotent
2939
';
2940

    
2941

    
2942
--
2943
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2944
--
2945

    
2946
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2947
    LANGUAGE plpgsql STRICT
2948
    AS $_$
2949
DECLARE
2950
	row_ util.map;
2951
BEGIN
2952
	-- rename any metadata cols rather than re-adding them with new names
2953
	BEGIN
2954
		PERFORM util.set_col_names(table_, names);
2955
	EXCEPTION
2956
		WHEN array_subscript_error THEN -- selective suppress
2957
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2958
				-- metadata cols not yet added
2959
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2960
			END IF;
2961
	END;
2962
	
2963
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2964
	LOOP
2965
		PERFORM util.mk_const_col((table_, row_."to"),
2966
			substring(row_."from" from 2));
2967
	END LOOP;
2968
	
2969
	PERFORM util.set_col_names(table_, names);
2970
END;
2971
$_$;
2972

    
2973

    
2974
--
2975
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2976
--
2977

    
2978
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2979
idempotent.
2980
the metadata mappings must be *last* in the names table.
2981
';
2982

    
2983

    
2984
--
2985
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2986
--
2987

    
2988
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2989
    LANGUAGE plpgsql STRICT
2990
    AS $_$
2991
DECLARE
2992
    sql text = $$ALTER TABLE $$||table_||$$
2993
$$||NULLIF(array_to_string(ARRAY(
2994
    SELECT
2995
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2996
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2997
    FROM
2998
    (
2999
        SELECT
3000
          quote_ident(col_name) AS col_name_sql
3001
        , util.col_type((table_, col_name)) AS curr_type
3002
        , type AS target_type
3003
        FROM unnest(col_casts)
3004
    ) s
3005
    WHERE curr_type != target_type
3006
), '
3007
, '), '');
3008
BEGIN
3009
    PERFORM util.debug_print_sql(sql);
3010
    EXECUTE COALESCE(sql, '');
3011
END;
3012
$_$;
3013

    
3014

    
3015
--
3016
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3017
--
3018

    
3019
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3020
idempotent
3021
';
3022

    
3023

    
3024
--
3025
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3026
--
3027

    
3028
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3029
    LANGUAGE sql
3030
    AS $_$
3031
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3032
$_$;
3033

    
3034

    
3035
--
3036
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3037
--
3038

    
3039
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3040
    LANGUAGE sql STABLE
3041
    AS $_$
3042
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3043
$$||util.show_grants_for($1)
3044
$_$;
3045

    
3046

    
3047
--
3048
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3049
--
3050

    
3051
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3052
    LANGUAGE sql STABLE
3053
    AS $_$
3054
SELECT string_agg(cmd, '')
3055
FROM
3056
(
3057
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3058
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3059
$$ ELSE '' END) AS cmd
3060
	FROM util.grants_users() f (user_)
3061
) s
3062
$_$;
3063

    
3064

    
3065
--
3066
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3067
--
3068

    
3069
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3070
    LANGUAGE sql STABLE
3071
    AS $_$
3072
SELECT oid FROM pg_class
3073
WHERE relkind = ANY($3) AND relname ~ $1
3074
AND util.schema_matches(util.schema(relnamespace), $2)
3075
ORDER BY relname
3076
$_$;
3077

    
3078

    
3079
--
3080
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3081
--
3082

    
3083
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3084
    LANGUAGE sql STABLE
3085
    AS $_$
3086
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3087
$_$;
3088

    
3089

    
3090
--
3091
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3092
--
3093

    
3094
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3095
    LANGUAGE sql IMMUTABLE
3096
    AS $_$
3097
SELECT '^'||util.regexp_quote($1)||'$'
3098
$_$;
3099

    
3100

    
3101
--
3102
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3103
--
3104

    
3105
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3106
    LANGUAGE plpgsql STABLE STRICT
3107
    AS $_$
3108
DECLARE
3109
    hstore hstore;
3110
BEGIN
3111
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3112
        table_||$$))$$ INTO STRICT hstore;
3113
    RETURN hstore;
3114
END;
3115
$_$;
3116

    
3117

    
3118
--
3119
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3120
--
3121

    
3122
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3123
    LANGUAGE sql STABLE
3124
    AS $_$
3125
SELECT COUNT(*) > 0 FROM pg_constraint
3126
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3127
$_$;
3128

    
3129

    
3130
--
3131
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3132
--
3133

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

    
3138

    
3139
--
3140
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3141
--
3142

    
3143
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3144
    LANGUAGE sql
3145
    AS $_$
3146
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3147
||quote_ident($2)||$$ CHECK (true)$$)
3148
$_$;
3149

    
3150

    
3151
--
3152
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3153
--
3154

    
3155
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3156
stores a status flag by the presence of a table constraint.
3157
idempotent.
3158
';
3159

    
3160

    
3161
--
3162
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3163
--
3164

    
3165
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3166
    LANGUAGE sql STABLE
3167
    AS $_$
3168
SELECT util.table_flag__get($1, 'nulls_mapped')
3169
$_$;
3170

    
3171

    
3172
--
3173
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3174
--
3175

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

    
3180

    
3181
--
3182
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3183
--
3184

    
3185
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3186
    LANGUAGE sql
3187
    AS $_$
3188
SELECT util.table_flag__set($1, 'nulls_mapped')
3189
$_$;
3190

    
3191

    
3192
--
3193
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3194
--
3195

    
3196
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3197
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3198
idempotent.
3199
';
3200

    
3201

    
3202
--
3203
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3204
--
3205

    
3206
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3207
    LANGUAGE plpgsql STRICT
3208
    AS $_$
3209
DECLARE
3210
    row record;
3211
BEGIN
3212
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3213
    LOOP
3214
        IF row.global_name != row.name THEN
3215
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3216
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3217
        END IF;
3218
    END LOOP;
3219
END;
3220
$_$;
3221

    
3222

    
3223
--
3224
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3225
--
3226

    
3227
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3228
idempotent
3229
';
3230

    
3231

    
3232
--
3233
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3234
--
3235

    
3236
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3237
    LANGUAGE sql
3238
    AS $_$
3239
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3240
SELECT NULL::void; -- don't fold away functions called in previous query
3241
$_$;
3242

    
3243

    
3244
--
3245
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3246
--
3247

    
3248
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3249
trims table_ to include only columns in the original data.
3250
idempotent.
3251
';
3252

    
3253

    
3254
--
3255
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3256
--
3257

    
3258
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3259
    LANGUAGE plpgsql STRICT
3260
    AS $_$
3261
BEGIN
3262
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3263
END;
3264
$_$;
3265

    
3266

    
3267
--
3268
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3269
--
3270

    
3271
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3272
idempotent
3273
';
3274

    
3275

    
3276
--
3277
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3278
--
3279

    
3280
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3281
    LANGUAGE sql IMMUTABLE
3282
    AS $_$
3283
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3284
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3285
$_$;
3286

    
3287

    
3288
--
3289
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3290
--
3291

    
3292
CREATE FUNCTION try_create(sql text) RETURNS void
3293
    LANGUAGE plpgsql STRICT
3294
    AS $$
3295
BEGIN
3296
    PERFORM util.eval(sql);
3297
EXCEPTION
3298
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3299
    WHEN undefined_column THEN NULL;
3300
    WHEN duplicate_column THEN NULL;
3301
END;
3302
$$;
3303

    
3304

    
3305
--
3306
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3307
--
3308

    
3309
COMMENT ON FUNCTION try_create(sql text) IS '
3310
idempotent
3311
';
3312

    
3313

    
3314
--
3315
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3316
--
3317

    
3318
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3319
    LANGUAGE sql
3320
    AS $_$
3321
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3322
$_$;
3323

    
3324

    
3325
--
3326
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3327
--
3328

    
3329
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3330
idempotent
3331
';
3332

    
3333

    
3334
--
3335
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3336
--
3337

    
3338
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3339
    LANGUAGE sql IMMUTABLE
3340
    AS $_$
3341
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3342
$_$;
3343

    
3344

    
3345
--
3346
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3347
--
3348

    
3349
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3350
a type''s NOT NULL qualifier
3351
';
3352

    
3353

    
3354
--
3355
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3356
--
3357

    
3358
CREATE FUNCTION typeof(value anyelement) RETURNS text
3359
    LANGUAGE sql IMMUTABLE
3360
    AS $_$
3361
SELECT util.qual_name(pg_typeof($1))
3362
$_$;
3363

    
3364

    
3365
--
3366
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3367
--
3368

    
3369
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3370
    LANGUAGE plpgsql STABLE
3371
    AS $_$
3372
DECLARE
3373
    type regtype;
3374
BEGIN
3375
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3376
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3377
    RETURN type;
3378
END;
3379
$_$;
3380

    
3381

    
3382
--
3383
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3384
--
3385

    
3386
CREATE AGGREGATE all_same(anyelement) (
3387
    SFUNC = all_same_transform,
3388
    STYPE = anyarray,
3389
    FINALFUNC = all_same_final
3390
);
3391

    
3392

    
3393
--
3394
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3395
--
3396

    
3397
COMMENT ON AGGREGATE all_same(anyelement) IS '
3398
includes NULLs in comparison
3399
';
3400

    
3401

    
3402
--
3403
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3404
--
3405

    
3406
CREATE AGGREGATE join_strs(text, text) (
3407
    SFUNC = join_strs_transform,
3408
    STYPE = text
3409
);
3410

    
3411

    
3412
--
3413
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3414
--
3415

    
3416
CREATE OPERATOR %== (
3417
    PROCEDURE = "%==",
3418
    LEFTARG = anyelement,
3419
    RIGHTARG = anyelement
3420
);
3421

    
3422

    
3423
--
3424
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3425
--
3426

    
3427
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3428
returns whether the map-keys of the compared values are the same
3429
(mnemonic: % is the Perl symbol for a hash map)
3430

    
3431
should be overridden for types that store both keys and values
3432

    
3433
used in a FULL JOIN to select which columns to join on
3434
';
3435

    
3436

    
3437
--
3438
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3439
--
3440

    
3441
CREATE OPERATOR -> (
3442
    PROCEDURE = map_get,
3443
    LEFTARG = regclass,
3444
    RIGHTARG = text
3445
);
3446

    
3447

    
3448
--
3449
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3450
--
3451

    
3452
CREATE OPERATOR => (
3453
    PROCEDURE = hstore,
3454
    LEFTARG = text[],
3455
    RIGHTARG = text
3456
);
3457

    
3458

    
3459
--
3460
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3461
--
3462

    
3463
COMMENT ON OPERATOR => (text[], text) IS '
3464
usage: array[''key1'', ...]::text[] => ''value''
3465
';
3466

    
3467

    
3468
--
3469
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3470
--
3471

    
3472
CREATE OPERATOR ?*>= (
3473
    PROCEDURE = is_populated_more_often_than,
3474
    LEFTARG = anyelement,
3475
    RIGHTARG = anyelement
3476
);
3477

    
3478

    
3479
--
3480
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3481
--
3482

    
3483
CREATE OPERATOR ?>= (
3484
    PROCEDURE = is_more_complete_than,
3485
    LEFTARG = anyelement,
3486
    RIGHTARG = anyelement
3487
);
3488

    
3489

    
3490
--
3491
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3492
--
3493

    
3494
CREATE OPERATOR ||% (
3495
    PROCEDURE = concat_esc,
3496
    LEFTARG = text,
3497
    RIGHTARG = text
3498
);
3499

    
3500

    
3501
--
3502
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3503
--
3504

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

    
3509

    
3510
--
3511
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3512
--
3513

    
3514
CREATE TABLE map (
3515
    "from" text NOT NULL,
3516
    "to" text,
3517
    filter text,
3518
    notes text
3519
);
3520

    
3521

    
3522
--
3523
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3524
--
3525

    
3526

    
3527

    
3528
--
3529
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3530
--
3531

    
3532

    
3533

    
3534
--
3535
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3536
--
3537

    
3538
ALTER TABLE ONLY map
3539
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3540

    
3541

    
3542
--
3543
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3544
--
3545

    
3546
ALTER TABLE ONLY map
3547
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3548

    
3549

    
3550
--
3551
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3552
--
3553

    
3554
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3555

    
3556

    
3557
--
3558
-- PostgreSQL database dump complete
3559
--
3560

    
(19-19/29)