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: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
929
--
930

    
931
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
932
    LANGUAGE sql
933
    AS $_$
934
SELECT util.materialize_view($2, $1)
935
$_$;
936

    
937

    
938
--
939
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
940
--
941

    
942
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
943
    LANGUAGE plpgsql STRICT
944
    AS $$
945
BEGIN
946
	PERFORM util.eval(sql);
947
EXCEPTION
948
WHEN duplicate_table THEN NULL;
949
WHEN duplicate_object THEN NULL; -- e.g. constraint
950
WHEN duplicate_column THEN NULL;
951
WHEN duplicate_function THEN NULL;
952
WHEN invalid_table_definition THEN
953
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
954
	ELSE RAISE;
955
	END IF;
956
END;
957
$$;
958

    
959

    
960
--
961
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
962
--
963

    
964
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
965
idempotent
966
';
967

    
968

    
969
--
970
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
971
--
972

    
973
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
974
    LANGUAGE sql STABLE
975
    AS $$
976
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
977
$$;
978

    
979

    
980
--
981
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
982
--
983

    
984
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
985
    LANGUAGE sql IMMUTABLE
986
    AS $_$
987
SELECT util.raise('NOTICE', 'returns: '
988
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
989
SELECT $1;
990
$_$;
991

    
992

    
993
--
994
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
995
--
996

    
997
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
998
    LANGUAGE sql IMMUTABLE
999
    AS $_$
1000
/* newline before so the query starts at the beginning of the line.
1001
newline after to visually separate queries from one another. */
1002
SELECT util.raise('NOTICE', $$
1003
$$||util.runnable_sql($1)||$$
1004
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1005
$_$;
1006

    
1007

    
1008
--
1009
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1010
--
1011

    
1012
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1013
    LANGUAGE sql STABLE
1014
    AS $_$
1015
SELECT util.eval2set($$
1016
SELECT col
1017
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1018
LEFT JOIN $$||$2||$$ ON "to" = col
1019
WHERE "from" IS NULL
1020
$$, NULL::text)
1021
$_$;
1022

    
1023

    
1024
--
1025
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1026
--
1027

    
1028
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1029
gets table_''s derived columns (all the columns not in the names table)
1030
';
1031

    
1032

    
1033
--
1034
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1035
--
1036

    
1037
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1038
    LANGUAGE sql
1039
    AS $_$
1040
SELECT * FROM util.diff($1::text, $2::text, $3,
1041
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1042
$_$;
1043

    
1044

    
1045
--
1046
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1047
--
1048

    
1049
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1050
col_type_null (*required*): NULL::shared_base_type
1051
usage:
1052
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1053
';
1054

    
1055

    
1056
--
1057
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1058
--
1059

    
1060
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1061
    LANGUAGE plpgsql
1062
    SET search_path TO pg_temp
1063
    AS $_$
1064
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1065
changes of search_path (schema elements are bound at inline time rather than
1066
runtime) */
1067
/* function option search_path is needed to limit the effects of
1068
`SET LOCAL search_path` to the current function */
1069
BEGIN
1070
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1071
	
1072
	PERFORM util.mk_keys_func(pg_typeof($3));
1073
	RETURN QUERY
1074
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1075
$$/* need to explicitly cast each side to the return type because this does not
1076
happen automatically even when an implicit cast is available */
1077
  left_::$$||util.typeof($3)||$$
1078
, right_::$$||util.typeof($3)
1079
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1080
the *same* base type, *even though* this is optional when using a custom %== */
1081
, util._if($4, $$true/*= CROSS JOIN*/$$,
1082
$$ left_::$$||util.typeof($3)||$$
1083
%== right_::$$||util.typeof($3)||$$
1084
	-- refer to EXPLAIN output for expansion of %==$$
1085
)), $3)
1086
	;
1087
END;
1088
$_$;
1089

    
1090

    
1091
--
1092
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1093
--
1094

    
1095
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1096
col_type_null (*required*): NULL::col_type
1097
single_row: whether the tables consist of a single row, which should be
1098
	displayed side-by-side
1099

    
1100
to match up rows using a subset of the columns, create a custom keys() function
1101
which returns this subset as a record:
1102
-- note that OUT parameters for the returned fields are *not* needed
1103
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1104
  RETURNS record AS
1105
$BODY$
1106
SELECT ($1.key_field_0, $1.key_field_1)
1107
$BODY$
1108
  LANGUAGE sql IMMUTABLE
1109
  COST 100;
1110

    
1111

    
1112
to run EXPLAIN on the FULL JOIN query:
1113
# run this function
1114
# look for a NOTICE containing the expanded query that it ran
1115
# run EXPLAIN on this expanded query
1116
';
1117

    
1118

    
1119
--
1120
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1121
--
1122

    
1123
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1124
    LANGUAGE sql
1125
    AS $_$
1126
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1127
$_$;
1128

    
1129

    
1130
--
1131
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1132
--
1133

    
1134
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1135
idempotent
1136
';
1137

    
1138

    
1139
--
1140
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1141
--
1142

    
1143
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1144
    LANGUAGE sql
1145
    AS $_$
1146
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1147
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1148
$_$;
1149

    
1150

    
1151
--
1152
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1153
--
1154

    
1155
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1156
idempotent
1157
';
1158

    
1159

    
1160
--
1161
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1162
--
1163

    
1164
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1165
    LANGUAGE sql
1166
    AS $_$
1167
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1168
included in the debug SQL */
1169
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1170
$_$;
1171

    
1172

    
1173
--
1174
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1175
--
1176

    
1177
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1178
    LANGUAGE sql
1179
    AS $_$
1180
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1181
||util._if($3, $$ CASCADE$$, ''::text))
1182
$_$;
1183

    
1184

    
1185
--
1186
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1187
--
1188

    
1189
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1190
idempotent
1191
';
1192

    
1193

    
1194
--
1195
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1196
--
1197

    
1198
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1199
    LANGUAGE sql
1200
    AS $_$
1201
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1202
$_$;
1203

    
1204

    
1205
--
1206
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1207
--
1208

    
1209
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1210
    LANGUAGE sql
1211
    AS $_$
1212
SELECT util.drop_relation(relation, $3)
1213
FROM util.show_relations_like($1, $2) relation
1214
;
1215
SELECT NULL::void; -- don't fold away functions called in previous query
1216
$_$;
1217

    
1218

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

    
1223
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1224
    LANGUAGE sql
1225
    AS $_$
1226
SELECT util.drop_relation('TABLE', $1, $2)
1227
$_$;
1228

    
1229

    
1230
--
1231
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1232
--
1233

    
1234
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1235
idempotent
1236
';
1237

    
1238

    
1239
--
1240
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1241
--
1242

    
1243
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1244
    LANGUAGE sql
1245
    AS $_$
1246
SELECT util.drop_relation('VIEW', $1, $2)
1247
$_$;
1248

    
1249

    
1250
--
1251
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1252
--
1253

    
1254
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1255
idempotent
1256
';
1257

    
1258

    
1259
--
1260
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1261
--
1262

    
1263
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1264
    LANGUAGE sql IMMUTABLE
1265
    AS $_$
1266
SELECT util.array_fill($1, 0)
1267
$_$;
1268

    
1269

    
1270
--
1271
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1272
--
1273

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

    
1278

    
1279
--
1280
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1281
--
1282

    
1283
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1284
    LANGUAGE sql IMMUTABLE
1285
    AS $_$
1286
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1287
$_$;
1288

    
1289

    
1290
--
1291
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1292
--
1293

    
1294
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1295
    LANGUAGE sql IMMUTABLE
1296
    AS $_$
1297
SELECT regexp_replace($2, '("?)$', $1||'\1')
1298
$_$;
1299

    
1300

    
1301
--
1302
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1303
--
1304

    
1305
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1306
    LANGUAGE plpgsql
1307
    AS $$
1308
BEGIN
1309
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1310
	EXECUTE sql;
1311
END;
1312
$$;
1313

    
1314

    
1315
--
1316
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1317
--
1318

    
1319
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1320
    LANGUAGE plpgsql
1321
    AS $$
1322
BEGIN
1323
	PERFORM util.debug_print_sql(sql);
1324
	RETURN QUERY EXECUTE sql;
1325
END;
1326
$$;
1327

    
1328

    
1329
--
1330
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1331
--
1332

    
1333
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1334
col_type_null (*required*): NULL::col_type
1335
';
1336

    
1337

    
1338
--
1339
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1340
--
1341

    
1342
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1343
    LANGUAGE plpgsql
1344
    AS $$
1345
BEGIN
1346
	PERFORM util.debug_print_sql(sql);
1347
	RETURN QUERY EXECUTE sql;
1348
END;
1349
$$;
1350

    
1351

    
1352
--
1353
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1354
--
1355

    
1356
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1357
    LANGUAGE plpgsql
1358
    AS $$
1359
BEGIN
1360
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1361
	RETURN QUERY EXECUTE sql;
1362
END;
1363
$$;
1364

    
1365

    
1366
--
1367
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1368
--
1369

    
1370
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1371
    LANGUAGE plpgsql STABLE
1372
    AS $$
1373
DECLARE
1374
	ret_val ret_type_null%TYPE;
1375
BEGIN
1376
	PERFORM util.debug_print_sql(sql);
1377
	EXECUTE sql INTO STRICT ret_val;
1378
	RETURN ret_val;
1379
END;
1380
$$;
1381

    
1382

    
1383
--
1384
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1385
--
1386

    
1387
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1388
ret_type_null: NULL::ret_type
1389
';
1390

    
1391

    
1392
--
1393
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1394
--
1395

    
1396
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1397
    LANGUAGE sql
1398
    AS $_$
1399
SELECT util.eval2val($$SELECT $$||$1, $2)
1400
$_$;
1401

    
1402

    
1403
--
1404
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1405
--
1406

    
1407
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1408
ret_type_null: NULL::ret_type
1409
';
1410

    
1411

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

    
1416
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1417
    LANGUAGE sql
1418
    AS $_$
1419
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1420
$_$;
1421

    
1422

    
1423
--
1424
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1425
--
1426

    
1427
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1428
sql: can be NULL, which will be passed through
1429
ret_type_null: NULL::ret_type
1430
';
1431

    
1432

    
1433
--
1434
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1435
--
1436

    
1437
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1438
    LANGUAGE sql STABLE
1439
    AS $_$
1440
SELECT col_name
1441
FROM unnest($2) s (col_name)
1442
WHERE util.col_exists(($1, col_name))
1443
$_$;
1444

    
1445

    
1446
--
1447
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1448
--
1449

    
1450
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1451
    LANGUAGE sql
1452
    AS $_$
1453
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1454
$_$;
1455

    
1456

    
1457
--
1458
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1459
--
1460

    
1461
CREATE FUNCTION explain2notice(sql text) RETURNS void
1462
    LANGUAGE sql
1463
    AS $_$
1464
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1465
$_$;
1466

    
1467

    
1468
--
1469
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1470
--
1471

    
1472
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1473
    LANGUAGE sql
1474
    AS $_$
1475
-- newline before and after to visually separate it from other debug info
1476
SELECT $$
1477
EXPLAIN:
1478
$$||util.explain2str($1)||$$
1479
$$
1480
$_$;
1481

    
1482

    
1483
--
1484
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1485
--
1486

    
1487
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1488
    LANGUAGE sql
1489
    AS $_$
1490
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1491
$_$;
1492

    
1493

    
1494
--
1495
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1496
--
1497

    
1498
CREATE FUNCTION explain2str(sql text) RETURNS text
1499
    LANGUAGE sql
1500
    AS $_$
1501
SELECT util.join_strs(explain, $$
1502
$$) FROM util.explain($1)
1503
$_$;
1504

    
1505

    
1506
SET default_tablespace = '';
1507

    
1508
SET default_with_oids = false;
1509

    
1510
--
1511
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1512
--
1513

    
1514
CREATE TABLE explain (
1515
    line text NOT NULL
1516
);
1517

    
1518

    
1519
--
1520
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522

    
1523
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1524
    LANGUAGE sql
1525
    AS $_$
1526
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1527
$$||quote_nullable($1)||$$
1528
)$$)
1529
$_$;
1530

    
1531

    
1532
--
1533
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1534
--
1535

    
1536
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1537
usage:
1538
PERFORM util.explain2table($$
1539
query
1540
$$);
1541
';
1542

    
1543

    
1544
--
1545
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1546
--
1547

    
1548
CREATE FUNCTION first_word(str text) RETURNS text
1549
    LANGUAGE sql IMMUTABLE
1550
    AS $_$
1551
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1552
$_$;
1553

    
1554

    
1555
--
1556
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1557
--
1558

    
1559
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1560
    LANGUAGE sql IMMUTABLE
1561
    AS $_$
1562
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1563
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1564
) END
1565
$_$;
1566

    
1567

    
1568
--
1569
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1570
--
1571

    
1572
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1573
ensures that an array will always have proper non-NULL dimensions
1574
';
1575

    
1576

    
1577
--
1578
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1579
--
1580

    
1581
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1582
    LANGUAGE plpgsql
1583
    AS $_$
1584
DECLARE
1585
	PG_EXCEPTION_DETAIL text;
1586
	recreate_users_cmd text = util.save_drop_views(users);
1587
BEGIN
1588
	PERFORM util.eval(cmd);
1589
	PERFORM util.eval(recreate_users_cmd);
1590
EXCEPTION
1591
WHEN dependent_objects_still_exist THEN
1592
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1593
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1594
	users = array(SELECT * FROM util.regexp_matches_group(
1595
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1596
	IF util.is_empty(users) THEN RAISE; END IF;
1597
	PERFORM util.force_recreate(cmd, users);
1598
END;
1599
$_$;
1600

    
1601

    
1602
--
1603
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1604
--
1605

    
1606
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1607
idempotent
1608

    
1609
users: not necessary to provide this because it will be autopopulated
1610
';
1611

    
1612

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

    
1617
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1618
    LANGUAGE plpgsql STRICT
1619
    AS $_$
1620
DECLARE
1621
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1622
$$||query;
1623
BEGIN
1624
	EXECUTE mk_view;
1625
EXCEPTION
1626
WHEN invalid_table_definition THEN
1627
	IF SQLERRM = 'cannot drop columns from view'
1628
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1629
	THEN
1630
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1631
		EXECUTE mk_view;
1632
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1633
	END IF;
1634
END;
1635
$_$;
1636

    
1637

    
1638
--
1639
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1640
--
1641

    
1642
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1643
idempotent
1644
';
1645

    
1646

    
1647
--
1648
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1649
--
1650

    
1651
CREATE FUNCTION grants_users() RETURNS SETOF text
1652
    LANGUAGE sql IMMUTABLE
1653
    AS $$
1654
VALUES ('bien_read'), ('public_')
1655
$$;
1656

    
1657

    
1658
--
1659
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1660
--
1661

    
1662
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1663
    LANGUAGE sql IMMUTABLE
1664
    AS $_$
1665
SELECT substring($2 for length($1)) = $1
1666
$_$;
1667

    
1668

    
1669
--
1670
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1671
--
1672

    
1673
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1674
    LANGUAGE sql STABLE
1675
    AS $_$
1676
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1677
$_$;
1678

    
1679

    
1680
--
1681
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1682
--
1683

    
1684
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1685
    LANGUAGE sql IMMUTABLE
1686
    AS $_$
1687
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1688
$_$;
1689

    
1690

    
1691
--
1692
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1693
--
1694

    
1695
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1696
avoids repeating the same value for each key
1697
';
1698

    
1699

    
1700
--
1701
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1702
--
1703

    
1704
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1705
    LANGUAGE sql IMMUTABLE
1706
    AS $_$
1707
SELECT COALESCE($1, $2)
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1713
--
1714

    
1715
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1716
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1717
';
1718

    
1719

    
1720
--
1721
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1722
--
1723

    
1724
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1725
    LANGUAGE sql
1726
    AS $_$
1727
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1728
$_$;
1729

    
1730

    
1731
--
1732
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1733
--
1734

    
1735
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1736
    LANGUAGE sql STABLE
1737
    AS $_$
1738
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1739
$_$;
1740

    
1741

    
1742
--
1743
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1744
--
1745

    
1746
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1747
    LANGUAGE sql IMMUTABLE
1748
    AS $_$
1749
SELECT util.array_length($1) = 0
1750
$_$;
1751

    
1752

    
1753
--
1754
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1755
--
1756

    
1757
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1758
    LANGUAGE sql IMMUTABLE
1759
    AS $_$
1760
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1761
$_$;
1762

    
1763

    
1764
--
1765
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767

    
1768
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1769
    LANGUAGE sql IMMUTABLE
1770
    AS $_$
1771
SELECT upper(util.first_word($1)) = ANY(
1772
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1773
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1774
)
1775
$_$;
1776

    
1777

    
1778
--
1779
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1780
--
1781

    
1782
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1783
    LANGUAGE sql IMMUTABLE
1784
    AS $_$
1785
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1786
$_$;
1787

    
1788

    
1789
--
1790
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1791
--
1792

    
1793
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1794
    LANGUAGE sql IMMUTABLE
1795
    AS $_$
1796
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1797
$_$;
1798

    
1799

    
1800
--
1801
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1802
--
1803

    
1804
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1805
    LANGUAGE sql IMMUTABLE
1806
    AS $_$
1807
SELECT upper(util.first_word($1)) = 'SET'
1808
$_$;
1809

    
1810

    
1811
--
1812
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1813
--
1814

    
1815
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1816
    LANGUAGE sql STABLE
1817
    AS $_$
1818
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1819
$_$;
1820

    
1821

    
1822
--
1823
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1824
--
1825

    
1826
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1827
    LANGUAGE sql STABLE
1828
    AS $_$
1829
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1830
$_$;
1831

    
1832

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

    
1837
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1838
    LANGUAGE sql IMMUTABLE STRICT
1839
    AS $_$
1840
SELECT $1 || $3 || $2
1841
$_$;
1842

    
1843

    
1844
--
1845
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1846
--
1847

    
1848
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1849
must be declared STRICT to use the special handling of STRICT aggregating functions
1850
';
1851

    
1852

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

    
1857
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1858
    LANGUAGE sql IMMUTABLE
1859
    AS $_$
1860
SELECT $1 -- compare on the entire value
1861
$_$;
1862

    
1863

    
1864
--
1865
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1866
--
1867

    
1868
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1869
    LANGUAGE sql IMMUTABLE
1870
    AS $_$
1871
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1872
$_$;
1873

    
1874

    
1875
--
1876
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1877
--
1878

    
1879
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1880
    LANGUAGE sql IMMUTABLE
1881
    AS $_$
1882
SELECT ltrim($1, $$
1883
$$)
1884
$_$;
1885

    
1886

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

    
1891
CREATE FUNCTION map_filter_insert() RETURNS trigger
1892
    LANGUAGE plpgsql
1893
    AS $$
1894
BEGIN
1895
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1896
	RETURN new;
1897
END;
1898
$$;
1899

    
1900

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

    
1905
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1906
    LANGUAGE plpgsql STABLE STRICT
1907
    AS $_$
1908
DECLARE
1909
    value text;
1910
BEGIN
1911
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1912
        INTO value USING key;
1913
    RETURN value;
1914
END;
1915
$_$;
1916

    
1917

    
1918
--
1919
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1920
--
1921

    
1922
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1923
    LANGUAGE sql IMMUTABLE
1924
    AS $_$
1925
SELECT util._map(util.nulls_map($1), $2)
1926
$_$;
1927

    
1928

    
1929
--
1930
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1931
--
1932

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

    
1936
[1] inlining of function calls, which is different from constant folding
1937
[2] _map()''s profiling query
1938
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1939
and map_nulls()''s profiling query
1940
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1941
both take ~920 ms.
1942
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.
1943
';
1944

    
1945

    
1946
--
1947
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1948
--
1949

    
1950
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1951
    LANGUAGE plpgsql STABLE STRICT
1952
    AS $_$
1953
BEGIN
1954
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1955
END;
1956
$_$;
1957

    
1958

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

    
1963
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1964
    LANGUAGE sql
1965
    AS $_$
1966
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1967
$$||util.ltrim_nl($2));
1968
-- make sure the created table has the correct estimated row count
1969
SELECT util.analyze_($1);
1970

    
1971
SELECT util.append_comment($1, '
1972
contents generated from:
1973
'||util.ltrim_nl($2)||';
1974
');
1975
$_$;
1976

    
1977

    
1978
--
1979
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1980
--
1981

    
1982
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1983
idempotent
1984
';
1985

    
1986

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

    
1991
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1992
    LANGUAGE sql
1993
    AS $_$
1994
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1995
$_$;
1996

    
1997

    
1998
--
1999
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2000
--
2001

    
2002
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2003
idempotent
2004
';
2005

    
2006

    
2007
--
2008
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2009
--
2010

    
2011
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2012
    LANGUAGE sql
2013
    AS $_$
2014
SELECT util.create_if_not_exists($$
2015
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2016
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2017
||quote_literal($2)||$$;
2018
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2019
constant
2020
';
2021
$$)
2022
$_$;
2023

    
2024

    
2025
--
2026
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2027
--
2028

    
2029
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2030
idempotent
2031
';
2032

    
2033

    
2034
--
2035
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2036
--
2037

    
2038
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2039
    LANGUAGE plpgsql STRICT
2040
    AS $_$
2041
DECLARE
2042
    type regtype = util.typeof(expr, col.table_::text::regtype);
2043
    col_name_sql text = quote_ident(col.name);
2044
BEGIN
2045
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2046
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2047
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2048
$$||expr||$$;
2049
$$);
2050
END;
2051
$_$;
2052

    
2053

    
2054
--
2055
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2056
--
2057

    
2058
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2059
idempotent
2060
';
2061

    
2062

    
2063
--
2064
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2065
--
2066

    
2067
CREATE FUNCTION mk_diff_query(left_ text, right_ text, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2068
    LANGUAGE sql IMMUTABLE
2069
    AS $_$
2070
SELECT
2071
$$SELECT
2072
$$||$3||$$
2073
FROM      $$||$1||$$ left_
2074
FULL JOIN $$||$2||$$ right_
2075
ON $$||$4||$$
2076
WHERE $$||$5||$$
2077
ORDER BY left_, right_
2078
$$
2079
$_$;
2080

    
2081

    
2082
--
2083
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2084
--
2085

    
2086
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2087
    LANGUAGE sql
2088
    AS $_$
2089
-- keys()
2090
SELECT util.mk_keys_func($1, ARRAY(
2091
SELECT col FROM util.typed_cols($1) col
2092
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2093
));
2094

    
2095
-- values_()
2096
SELECT util.mk_keys_func($1, COALESCE(
2097
	NULLIF(ARRAY(
2098
	SELECT col FROM util.typed_cols($1) col
2099
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2100
	), ARRAY[]::util.col_cast[])
2101
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2102
, 'values_');
2103
$_$;
2104

    
2105

    
2106
--
2107
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2108
--
2109

    
2110
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2111
    LANGUAGE sql
2112
    AS $_$
2113
SELECT util.create_if_not_exists($$
2114
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2115
($$||util.mk_typed_cols_list($2)||$$);
2116
$$);
2117

    
2118
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2119
$_$;
2120

    
2121

    
2122
--
2123
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2124
--
2125

    
2126
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2127
    LANGUAGE sql
2128
    AS $_$
2129
SELECT util.create_if_not_exists($$
2130
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2131
||util.qual_name($1)||$$)
2132
  RETURNS $$||util.qual_name($2)||$$ AS
2133
$BODY1$
2134
SELECT ROW($$||
2135
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2136
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2137
$BODY1$
2138
  LANGUAGE sql IMMUTABLE
2139
  COST 100;
2140
$$);
2141
$_$;
2142

    
2143

    
2144
--
2145
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2146
--
2147

    
2148
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2149
    LANGUAGE sql
2150
    AS $_$
2151
SELECT util.create_if_not_exists($$
2152
CREATE TABLE $$||$1||$$
2153
(
2154
    LIKE util.map INCLUDING ALL
2155
);
2156

    
2157
CREATE TRIGGER map_filter_insert
2158
  BEFORE INSERT
2159
  ON $$||$1||$$
2160
  FOR EACH ROW
2161
  EXECUTE PROCEDURE util.map_filter_insert();
2162
$$)
2163
$_$;
2164

    
2165

    
2166
--
2167
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2168
--
2169

    
2170
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2171
    LANGUAGE sql IMMUTABLE
2172
    AS $_$
2173
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2174
util.qual_name((unnest).type), ''), '')
2175
FROM unnest($1)
2176
$_$;
2177

    
2178

    
2179
--
2180
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2181
--
2182

    
2183
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2184
    LANGUAGE sql IMMUTABLE
2185
    AS $_$
2186
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2187
$_$;
2188

    
2189

    
2190
--
2191
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2192
--
2193

    
2194
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2195
auto-appends util to the search_path to enable use of util operators
2196
';
2197

    
2198

    
2199
--
2200
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2201
--
2202

    
2203
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2204
    LANGUAGE sql IMMUTABLE
2205
    AS $_$
2206
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2207
$_$;
2208

    
2209

    
2210
--
2211
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2212
--
2213

    
2214
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2215
    LANGUAGE sql IMMUTABLE
2216
    AS $_$
2217
/* debug_print_return_value() needed because this function is used with EXECUTE
2218
rather than util.eval() (in order to affect the calling function), so the
2219
search_path would not otherwise be printed */
2220
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2221
||$$ search_path TO $$||$1
2222
$_$;
2223

    
2224

    
2225
--
2226
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2227
--
2228

    
2229
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2230
    LANGUAGE sql
2231
    AS $_$
2232
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2233
$_$;
2234

    
2235

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

    
2240
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2241
idempotent
2242
';
2243

    
2244

    
2245
--
2246
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2247
--
2248

    
2249
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2250
    LANGUAGE plpgsql STRICT
2251
    AS $_$
2252
DECLARE
2253
	view_qual_name text = util.qual_name(view_);
2254
BEGIN
2255
	EXECUTE $$
2256
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2257
  RETURNS SETOF $$||view_||$$ AS
2258
$BODY1$
2259
SELECT * FROM $$||view_qual_name||$$
2260
ORDER BY sort_col
2261
LIMIT $1 OFFSET $2
2262
$BODY1$
2263
  LANGUAGE sql STABLE
2264
  COST 100
2265
  ROWS 1000
2266
$$;
2267
	
2268
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2269
END;
2270
$_$;
2271

    
2272

    
2273
--
2274
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2278
    LANGUAGE plpgsql STRICT
2279
    AS $_$
2280
DECLARE
2281
	view_qual_name text = util.qual_name(view_);
2282
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2283
BEGIN
2284
	EXECUTE $$
2285
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2286
  RETURNS integer AS
2287
$BODY1$
2288
SELECT $$||quote_ident(row_num_col)||$$
2289
FROM $$||view_qual_name||$$
2290
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2291
LIMIT 1
2292
$BODY1$
2293
  LANGUAGE sql STABLE
2294
  COST 100;
2295
$$;
2296
	
2297
	EXECUTE $$
2298
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2299
  RETURNS SETOF $$||view_||$$ AS
2300
$BODY1$
2301
SELECT * FROM $$||view_qual_name||$$
2302
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2303
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2304
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2305
ORDER BY $$||quote_ident(row_num_col)||$$
2306
$BODY1$
2307
  LANGUAGE sql STABLE
2308
  COST 100
2309
  ROWS 1000
2310
$$;
2311
	
2312
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2313
END;
2314
$_$;
2315

    
2316

    
2317
--
2318
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2319
--
2320

    
2321
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2322
    LANGUAGE plpgsql STRICT
2323
    AS $_$
2324
DECLARE
2325
	view_qual_name text = util.qual_name(view_);
2326
BEGIN
2327
	EXECUTE $$
2328
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2329
  RETURNS SETOF $$||view_||$$
2330
  SET enable_sort TO 'off'
2331
  AS
2332
$BODY1$
2333
SELECT * FROM $$||view_qual_name||$$($2, $3)
2334
$BODY1$
2335
  LANGUAGE sql STABLE
2336
  COST 100
2337
  ROWS 1000
2338
;
2339
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2340
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2341
If you want to run EXPLAIN and get expanded output, use the regular subset
2342
function instead. (When a config param is set on a function, EXPLAIN produces
2343
just a function scan.)
2344
';
2345
$$;
2346
END;
2347
$_$;
2348

    
2349

    
2350
--
2351
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2352
--
2353

    
2354
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2355
creates subset function which turns off enable_sort
2356
';
2357

    
2358

    
2359
--
2360
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2361
--
2362

    
2363
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2364
    LANGUAGE sql IMMUTABLE
2365
    AS $_$
2366
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2367
util.qual_name((unnest).type), ', '), '')
2368
FROM unnest($1)
2369
$_$;
2370

    
2371

    
2372
--
2373
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2374
--
2375

    
2376
CREATE FUNCTION name(table_ regclass) RETURNS text
2377
    LANGUAGE sql STABLE
2378
    AS $_$
2379
SELECT relname::text FROM pg_class WHERE oid = $1
2380
$_$;
2381

    
2382

    
2383
--
2384
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2385
--
2386

    
2387
CREATE FUNCTION name(type regtype) RETURNS text
2388
    LANGUAGE sql STABLE
2389
    AS $_$
2390
SELECT typname::text FROM pg_type WHERE oid = $1
2391
$_$;
2392

    
2393

    
2394
--
2395
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2396
--
2397

    
2398
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2399
    LANGUAGE sql IMMUTABLE
2400
    AS $_$
2401
SELECT octet_length($1) >= util.namedatalen() - $2
2402
$_$;
2403

    
2404

    
2405
--
2406
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2407
--
2408

    
2409
CREATE FUNCTION namedatalen() RETURNS integer
2410
    LANGUAGE sql IMMUTABLE
2411
    AS $$
2412
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2413
$$;
2414

    
2415

    
2416
--
2417
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2418
--
2419

    
2420
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2421
    LANGUAGE sql IMMUTABLE
2422
    AS $_$
2423
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2424
$_$;
2425

    
2426

    
2427
--
2428
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2429
--
2430

    
2431
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2432
    LANGUAGE sql IMMUTABLE
2433
    AS $_$
2434
SELECT $1 IS NOT NULL
2435
$_$;
2436

    
2437

    
2438
--
2439
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2440
--
2441

    
2442
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2443
    LANGUAGE sql IMMUTABLE
2444
    AS $_$
2445
SELECT util.hstore($1, NULL) || '*=>*'
2446
$_$;
2447

    
2448

    
2449
--
2450
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2451
--
2452

    
2453
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2454
for use with _map()
2455
';
2456

    
2457

    
2458
--
2459
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2460
--
2461

    
2462
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2463
    LANGUAGE sql IMMUTABLE
2464
    AS $_$
2465
SELECT $2 + COALESCE($1, 0)
2466
$_$;
2467

    
2468

    
2469
--
2470
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2471
--
2472

    
2473
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2474
    LANGUAGE sql IMMUTABLE
2475
    AS $_$
2476
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2477
$_$;
2478

    
2479

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

    
2484
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2485
    LANGUAGE sql
2486
    AS $_$
2487
SELECT util.set_comment($1, concat($2, util.comment($1)))
2488
$_$;
2489

    
2490

    
2491
--
2492
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2493
--
2494

    
2495
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2496
comment: must start and end with a newline
2497
';
2498

    
2499

    
2500
--
2501
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2502
--
2503

    
2504
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2505
    LANGUAGE sql IMMUTABLE
2506
    AS $_$
2507
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2508
$_$;
2509

    
2510

    
2511
--
2512
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2513
--
2514

    
2515
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2516
    LANGUAGE sql STABLE
2517
    SET search_path TO pg_temp
2518
    AS $_$
2519
SELECT $1::text
2520
$_$;
2521

    
2522

    
2523
--
2524
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2525
--
2526

    
2527
CREATE FUNCTION qual_name(type regtype) RETURNS text
2528
    LANGUAGE sql STABLE
2529
    SET search_path TO pg_temp
2530
    AS $_$
2531
SELECT $1::text
2532
$_$;
2533

    
2534

    
2535
--
2536
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2537
--
2538

    
2539
COMMENT ON FUNCTION qual_name(type regtype) IS '
2540
a type''s schema-qualified name
2541
';
2542

    
2543

    
2544
--
2545
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2546
--
2547

    
2548
CREATE FUNCTION qual_name(type unknown) RETURNS text
2549
    LANGUAGE sql STABLE
2550
    AS $_$
2551
SELECT util.qual_name($1::text::regtype)
2552
$_$;
2553

    
2554

    
2555
--
2556
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2557
--
2558

    
2559
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2560
    LANGUAGE sql IMMUTABLE
2561
    AS $_$
2562
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2563
$_$;
2564

    
2565

    
2566
--
2567
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2568
--
2569

    
2570
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2571
    LANGUAGE sql IMMUTABLE
2572
    AS $_$
2573
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2574
$_$;
2575

    
2576

    
2577
--
2578
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2579
--
2580

    
2581
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2582
    LANGUAGE sql IMMUTABLE
2583
    AS $_$
2584
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2585
$_$;
2586

    
2587

    
2588
--
2589
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2590
--
2591

    
2592
CREATE FUNCTION raise(type text, msg text) RETURNS void
2593
    LANGUAGE sql IMMUTABLE
2594
    AS $_X$
2595
SELECT util.eval($$
2596
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2597
  RETURNS void AS
2598
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2599
$__BODY1$
2600
BEGIN
2601
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2602
END;
2603
$__BODY1$
2604
  LANGUAGE plpgsql IMMUTABLE
2605
  COST 100;
2606
$$, verbose_ := false);
2607

    
2608
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2609
$_X$;
2610

    
2611

    
2612
--
2613
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2614
--
2615

    
2616
COMMENT ON FUNCTION raise(type text, msg text) IS '
2617
type: a log level from
2618
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2619
or a condition name from
2620
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2621
';
2622

    
2623

    
2624
--
2625
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2626
--
2627

    
2628
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2629
    LANGUAGE sql IMMUTABLE
2630
    AS $_$
2631
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2632
$_$;
2633

    
2634

    
2635
--
2636
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2637
--
2638

    
2639
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2640
    LANGUAGE plpgsql IMMUTABLE STRICT
2641
    AS $$
2642
BEGIN
2643
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2644
END;
2645
$$;
2646

    
2647

    
2648
--
2649
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2650
--
2651

    
2652
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2653
    LANGUAGE sql IMMUTABLE
2654
    AS $_$
2655
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2656
$_$;
2657

    
2658

    
2659
--
2660
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2661
--
2662

    
2663
CREATE FUNCTION regexp_quote(str text) RETURNS text
2664
    LANGUAGE sql IMMUTABLE
2665
    AS $_$
2666
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2667
$_$;
2668

    
2669

    
2670
--
2671
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2672
--
2673

    
2674
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2675
    LANGUAGE sql IMMUTABLE
2676
    AS $_$
2677
SELECT (CASE WHEN right($1, 1) = ')'
2678
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2679
$_$;
2680

    
2681

    
2682
--
2683
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2684
--
2685

    
2686
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2687
    LANGUAGE sql STABLE
2688
    AS $_$
2689
SELECT util.relation_type(util.relation_type_char($1))
2690
$_$;
2691

    
2692

    
2693
--
2694
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2695
--
2696

    
2697
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2698
    LANGUAGE sql IMMUTABLE
2699
    AS $_$
2700
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2701
$_$;
2702

    
2703

    
2704
--
2705
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2706
--
2707

    
2708
CREATE FUNCTION relation_type(type regtype) RETURNS text
2709
    LANGUAGE sql IMMUTABLE
2710
    AS $$
2711
SELECT 'TYPE'::text
2712
$$;
2713

    
2714

    
2715
--
2716
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2717
--
2718

    
2719
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2720
    LANGUAGE sql STABLE
2721
    AS $_$
2722
SELECT relkind FROM pg_class WHERE oid = $1
2723
$_$;
2724

    
2725

    
2726
--
2727
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2728
--
2729

    
2730
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2731
    LANGUAGE sql
2732
    AS $_$
2733
/* can't have in_table/out_table inherit from *each other*, because inheritance
2734
also causes the rows of the parent table to be included in the child table.
2735
instead, they need to inherit from a common, empty table. */
2736
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2737
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2738
SELECT util.inherit($2, $4);
2739
SELECT util.inherit($3, $4);
2740

    
2741
SELECT util.rematerialize_query($1, $$
2742
SELECT * FROM util.diff(
2743
  $$||util.quote_typed($2)||$$
2744
, $$||util.quote_typed($3)||$$
2745
, NULL::$$||$4||$$)
2746
$$);
2747

    
2748
/* the table unfortunately cannot be *materialized* in human-readable form,
2749
because this would create column name collisions between the two sides */
2750
SELECT util.prepend_comment($1, '
2751
to view this table in human-readable form (with each side''s tuple column
2752
expanded to its component fields):
2753
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2754
');
2755
$_$;
2756

    
2757

    
2758
--
2759
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2760
--
2761

    
2762
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2763
type_table (*required*): table to create as the shared base type
2764
';
2765

    
2766

    
2767
--
2768
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2769
--
2770

    
2771
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2772
    LANGUAGE sql
2773
    AS $_$
2774
SELECT util.drop_table($1);
2775
SELECT util.materialize_query($1, $2);
2776
$_$;
2777

    
2778

    
2779
--
2780
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2781
--
2782

    
2783
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2784
idempotent, but repeats action each time
2785
';
2786

    
2787

    
2788
--
2789
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2790
--
2791

    
2792
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2793
    LANGUAGE sql
2794
    AS $_$
2795
SELECT util.drop_table($1);
2796
SELECT util.materialize_view($1, $2);
2797
$_$;
2798

    
2799

    
2800
--
2801
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2802
--
2803

    
2804
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2805
idempotent, but repeats action each time
2806
';
2807

    
2808

    
2809
--
2810
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2811
--
2812

    
2813
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2814
    LANGUAGE sql
2815
    AS $_$
2816
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2817
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2818
FROM util.col_names($1::text::regtype) f (name);
2819
SELECT NULL::void; -- don't fold away functions called in previous query
2820
$_$;
2821

    
2822

    
2823
--
2824
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2825
--
2826

    
2827
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2828
idempotent
2829
';
2830

    
2831

    
2832
--
2833
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2834
--
2835

    
2836
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2837
    LANGUAGE sql
2838
    AS $_$
2839
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2840
included in the debug SQL */
2841
SELECT util.rename_relation(util.qual_name($1), $2)
2842
$_$;
2843

    
2844

    
2845
--
2846
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2847
--
2848

    
2849
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2850
    LANGUAGE sql
2851
    AS $_$
2852
/* 'ALTER TABLE can be used with views too'
2853
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2854
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2855
||quote_ident($2))
2856
$_$;
2857

    
2858

    
2859
--
2860
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2861
--
2862

    
2863
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2864
idempotent
2865
';
2866

    
2867

    
2868
--
2869
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2870
--
2871

    
2872
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2873
    LANGUAGE sql IMMUTABLE
2874
    AS $_$
2875
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2876
$_$;
2877

    
2878

    
2879
--
2880
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2881
--
2882

    
2883
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2884
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 
2885
';
2886

    
2887

    
2888
--
2889
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2890
--
2891

    
2892
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2893
    LANGUAGE sql
2894
    AS $_$
2895
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2896
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2897
SELECT util.set_col_names($1, $2);
2898
$_$;
2899

    
2900

    
2901
--
2902
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2903
--
2904

    
2905
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2906
idempotent.
2907
alters the names table, so it will need to be repopulated after running this function.
2908
';
2909

    
2910

    
2911
--
2912
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2913
--
2914

    
2915
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2916
    LANGUAGE sql
2917
    AS $_$
2918
SELECT util.drop_table($1);
2919
SELECT util.mk_map_table($1);
2920
$_$;
2921

    
2922

    
2923
--
2924
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2925
--
2926

    
2927
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2928
    LANGUAGE sql IMMUTABLE
2929
    AS $_$
2930
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2931
$_$;
2932

    
2933

    
2934
--
2935
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2936
--
2937

    
2938
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2939
    LANGUAGE sql IMMUTABLE
2940
    AS $_$
2941
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
2942
ELSE util.mk_set_search_path(for_printing := true)||$$;
2943
$$ END)||$1
2944
$_$;
2945

    
2946

    
2947
--
2948
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2949
--
2950

    
2951
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2952
    LANGUAGE plpgsql STRICT
2953
    AS $_$
2954
DECLARE
2955
	result text = NULL;
2956
BEGIN
2957
	BEGIN
2958
		result = util.show_create_view(view_);
2959
		PERFORM util.eval($$DROP VIEW $$||view_);
2960
	EXCEPTION
2961
		WHEN undefined_table THEN NULL;
2962
	END;
2963
	RETURN result;
2964
END;
2965
$_$;
2966

    
2967

    
2968
--
2969
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2970
--
2971

    
2972
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2973
    LANGUAGE sql
2974
    AS $_$
2975
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2976
$_$;
2977

    
2978

    
2979
--
2980
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2981
--
2982

    
2983
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2984
    LANGUAGE sql STABLE
2985
    AS $_$
2986
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2987
$_$;
2988

    
2989

    
2990
--
2991
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2992
--
2993

    
2994
CREATE FUNCTION schema(table_ regclass) RETURNS text
2995
    LANGUAGE sql STABLE
2996
    AS $_$
2997
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2998
$_$;
2999

    
3000

    
3001
--
3002
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3003
--
3004

    
3005
CREATE FUNCTION schema(type regtype) RETURNS text
3006
    LANGUAGE sql STABLE
3007
    AS $_$
3008
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3009
$_$;
3010

    
3011

    
3012
--
3013
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3014
--
3015

    
3016
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3017
    LANGUAGE sql STABLE
3018
    AS $_$
3019
SELECT util.schema(pg_typeof($1))
3020
$_$;
3021

    
3022

    
3023
--
3024
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3025
--
3026

    
3027
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3028
    LANGUAGE sql STABLE
3029
    AS $_$
3030
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3031
$_$;
3032

    
3033

    
3034
--
3035
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3036
--
3037

    
3038
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3039
a schema bundle is a group of schemas with a common prefix
3040
';
3041

    
3042

    
3043
--
3044
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3045
--
3046

    
3047
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3048
    LANGUAGE sql
3049
    AS $_$
3050
SELECT util.schema_rename(old_schema,
3051
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3052
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3053
SELECT NULL::void; -- don't fold away functions called in previous query
3054
$_$;
3055

    
3056

    
3057
--
3058
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3059
--
3060

    
3061
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3062
    LANGUAGE plpgsql
3063
    AS $$
3064
BEGIN
3065
	-- don't schema_bundle_rm() the schema_bundle to keep!
3066
	IF replace = with_ THEN RETURN; END IF;
3067
	
3068
	PERFORM util.schema_bundle_rm(replace);
3069
	PERFORM util.schema_bundle_rename(with_, replace);
3070
END;
3071
$$;
3072

    
3073

    
3074
--
3075
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3076
--
3077

    
3078
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3079
    LANGUAGE sql
3080
    AS $_$
3081
SELECT util.schema_rm(schema)
3082
FROM util.schema_bundle_get_schemas($1) f (schema);
3083
SELECT NULL::void; -- don't fold away functions called in previous query
3084
$_$;
3085

    
3086

    
3087
--
3088
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3089
--
3090

    
3091
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3092
    LANGUAGE sql STABLE
3093
    AS $_$
3094
SELECT quote_ident(util.schema($1))
3095
$_$;
3096

    
3097

    
3098
--
3099
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3100
--
3101

    
3102
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3103
    LANGUAGE sql IMMUTABLE
3104
    AS $_$
3105
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3106
$_$;
3107

    
3108

    
3109
--
3110
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3111
--
3112

    
3113
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3114
    LANGUAGE sql STABLE
3115
    AS $_$
3116
SELECT oid FROM pg_namespace WHERE nspname = $1
3117
$_$;
3118

    
3119

    
3120
--
3121
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3122
--
3123

    
3124
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3125
    LANGUAGE sql IMMUTABLE
3126
    AS $_$
3127
SELECT util.schema_regexp(schema_anchor := $1)
3128
$_$;
3129

    
3130

    
3131
--
3132
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3133
--
3134

    
3135
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3136
    LANGUAGE sql IMMUTABLE
3137
    AS $_$
3138
SELECT util.str_equality_regexp(util.schema($1))
3139
$_$;
3140

    
3141

    
3142
--
3143
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3144
--
3145

    
3146
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3147
    LANGUAGE sql
3148
    AS $_$
3149
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3150
$_$;
3151

    
3152

    
3153
--
3154
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3155
--
3156

    
3157
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3158
    LANGUAGE plpgsql
3159
    AS $$
3160
BEGIN
3161
	-- don't schema_rm() the schema to keep!
3162
	IF replace = with_ THEN RETURN; END IF;
3163
	
3164
	PERFORM util.schema_rm(replace);
3165
	PERFORM util.schema_rename(with_, replace);
3166
END;
3167
$$;
3168

    
3169

    
3170
--
3171
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3172
--
3173

    
3174
CREATE FUNCTION schema_rm(schema text) RETURNS void
3175
    LANGUAGE sql
3176
    AS $_$
3177
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3178
$_$;
3179

    
3180

    
3181
--
3182
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3183
--
3184

    
3185
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3186
    LANGUAGE sql
3187
    AS $_$
3188
SELECT util.eval(
3189
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3190
$_$;
3191

    
3192

    
3193
--
3194
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3195
--
3196

    
3197
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3198
    LANGUAGE plpgsql STRICT
3199
    AS $_$
3200
DECLARE
3201
    old text[] = ARRAY(SELECT util.col_names(table_));
3202
    new text[] = ARRAY(SELECT util.map_values(names));
3203
BEGIN
3204
    old = old[1:array_length(new, 1)]; -- truncate to same length
3205
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3206
||$$ TO $$||quote_ident(value))
3207
    FROM each(hstore(old, new))
3208
    WHERE value != key -- not same name
3209
    ;
3210
END;
3211
$_$;
3212

    
3213

    
3214
--
3215
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3216
--
3217

    
3218
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3219
idempotent
3220
';
3221

    
3222

    
3223
--
3224
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3225
--
3226

    
3227
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3228
    LANGUAGE plpgsql STRICT
3229
    AS $_$
3230
DECLARE
3231
	row_ util.map;
3232
BEGIN
3233
	-- rename any metadata cols rather than re-adding them with new names
3234
	BEGIN
3235
		PERFORM util.set_col_names(table_, names);
3236
	EXCEPTION
3237
		WHEN array_subscript_error THEN -- selective suppress
3238
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3239
				-- metadata cols not yet added
3240
			ELSE RAISE;
3241
			END IF;
3242
	END;
3243
	
3244
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3245
	LOOP
3246
		PERFORM util.mk_const_col((table_, row_."to"),
3247
			substring(row_."from" from 2));
3248
	END LOOP;
3249
	
3250
	PERFORM util.set_col_names(table_, names);
3251
END;
3252
$_$;
3253

    
3254

    
3255
--
3256
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3257
--
3258

    
3259
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3260
idempotent.
3261
the metadata mappings must be *last* in the names table.
3262
';
3263

    
3264

    
3265
--
3266
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3267
--
3268

    
3269
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3270
    LANGUAGE plpgsql STRICT
3271
    AS $_$
3272
DECLARE
3273
    sql text = $$ALTER TABLE $$||table_||$$
3274
$$||NULLIF(array_to_string(ARRAY(
3275
    SELECT
3276
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3277
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3278
    FROM
3279
    (
3280
        SELECT
3281
          quote_ident(col_name) AS col_name_sql
3282
        , util.col_type((table_, col_name)) AS curr_type
3283
        , type AS target_type
3284
        FROM unnest(col_casts)
3285
    ) s
3286
    WHERE curr_type != target_type
3287
), '
3288
, '), '');
3289
BEGIN
3290
    PERFORM util.debug_print_sql(sql);
3291
    EXECUTE COALESCE(sql, '');
3292
END;
3293
$_$;
3294

    
3295

    
3296
--
3297
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3298
--
3299

    
3300
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3301
idempotent
3302
';
3303

    
3304

    
3305
--
3306
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3307
--
3308

    
3309
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3310
    LANGUAGE sql
3311
    AS $_$
3312
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3313
$_$;
3314

    
3315

    
3316
--
3317
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3318
--
3319

    
3320
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3321
    LANGUAGE sql
3322
    AS $_$
3323
SELECT util.eval(util.mk_set_search_path($1, $2))
3324
$_$;
3325

    
3326

    
3327
--
3328
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3329
--
3330

    
3331
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3332
    LANGUAGE sql STABLE
3333
    AS $_$
3334
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3335
$$||util.show_grants_for($1)
3336
$_$;
3337

    
3338

    
3339
--
3340
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3341
--
3342

    
3343
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3344
    LANGUAGE sql STABLE
3345
    AS $_$
3346
SELECT string_agg(cmd, '')
3347
FROM
3348
(
3349
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3350
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3351
$$ ELSE '' END) AS cmd
3352
	FROM util.grants_users() f (user_)
3353
) s
3354
$_$;
3355

    
3356

    
3357
--
3358
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3359
--
3360

    
3361
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3362
    LANGUAGE sql STABLE
3363
    AS $_$
3364
SELECT oid FROM pg_class
3365
WHERE relkind = ANY($3) AND relname ~ $1
3366
AND util.schema_matches(util.schema(relnamespace), $2)
3367
ORDER BY relname
3368
$_$;
3369

    
3370

    
3371
--
3372
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3373
--
3374

    
3375
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3376
    LANGUAGE sql STABLE
3377
    AS $_$
3378
SELECT oid
3379
FROM pg_type
3380
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3381
ORDER BY typname
3382
$_$;
3383

    
3384

    
3385
--
3386
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3387
--
3388

    
3389
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3390
    LANGUAGE sql STABLE
3391
    AS $_$
3392
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3393
$_$;
3394

    
3395

    
3396
--
3397
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3398
--
3399

    
3400
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3401
    LANGUAGE sql IMMUTABLE
3402
    AS $_$
3403
SELECT '^'||util.regexp_quote($1)||'$'
3404
$_$;
3405

    
3406

    
3407
--
3408
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3409
--
3410

    
3411
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3412
    LANGUAGE plpgsql STABLE STRICT
3413
    AS $_$
3414
DECLARE
3415
    hstore hstore;
3416
BEGIN
3417
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3418
        table_||$$))$$ INTO STRICT hstore;
3419
    RETURN hstore;
3420
END;
3421
$_$;
3422

    
3423

    
3424
--
3425
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3426
--
3427

    
3428
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3429
    LANGUAGE sql STABLE
3430
    AS $_$
3431
SELECT COUNT(*) > 0 FROM pg_constraint
3432
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3433
$_$;
3434

    
3435

    
3436
--
3437
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3438
--
3439

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

    
3444

    
3445
--
3446
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3447
--
3448

    
3449
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3450
    LANGUAGE sql
3451
    AS $_$
3452
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3453
||quote_ident($2)||$$ CHECK (true)$$)
3454
$_$;
3455

    
3456

    
3457
--
3458
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3459
--
3460

    
3461
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3462
stores a status flag by the presence of a table constraint.
3463
idempotent.
3464
';
3465

    
3466

    
3467
--
3468
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3469
--
3470

    
3471
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3472
    LANGUAGE sql STABLE
3473
    AS $_$
3474
SELECT util.table_flag__get($1, 'nulls_mapped')
3475
$_$;
3476

    
3477

    
3478
--
3479
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3480
--
3481

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

    
3486

    
3487
--
3488
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3489
--
3490

    
3491
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3492
    LANGUAGE sql
3493
    AS $_$
3494
SELECT util.table_flag__set($1, 'nulls_mapped')
3495
$_$;
3496

    
3497

    
3498
--
3499
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3500
--
3501

    
3502
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3503
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3504
idempotent.
3505
';
3506

    
3507

    
3508
--
3509
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3510
--
3511

    
3512
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3513
    LANGUAGE plpgsql STRICT
3514
    AS $_$
3515
DECLARE
3516
    row record;
3517
BEGIN
3518
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3519
    LOOP
3520
        IF row.global_name != row.name THEN
3521
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3522
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3523
        END IF;
3524
    END LOOP;
3525
END;
3526
$_$;
3527

    
3528

    
3529
--
3530
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3531
--
3532

    
3533
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3534
idempotent
3535
';
3536

    
3537

    
3538
--
3539
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3540
--
3541

    
3542
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3543
    LANGUAGE sql
3544
    AS $_$
3545
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3546
SELECT NULL::void; -- don't fold away functions called in previous query
3547
$_$;
3548

    
3549

    
3550
--
3551
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3552
--
3553

    
3554
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3555
trims table_ to include only columns in the original data.
3556
idempotent.
3557
';
3558

    
3559

    
3560
--
3561
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3562
--
3563

    
3564
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3565
    LANGUAGE plpgsql STRICT
3566
    AS $_$
3567
BEGIN
3568
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3569
END;
3570
$_$;
3571

    
3572

    
3573
--
3574
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3575
--
3576

    
3577
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3578
idempotent
3579
';
3580

    
3581

    
3582
--
3583
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3584
--
3585

    
3586
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3587
    LANGUAGE sql IMMUTABLE
3588
    AS $_$
3589
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3590
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3591
$_$;
3592

    
3593

    
3594
--
3595
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3596
--
3597

    
3598
CREATE FUNCTION try_create(sql text) RETURNS void
3599
    LANGUAGE plpgsql STRICT
3600
    AS $$
3601
BEGIN
3602
    PERFORM util.eval(sql);
3603
EXCEPTION
3604
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3605
    WHEN undefined_column THEN NULL;
3606
    WHEN duplicate_column THEN NULL;
3607
END;
3608
$$;
3609

    
3610

    
3611
--
3612
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3613
--
3614

    
3615
COMMENT ON FUNCTION try_create(sql text) IS '
3616
idempotent
3617
';
3618

    
3619

    
3620
--
3621
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3622
--
3623

    
3624
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3625
    LANGUAGE sql
3626
    AS $_$
3627
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3628
$_$;
3629

    
3630

    
3631
--
3632
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3633
--
3634

    
3635
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3636
idempotent
3637
';
3638

    
3639

    
3640
--
3641
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3642
--
3643

    
3644
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3645
    LANGUAGE sql IMMUTABLE
3646
    AS $_$
3647
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3648
$_$;
3649

    
3650

    
3651
--
3652
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3653
--
3654

    
3655
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3656
a type''s NOT NULL qualifier
3657
';
3658

    
3659

    
3660
--
3661
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3662
--
3663

    
3664
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3665
    LANGUAGE sql STABLE
3666
    AS $_$
3667
SELECT (attname::text, atttypid)::util.col_cast
3668
FROM pg_attribute
3669
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3670
ORDER BY attnum
3671
$_$;
3672

    
3673

    
3674
--
3675
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3676
--
3677

    
3678
CREATE FUNCTION typeof(value anyelement) RETURNS text
3679
    LANGUAGE sql IMMUTABLE
3680
    AS $_$
3681
SELECT util.qual_name(pg_typeof($1))
3682
$_$;
3683

    
3684

    
3685
--
3686
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3687
--
3688

    
3689
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3690
    LANGUAGE plpgsql STABLE
3691
    AS $_$
3692
DECLARE
3693
    type regtype;
3694
BEGIN
3695
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3696
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3697
    RETURN type;
3698
END;
3699
$_$;
3700

    
3701

    
3702
--
3703
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3704
--
3705

    
3706
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3707
    LANGUAGE sql
3708
    AS $_$
3709
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3710
$_$;
3711

    
3712

    
3713
--
3714
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3715
--
3716

    
3717
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3718
auto-appends util to the search_path to enable use of util operators
3719
';
3720

    
3721

    
3722
--
3723
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3724
--
3725

    
3726
CREATE AGGREGATE all_same(anyelement) (
3727
    SFUNC = all_same_transform,
3728
    STYPE = anyarray,
3729
    FINALFUNC = all_same_final
3730
);
3731

    
3732

    
3733
--
3734
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3735
--
3736

    
3737
COMMENT ON AGGREGATE all_same(anyelement) IS '
3738
includes NULLs in comparison
3739
';
3740

    
3741

    
3742
--
3743
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3744
--
3745

    
3746
CREATE AGGREGATE join_strs(text, text) (
3747
    SFUNC = join_strs_transform,
3748
    STYPE = text
3749
);
3750

    
3751

    
3752
--
3753
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3754
--
3755

    
3756
CREATE OPERATOR %== (
3757
    PROCEDURE = "%==",
3758
    LEFTARG = anyelement,
3759
    RIGHTARG = anyelement
3760
);
3761

    
3762

    
3763
--
3764
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3765
--
3766

    
3767
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3768
returns whether the map-keys of the compared values are the same
3769
(mnemonic: % is the Perl symbol for a hash map)
3770

    
3771
should be overridden for types that store both keys and values
3772

    
3773
used in a FULL JOIN to select which columns to join on
3774
';
3775

    
3776

    
3777
--
3778
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3779
--
3780

    
3781
CREATE OPERATOR -> (
3782
    PROCEDURE = map_get,
3783
    LEFTARG = regclass,
3784
    RIGHTARG = text
3785
);
3786

    
3787

    
3788
--
3789
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3790
--
3791

    
3792
CREATE OPERATOR => (
3793
    PROCEDURE = hstore,
3794
    LEFTARG = text[],
3795
    RIGHTARG = text
3796
);
3797

    
3798

    
3799
--
3800
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3801
--
3802

    
3803
COMMENT ON OPERATOR => (text[], text) IS '
3804
usage: array[''key1'', ...]::text[] => ''value''
3805
';
3806

    
3807

    
3808
--
3809
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3810
--
3811

    
3812
CREATE OPERATOR ?*>= (
3813
    PROCEDURE = is_populated_more_often_than,
3814
    LEFTARG = anyelement,
3815
    RIGHTARG = anyelement
3816
);
3817

    
3818

    
3819
--
3820
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3821
--
3822

    
3823
CREATE OPERATOR ?>= (
3824
    PROCEDURE = is_more_complete_than,
3825
    LEFTARG = anyelement,
3826
    RIGHTARG = anyelement
3827
);
3828

    
3829

    
3830
--
3831
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3832
--
3833

    
3834
CREATE OPERATOR ||% (
3835
    PROCEDURE = concat_esc,
3836
    LEFTARG = text,
3837
    RIGHTARG = text
3838
);
3839

    
3840

    
3841
--
3842
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3843
--
3844

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

    
3849

    
3850
--
3851
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3852
--
3853

    
3854
CREATE TABLE map (
3855
    "from" text NOT NULL,
3856
    "to" text,
3857
    filter text,
3858
    notes text
3859
);
3860

    
3861

    
3862
--
3863
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3864
--
3865

    
3866

    
3867

    
3868
--
3869
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3870
--
3871

    
3872

    
3873

    
3874
--
3875
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3876
--
3877

    
3878
ALTER TABLE ONLY map
3879
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3880

    
3881

    
3882
--
3883
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3884
--
3885

    
3886
ALTER TABLE ONLY map
3887
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3888

    
3889

    
3890
--
3891
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3892
--
3893

    
3894
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3895

    
3896

    
3897
--
3898
-- PostgreSQL database dump complete
3899
--
3900

    
(19-19/29)