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: db_item; Type: TYPE; Schema: util; Owner: -
76
--
77

    
78
CREATE TYPE db_item AS (
79
	path text,
80
	def text
81
);
82

    
83

    
84
--
85
-- Name: restore_views_info; Type: TYPE; Schema: util; Owner: -
86
--
87

    
88
CREATE TYPE restore_views_info AS (
89
	views db_item[]
90
);
91

    
92

    
93
--
94
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
95
--
96

    
97
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
98
    LANGUAGE sql STABLE
99
    AS $_$
100
SELECT keys($1) = keys($2)
101
$_$;
102

    
103

    
104
--
105
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
106
--
107

    
108
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
109
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**)
110
';
111

    
112

    
113
--
114
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
115
--
116

    
117
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
118
    LANGUAGE sql IMMUTABLE
119
    AS $_$
120
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
121
$_$;
122

    
123

    
124
--
125
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
126
--
127

    
128
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
129
    LANGUAGE sql IMMUTABLE
130
    AS $_$
131
SELECT bool_and(value)
132
FROM
133
(VALUES
134
      ($1)
135
    , ($2)
136
    , ($3)
137
    , ($4)
138
    , ($5)
139
)
140
AS v (value)
141
$_$;
142

    
143

    
144
--
145
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
146
--
147

    
148
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
149
_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.
150
';
151

    
152

    
153
--
154
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
155
--
156

    
157
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
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT avg(value)
161
FROM
162
(VALUES
163
      ($1)
164
    , ($2)
165
    , ($3)
166
    , ($4)
167
    , ($5)
168
)
169
AS v (value)
170
$_$;
171

    
172

    
173
--
174
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
175
--
176

    
177
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
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)
181
FROM 
182
(
183
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
184
    UNION ALL
185
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
186
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
187
)
188
matches (g)
189
$_$;
190

    
191

    
192
--
193
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
194
--
195

    
196
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
197
    LANGUAGE sql IMMUTABLE
198
    AS $_$
199
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
200
FROM
201
(VALUES
202
      ($1)
203
    , ($2/60)
204
    , ($3/60/60)
205
)
206
AS v (value)
207
$_$;
208

    
209

    
210
--
211
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
212
--
213

    
214
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
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
218
$_$;
219

    
220

    
221
--
222
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
223
--
224

    
225
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228
SELECT $1 = $2
229
$_$;
230

    
231

    
232
--
233
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
234
--
235

    
236
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239
-- Fix dates after threshold date
240
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
241
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
242
$_$;
243

    
244

    
245
--
246
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
247
--
248

    
249
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
250
    LANGUAGE sql IMMUTABLE
251
    AS $_$
252
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
253
$_$;
254

    
255

    
256
--
257
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
258
--
259

    
260
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
261
    LANGUAGE sql IMMUTABLE
262
    AS $_$
263
SELECT util._if($1 != '', $2, $3)
264
$_$;
265

    
266

    
267
--
268
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
269
--
270

    
271
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
272
    LANGUAGE sql IMMUTABLE
273
    AS $_$
274
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
275
$_$;
276

    
277

    
278
--
279
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
280
--
281

    
282
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
283
    LANGUAGE sql IMMUTABLE
284
    AS $_$
285
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
286
$_$;
287

    
288

    
289
--
290
-- Name: _km_to_m(double precision); Type: FUNCTION; Schema: util; Owner: -
291
--
292

    
293
CREATE FUNCTION _km_to_m(value double precision) RETURNS double precision
294
    LANGUAGE sql IMMUTABLE
295
    AS $_$
296
SELECT $1*1000.
297
$_$;
298

    
299

    
300
--
301
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
302
--
303

    
304
CREATE FUNCTION _label(label text, value text) RETURNS text
305
    LANGUAGE sql IMMUTABLE
306
    AS $_$
307
SELECT coalesce($1 || ': ', '') || $2
308
$_$;
309

    
310

    
311
--
312
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
313
--
314

    
315
CREATE FUNCTION _lowercase(value text) RETURNS text
316
    LANGUAGE sql IMMUTABLE
317
    AS $_$
318
SELECT lower($1)
319
$_$;
320

    
321

    
322
--
323
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
324
--
325

    
326
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
327
    LANGUAGE plpgsql IMMUTABLE STRICT
328
    AS $$
329
DECLARE
330
    result value%TYPE := util._map(map, value::text)::unknown;
331
BEGIN
332
    RETURN result;
333
END;
334
$$;
335

    
336

    
337
--
338
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
339
--
340

    
341
CREATE FUNCTION _map(map hstore, value text) RETURNS text
342
    LANGUAGE plpgsql IMMUTABLE STRICT
343
    AS $$
344
DECLARE
345
    match text := map -> value;
346
BEGIN
347
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
348
        match := map -> '*'; -- use default entry
349
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
350
        END IF;
351
    END IF;
352
    
353
    -- Interpret result
354
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
355
    ELSIF match = '*' THEN RETURN value;
356
    ELSE RETURN match;
357
    END IF;
358
END;
359
$$;
360

    
361

    
362
--
363
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
364
--
365

    
366
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
367
    LANGUAGE sql IMMUTABLE
368
    AS $_$
369
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
370
$_$;
371

    
372

    
373
--
374
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
375
--
376

    
377
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
378
    LANGUAGE sql IMMUTABLE
379
    AS $_$
380
SELECT util.join_strs(value, '; ')
381
FROM
382
(
383
    SELECT *
384
    FROM
385
    (
386
        SELECT
387
        DISTINCT ON (value)
388
        *
389
        FROM
390
        (VALUES
391
              (1, $1)
392
            , (2, $2)
393
            , (3, $3)
394
            , (4, $4)
395
            , (5, $5)
396
            , (6, $6)
397
            , (7, $7)
398
            , (8, $8)
399
            , (9, $9)
400
            , (10, $10)
401
        )
402
        AS v (sort_order, value)
403
        WHERE value IS NOT NULL
404
    )
405
    AS v
406
    ORDER BY sort_order
407
)
408
AS v
409
$_$;
410

    
411

    
412
--
413
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
420
$_$;
421

    
422

    
423
--
424
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
425
--
426

    
427
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
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT util.join_strs(value, ' ')
431
FROM
432
(
433
    SELECT *
434
    FROM
435
    (
436
        SELECT
437
        DISTINCT ON (value)
438
        *
439
        FROM
440
        (VALUES
441
              (1, $1)
442
            , (2, $2)
443
            , (3, $3)
444
            , (4, $4)
445
            , (5, $5)
446
            , (6, $6)
447
            , (7, $7)
448
            , (8, $8)
449
            , (9, $9)
450
            , (10, $10)
451
        )
452
        AS v (sort_order, value)
453
        WHERE value IS NOT NULL
454
    )
455
    AS v
456
    ORDER BY sort_order
457
)
458
AS v
459
$_$;
460

    
461

    
462
--
463
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
464
--
465

    
466
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
467
    LANGUAGE sql IMMUTABLE
468
    AS $_$
469
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
470
$_$;
471

    
472

    
473
--
474
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
475
--
476

    
477
CREATE FUNCTION _not(value boolean) RETURNS boolean
478
    LANGUAGE sql IMMUTABLE
479
    AS $_$
480
SELECT NOT $1
481
$_$;
482

    
483

    
484
--
485
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
486
--
487

    
488
CREATE FUNCTION _now() RETURNS timestamp with time zone
489
    LANGUAGE sql STABLE
490
    AS $$
491
SELECT now()
492
$$;
493

    
494

    
495
--
496
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
497
--
498

    
499
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
500
    LANGUAGE sql IMMUTABLE
501
    AS $_$
502
SELECT util."_nullIf"($1, $2, $3::util.datatype)
503
$_$;
504

    
505

    
506
--
507
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
508
--
509

    
510
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
511
    LANGUAGE plpgsql IMMUTABLE
512
    AS $$
513
DECLARE
514
    type util.datatype NOT NULL := type; -- add NOT NULL
515
BEGIN
516
    IF type = 'str' THEN RETURN nullif(value::text, "null");
517
    -- Invalid value is ignored, but invalid null value generates error
518
    ELSIF type = 'float' THEN
519
        DECLARE
520
            -- Outside the try block so that invalid null value generates error
521
            "null" double precision := "null"::double precision;
522
        BEGIN
523
            RETURN nullif(value::double precision, "null");
524
        EXCEPTION
525
            WHEN data_exception THEN RETURN value; -- ignore invalid value
526
        END;
527
    END IF;
528
END;
529
$$;
530

    
531

    
532
--
533
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
534
--
535

    
536
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
537
    LANGUAGE sql IMMUTABLE
538
    AS $_$
539
SELECT bool_or(value)
540
FROM
541
(VALUES
542
      ($1)
543
    , ($2)
544
    , ($3)
545
    , ($4)
546
    , ($5)
547
)
548
AS v (value)
549
$_$;
550

    
551

    
552
--
553
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
554
--
555

    
556
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
557
_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.
558
';
559

    
560

    
561
--
562
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
563
--
564

    
565
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
566
    LANGUAGE sql IMMUTABLE
567
    AS $_$
568
SELECT $2 - $1
569
$_$;
570

    
571

    
572
--
573
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
574
--
575

    
576
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
577
    LANGUAGE sql IMMUTABLE
578
    AS $_$
579
SELECT regexp_split_to_table($1, $2)
580
$_$;
581

    
582

    
583
--
584
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
585
--
586

    
587
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
588
    LANGUAGE sql STABLE
589
    AS $_$
590
SELECT util.derived_cols($1, $2)
591
UNION
592
SELECT util.eval2set($$
593
SELECT col
594
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
595
JOIN $$||$2||$$ ON "to" = col
596
WHERE "from" LIKE ':%'
597
$$, NULL::text)
598
$_$;
599

    
600

    
601
--
602
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
603
--
604

    
605
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
606
gets table_''s added columns (all the columns not in the original data)
607
';
608

    
609

    
610
--
611
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
612
--
613

    
614
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
618
$_$;
619

    
620

    
621
--
622
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
623
--
624

    
625
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
626
    LANGUAGE plpgsql IMMUTABLE
627
    AS $$
628
DECLARE
629
	value_cmp         state%TYPE = ARRAY[value];
630
	state             state%TYPE = COALESCE(state, value_cmp);
631
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
632
BEGIN
633
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
634
END;
635
$$;
636

    
637

    
638
--
639
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
640
--
641

    
642
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
643
    LANGUAGE sql
644
    AS $_$
645
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
646
$_$;
647

    
648

    
649
--
650
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
651
--
652

    
653
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
654
    LANGUAGE sql
655
    AS $_$
656
SELECT util.set_comment($1, concat(util.comment($1), $2))
657
$_$;
658

    
659

    
660
--
661
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
662
--
663

    
664
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
665
comment: must start and end with a newline
666
';
667

    
668

    
669
--
670
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
671
--
672

    
673
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
674
    LANGUAGE sql IMMUTABLE
675
    AS $_$
676
SELECT pg_catalog.array_fill($1, ARRAY[$2])
677
$_$;
678

    
679

    
680
--
681
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
682
--
683

    
684
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
685
    LANGUAGE sql IMMUTABLE
686
    AS $_$
687
SELECT util.array_length($1, 1)
688
$_$;
689

    
690

    
691
--
692
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
693
--
694

    
695
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
696
    LANGUAGE sql IMMUTABLE
697
    AS $_$
698
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
699
$_$;
700

    
701

    
702
--
703
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
704
--
705

    
706
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
707
returns 0 instead of NULL for empty arrays
708
';
709

    
710

    
711
--
712
-- Name: array_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
713
--
714

    
715
CREATE FUNCTION array_reverse("array" anyarray) RETURNS anyarray
716
    LANGUAGE sql IMMUTABLE
717
    AS $_$
718
SELECT array(SELECT elem FROM util.in_reverse($1) elem)
719
$_$;
720

    
721

    
722
--
723
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
724
--
725

    
726
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
727
    LANGUAGE sql
728
    AS $_$
729
SELECT CASE WHEN util.freq_always_1($1, $2)
730
THEN util.rm_freq($1, $2)
731
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
732
END
733
$_$;
734

    
735

    
736
--
737
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
738
--
739

    
740
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
741
    LANGUAGE plpgsql IMMUTABLE
742
    AS $$
743
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
744
return value, causing a type mismatch */
745
BEGIN
746
	-- will then be assignment-cast to return type via INOUT
747
	RETURN value::cstring;
748
END;
749
$$;
750

    
751

    
752
--
753
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
754
--
755

    
756
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
757
allows casting to an arbitrary type without eval()
758

    
759
usage:
760
SELECT util.cast(''value'', NULL::integer);
761

    
762
note that there does *not* need to be a cast from text to the output type,
763
because an INOUT cast is used instead
764
(http://www.postgresql.org/docs/9.3/static/sql-createcast.html#AEN69507)
765

    
766
ret_type_null: NULL::ret_type
767
';
768

    
769

    
770
--
771
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
772
--
773

    
774
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
775
    LANGUAGE sql STABLE
776
    AS $_$
777
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
778
$_$;
779

    
780

    
781
--
782
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
783
--
784

    
785
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
786
    LANGUAGE plpgsql STRICT
787
    AS $_$
788
BEGIN
789
    -- not yet clustered (ARRAY[] compares NULLs literally)
790
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
791
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
792
    END IF;
793
END;
794
$_$;
795

    
796

    
797
--
798
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
799
--
800

    
801
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
802
idempotent
803
';
804

    
805

    
806
--
807
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
808
--
809

    
810
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
811
    LANGUAGE sql IMMUTABLE
812
    AS $_$
813
SELECT value
814
FROM unnest($1) value
815
WHERE value IS NOT NULL
816
LIMIT 1
817
$_$;
818

    
819

    
820
--
821
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
822
--
823

    
824
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
825
uses:
826
* coalescing array elements or rows together
827
* forcing evaluation of all values of a COALESCE()
828
';
829

    
830

    
831
--
832
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
833
--
834

    
835
CREATE FUNCTION col__min(col col_ref) RETURNS integer
836
    LANGUAGE sql STABLE
837
    AS $_$
838
SELECT util.eval2val($$
839
SELECT $$||quote_ident($1.name)||$$
840
FROM $$||$1.table_||$$
841
ORDER BY $$||quote_ident($1.name)||$$ ASC
842
LIMIT 1
843
$$, NULL::integer)
844
$_$;
845

    
846

    
847
--
848
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
849
--
850

    
851
CREATE FUNCTION col_comment(col col_ref) RETURNS text
852
    LANGUAGE plpgsql STABLE STRICT
853
    AS $$
854
DECLARE
855
	comment text;
856
BEGIN
857
	SELECT description
858
	FROM pg_attribute
859
	LEFT JOIN pg_description ON objoid = attrelid
860
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
861
	WHERE attrelid = col.table_ AND attname = col.name
862
	INTO STRICT comment
863
	;
864
	RETURN comment;
865
EXCEPTION
866
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
867
END;
868
$$;
869

    
870

    
871
--
872
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
873
--
874

    
875
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
876
    LANGUAGE plpgsql STABLE STRICT
877
    AS $$
878
DECLARE
879
	default_sql text;
880
BEGIN
881
	SELECT adsrc
882
	FROM pg_attribute
883
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
884
	WHERE attrelid = col.table_ AND attname = col.name
885
	INTO STRICT default_sql
886
	;
887
	RETURN default_sql;
888
EXCEPTION
889
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
890
END;
891
$$;
892

    
893

    
894
--
895
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
899
    LANGUAGE sql STABLE
900
    AS $_$
901
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
902
$_$;
903

    
904

    
905
--
906
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
907
--
908

    
909
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
910
ret_type_null: NULL::ret_type
911
';
912

    
913

    
914
--
915
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
916
--
917

    
918
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
919
    LANGUAGE plpgsql STRICT
920
    AS $$
921
BEGIN
922
    PERFORM util.col_type(col);
923
    RETURN true;
924
EXCEPTION
925
    WHEN undefined_column THEN RETURN false;
926
END;
927
$$;
928

    
929

    
930
--
931
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
932
--
933

    
934
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
935
    LANGUAGE plpgsql STABLE STRICT
936
    AS $$
937
DECLARE
938
    prefix text := util.name(type)||'.';
939
BEGIN
940
    RETURN QUERY
941
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
942
        FROM util.col_names(type) f (name_);
943
END;
944
$$;
945

    
946

    
947
--
948
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
949
--
950

    
951
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
952
    LANGUAGE sql STABLE
953
    AS $_$
954
SELECT attname::text
955
FROM pg_attribute
956
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
957
ORDER BY attnum
958
$_$;
959

    
960

    
961
--
962
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
963
--
964

    
965
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
966
    LANGUAGE plpgsql STABLE STRICT
967
    AS $_$
968
BEGIN
969
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
970
END;
971
$_$;
972

    
973

    
974
--
975
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
976
--
977

    
978
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
979
    LANGUAGE plpgsql STABLE STRICT
980
    AS $$
981
DECLARE
982
    type regtype;
983
BEGIN
984
    SELECT atttypid FROM pg_attribute
985
    WHERE attrelid = col.table_ AND attname = col.name
986
    INTO STRICT type
987
    ;
988
    RETURN type;
989
EXCEPTION
990
    WHEN no_data_found THEN
991
        RAISE undefined_column USING MESSAGE =
992
            concat('undefined column: ', col.name);
993
END;
994
$$;
995

    
996

    
997
--
998
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
999
--
1000

    
1001
CREATE FUNCTION comment(element oid) RETURNS text
1002
    LANGUAGE sql STABLE
1003
    AS $_$
1004
SELECT description FROM pg_description WHERE objoid = $1
1005
$_$;
1006

    
1007

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

    
1012
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
1013
    LANGUAGE sql IMMUTABLE
1014
    AS $_$
1015
SELECT util.esc_name__append($2, $1)
1016
$_$;
1017

    
1018

    
1019
--
1020
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1021
--
1022

    
1023
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1024
    LANGUAGE sql IMMUTABLE
1025
    AS $_$
1026
SELECT position($1 in $2) > 0 /*1-based offset*/
1027
$_$;
1028

    
1029

    
1030
--
1031
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1032
--
1033

    
1034
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1035
    LANGUAGE sql
1036
    AS $_$
1037
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1038
$_$;
1039

    
1040

    
1041
--
1042
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1043
--
1044

    
1045
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1046
    LANGUAGE sql
1047
    AS $_$
1048
SELECT util.materialize_view($2, $1)
1049
$_$;
1050

    
1051

    
1052
--
1053
-- Name: create_if_not_exists(text, text); Type: FUNCTION; Schema: util; Owner: -
1054
--
1055

    
1056
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1057
    LANGUAGE plpgsql
1058
    AS $$
1059
BEGIN
1060
	/* always generate standard exception if exists, even if table definition
1061
	would be invalid (which generates a variety of exceptions) */
1062
	IF util.relation_exists(relation) THEN RAISE duplicate_table; END IF;
1063
	PERFORM util.eval(sql);
1064
EXCEPTION
1065
WHEN   duplicate_table
1066
	OR duplicate_object -- eg. constraint
1067
	OR duplicate_column
1068
	OR duplicate_function
1069
THEN NULL;
1070
WHEN invalid_table_definition THEN
1071
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1072
	ELSE RAISE;
1073
	END IF;
1074
END;
1075
$$;
1076

    
1077

    
1078
--
1079
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1080
--
1081

    
1082
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1083
idempotent
1084
';
1085

    
1086

    
1087
--
1088
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1089
--
1090

    
1091
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1092
    LANGUAGE sql STABLE
1093
    AS $$
1094
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1095
$$;
1096

    
1097

    
1098
--
1099
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1100
--
1101

    
1102
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1103
    LANGUAGE sql IMMUTABLE
1104
    AS $_$
1105
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1106
$_$;
1107

    
1108

    
1109
--
1110
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1111
--
1112

    
1113
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1114
    LANGUAGE sql IMMUTABLE
1115
    AS $_$
1116
SELECT util.debug_print_value('returns: ', $1, $2);
1117
SELECT $1;
1118
$_$;
1119

    
1120

    
1121
--
1122
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1123
--
1124

    
1125
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1126
    LANGUAGE sql IMMUTABLE
1127
    AS $_$
1128
/* newline before so the query starts at the beginning of the line.
1129
newline after to visually separate queries from one another. */
1130
SELECT util.raise('NOTICE', $$
1131
$$||util.runnable_sql($1)||$$
1132
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1133
$_$;
1134

    
1135

    
1136
--
1137
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1138
--
1139

    
1140
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1141
    LANGUAGE sql IMMUTABLE
1142
    AS $_$
1143
SELECT util.raise('NOTICE', concat($1,
1144
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1145
$$)
1146
$_$;
1147

    
1148

    
1149
--
1150
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1151
--
1152

    
1153
CREATE FUNCTION debug_print_var(var text, value anyelement, encode boolean DEFAULT false) RETURNS void
1154
    LANGUAGE sql IMMUTABLE
1155
    AS $_$
1156
/* can't use EXECUTE in the caller because "No substitution of PL/pgSQL
1157
variables is done on the computed command string"
1158
(http://www.postgresql.org/docs/9.3/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN) */
1159
SELECT util.debug_print_value($1||' = ', $2, $3)
1160
$_$;
1161

    
1162

    
1163
--
1164
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1165
--
1166

    
1167
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1168
    LANGUAGE sql STABLE
1169
    AS $_$
1170
SELECT util.eval2set($$
1171
SELECT col
1172
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1173
LEFT JOIN $$||$2||$$ ON "to" = col
1174
WHERE "from" IS NULL
1175
$$, NULL::text)
1176
$_$;
1177

    
1178

    
1179
--
1180
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1181
--
1182

    
1183
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1184
gets table_''s derived columns (all the columns not in the names table)
1185
';
1186

    
1187

    
1188
--
1189
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1190
--
1191

    
1192
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1193
    LANGUAGE sql
1194
    AS $_$
1195
-- create a diff when the # of copies of a row differs between the tables
1196
SELECT util.to_freq($1);
1197
SELECT util.to_freq($2);
1198
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1199

    
1200
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1201
$_$;
1202

    
1203

    
1204
--
1205
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1206
--
1207

    
1208
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1209
usage:
1210
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1211

    
1212
col_type_null (*required*): NULL::shared_base_type
1213
';
1214

    
1215

    
1216
--
1217
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1218
--
1219

    
1220
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
1221
    LANGUAGE plpgsql
1222
    SET search_path TO pg_temp
1223
    AS $_$
1224
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1225
changes of search_path (schema elements are bound at inline time rather than
1226
runtime) */
1227
/* function option search_path is needed to limit the effects of
1228
`SET LOCAL search_path` to the current function */
1229
BEGIN
1230
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1231
	
1232
	PERFORM util.mk_keys_func(pg_typeof($3));
1233
	RETURN QUERY
1234
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1235
$$/* need to explicitly cast each side to the return type because this does not
1236
happen automatically even when an implicit cast is available */
1237
  left_::$$||util.typeof($3)||$$
1238
, right_::$$||util.typeof($3)
1239
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1240
the *same* base type, *even though* this is optional when using a custom %== */
1241
, util._if($4, $$true/*= CROSS JOIN*/$$,
1242
$$ left_::$$||util.typeof($3)||$$
1243
%== right_::$$||util.typeof($3)||$$
1244
	-- refer to EXPLAIN output for expansion of %==$$
1245
)
1246
,     $$         left_::$$||util.typeof($3)||$$
1247
IS DISTINCT FROM right_::$$||util.typeof($3)
1248
), $3)
1249
	;
1250
END;
1251
$_$;
1252

    
1253

    
1254
--
1255
-- 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: -
1256
--
1257

    
1258
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1259
col_type_null (*required*): NULL::col_type
1260
single_row: whether the tables consist of a single row, which should be
1261
	displayed side-by-side
1262

    
1263
to match up rows using a subset of the columns, create a custom keys() function
1264
which returns this subset as a record:
1265
-- note that OUT parameters for the returned fields are *not* needed
1266
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1267
  RETURNS record AS
1268
$BODY$
1269
SELECT ($1.key_field_0, $1.key_field_1)
1270
$BODY$
1271
  LANGUAGE sql IMMUTABLE
1272
  COST 100;
1273

    
1274

    
1275
to run EXPLAIN on the FULL JOIN query:
1276
# run this function
1277
# look for a NOTICE containing the expanded query that it ran
1278
# run EXPLAIN on this expanded query
1279
';
1280

    
1281

    
1282
--
1283
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1284
--
1285

    
1286
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1287
    LANGUAGE sql
1288
    AS $_$
1289
SELECT * FROM util.diff($1::text, $2::text, $3,
1290
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1291
$_$;
1292

    
1293

    
1294
--
1295
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1296
--
1297

    
1298
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1299
helper function used by diff(regclass, regclass)
1300

    
1301
usage:
1302
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1303

    
1304
col_type_null (*required*): NULL::shared_base_type
1305
';
1306

    
1307

    
1308
--
1309
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1310
--
1311

    
1312
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1313
    LANGUAGE sql
1314
    AS $_$
1315
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1316
$_$;
1317

    
1318

    
1319
--
1320
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1321
--
1322

    
1323
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1324
idempotent
1325
';
1326

    
1327

    
1328
--
1329
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1330
--
1331

    
1332
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1333
    LANGUAGE sql
1334
    AS $_$
1335
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1336
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1337
$_$;
1338

    
1339

    
1340
--
1341
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1342
--
1343

    
1344
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1345
idempotent
1346
';
1347

    
1348

    
1349
--
1350
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1351
--
1352

    
1353
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1354
    LANGUAGE sql
1355
    AS $_$
1356
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1357
SELECT NULL::void; -- don't fold away functions called in previous query
1358
$_$;
1359

    
1360

    
1361
--
1362
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1363
--
1364

    
1365
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1366
idempotent
1367
';
1368

    
1369

    
1370
--
1371
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1372
--
1373

    
1374
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1375
    LANGUAGE sql
1376
    AS $_$
1377
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1378
included in the debug SQL */
1379
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1380
$_$;
1381

    
1382

    
1383
--
1384
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1385
--
1386

    
1387
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1388
    LANGUAGE sql
1389
    AS $_$
1390
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1391
||util._if($3, $$ CASCADE$$, ''::text))
1392
$_$;
1393

    
1394

    
1395
--
1396
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1397
--
1398

    
1399
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1400
idempotent
1401
';
1402

    
1403

    
1404
--
1405
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1406
--
1407

    
1408
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1409
    LANGUAGE sql
1410
    AS $_$
1411
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1412
$_$;
1413

    
1414

    
1415
--
1416
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1417
--
1418

    
1419
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1420
    LANGUAGE sql
1421
    AS $_$
1422
SELECT util.debug_print_func_call(util.quote_func_call(
1423
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1424
util.quote_typed($3)))
1425
;
1426
SELECT util.drop_relation(relation, $3)
1427
FROM util.show_relations_like($1, $2) relation
1428
;
1429
SELECT NULL::void; -- don't fold away functions called in previous query
1430
$_$;
1431

    
1432

    
1433
--
1434
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1435
--
1436

    
1437
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1438
    LANGUAGE sql
1439
    AS $_$
1440
SELECT util.drop_relation('TABLE', $1, $2)
1441
$_$;
1442

    
1443

    
1444
--
1445
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1446
--
1447

    
1448
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1449
idempotent
1450
';
1451

    
1452

    
1453
--
1454
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1455
--
1456

    
1457
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1458
    LANGUAGE sql
1459
    AS $_$
1460
SELECT util.drop_relation('VIEW', $1, $2)
1461
$_$;
1462

    
1463

    
1464
--
1465
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1466
--
1467

    
1468
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1469
idempotent
1470
';
1471

    
1472

    
1473
--
1474
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1475
--
1476

    
1477
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1478
    LANGUAGE sql IMMUTABLE
1479
    AS $_$
1480
SELECT util.array_fill($1, 0)
1481
$_$;
1482

    
1483

    
1484
--
1485
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1486
--
1487

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

    
1492

    
1493
--
1494
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1495
--
1496

    
1497
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1498
    LANGUAGE sql IMMUTABLE
1499
    AS $_$
1500
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1501
$_$;
1502

    
1503

    
1504
--
1505
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1506
--
1507

    
1508
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1509
    LANGUAGE sql IMMUTABLE
1510
    AS $_$
1511
SELECT regexp_replace($2, '("?)$', $1||'\1')
1512
$_$;
1513

    
1514

    
1515
--
1516
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1517
--
1518

    
1519
CREATE FUNCTION eval(queries text[]) RETURNS void
1520
    LANGUAGE sql
1521
    AS $_$
1522
SELECT util.eval(query) FROM unnest($1) query;
1523
SELECT NULL::void; -- don't fold away functions called in previous query
1524
$_$;
1525

    
1526

    
1527
--
1528
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1529
--
1530

    
1531
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1532
    LANGUAGE plpgsql
1533
    AS $$
1534
BEGIN
1535
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1536
	EXECUTE sql;
1537
END;
1538
$$;
1539

    
1540

    
1541
--
1542
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1543
--
1544

    
1545
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1546
    LANGUAGE plpgsql
1547
    AS $$
1548
BEGIN
1549
	PERFORM util.debug_print_sql(sql);
1550
	RETURN QUERY EXECUTE sql;
1551
END;
1552
$$;
1553

    
1554

    
1555
--
1556
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1557
--
1558

    
1559
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1560
col_type_null (*required*): NULL::col_type
1561
';
1562

    
1563

    
1564
--
1565
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1566
--
1567

    
1568
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1569
    LANGUAGE plpgsql
1570
    AS $$
1571
BEGIN
1572
	PERFORM util.debug_print_sql(sql);
1573
	RETURN QUERY EXECUTE sql;
1574
END;
1575
$$;
1576

    
1577

    
1578
--
1579
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1580
--
1581

    
1582
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1583
    LANGUAGE plpgsql
1584
    AS $$
1585
BEGIN
1586
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1587
	RETURN QUERY EXECUTE sql;
1588
END;
1589
$$;
1590

    
1591

    
1592
--
1593
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1594
--
1595

    
1596
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1597
    LANGUAGE plpgsql STABLE
1598
    AS $$
1599
DECLARE
1600
	ret_val ret_type_null%TYPE;
1601
BEGIN
1602
	PERFORM util.debug_print_sql(sql);
1603
	EXECUTE sql INTO STRICT ret_val;
1604
	RETURN ret_val;
1605
END;
1606
$$;
1607

    
1608

    
1609
--
1610
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1611
--
1612

    
1613
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1614
ret_type_null: NULL::ret_type
1615
';
1616

    
1617

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

    
1622
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1623
    LANGUAGE sql
1624
    AS $_$
1625
SELECT util.eval2val($$SELECT $$||$1, $2)
1626
$_$;
1627

    
1628

    
1629
--
1630
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1631
--
1632

    
1633
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1634
ret_type_null: NULL::ret_type
1635
';
1636

    
1637

    
1638
--
1639
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1640
--
1641

    
1642
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1643
    LANGUAGE sql
1644
    AS $_$
1645
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1646
$_$;
1647

    
1648

    
1649
--
1650
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1651
--
1652

    
1653
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1654
sql: can be NULL, which will be passed through
1655
ret_type_null: NULL::ret_type
1656
';
1657

    
1658

    
1659
--
1660
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1661
--
1662

    
1663
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1664
    LANGUAGE sql STABLE
1665
    AS $_$
1666
SELECT col_name
1667
FROM unnest($2) s (col_name)
1668
WHERE util.col_exists(($1, col_name))
1669
$_$;
1670

    
1671

    
1672
--
1673
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1674
--
1675

    
1676
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1677
    LANGUAGE sql
1678
    SET client_min_messages TO 'error'
1679
    AS $_$
1680
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1681
the query, so this prevents displaying any log messages printed by them */
1682
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1683
$_$;
1684

    
1685

    
1686
--
1687
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1688
--
1689

    
1690
CREATE FUNCTION explain2notice(sql text) RETURNS void
1691
    LANGUAGE sql
1692
    AS $_$
1693
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1694
$_$;
1695

    
1696

    
1697
--
1698
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1699
--
1700

    
1701
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1702
    LANGUAGE sql
1703
    AS $_$
1704
-- newline before and after to visually separate it from other debug info
1705
SELECT COALESCE($$
1706
EXPLAIN:
1707
$$||util.fold_explain_msg(util.explain2str($1))||$$
1708
$$, '')
1709
$_$;
1710

    
1711

    
1712
--
1713
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1714
--
1715

    
1716
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1717
    LANGUAGE plpgsql
1718
    AS $$
1719
BEGIN
1720
	RETURN util.explain2notice_msg(sql);
1721
EXCEPTION
1722
WHEN syntax_error THEN RETURN NULL; -- non-explainable query
1723
	/* don't use util.is_explainable() because the list provided by Postgres
1724
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1725
	excludes some query types that are in fact EXPLAIN-able */
1726
END;
1727
$$;
1728

    
1729

    
1730
--
1731
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1732
--
1733

    
1734
CREATE FUNCTION explain2str(sql text) RETURNS text
1735
    LANGUAGE sql
1736
    AS $_$
1737
SELECT util.join_strs(explain, $$
1738
$$) FROM util.explain($1)
1739
$_$;
1740

    
1741

    
1742
SET default_tablespace = '';
1743

    
1744
SET default_with_oids = false;
1745

    
1746
--
1747
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1748
--
1749

    
1750
CREATE TABLE explain (
1751
    line text NOT NULL
1752
);
1753

    
1754

    
1755
--
1756
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1757
--
1758

    
1759
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1760
    LANGUAGE sql
1761
    AS $_$
1762
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1763
$$||quote_nullable($1)||$$
1764
)$$)
1765
$_$;
1766

    
1767

    
1768
--
1769
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1770
--
1771

    
1772
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1773
usage:
1774
PERFORM util.explain2table($$
1775
query
1776
$$);
1777
';
1778

    
1779

    
1780
--
1781
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1782
--
1783

    
1784
CREATE FUNCTION first_word(str text) RETURNS text
1785
    LANGUAGE sql IMMUTABLE
1786
    AS $_$
1787
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1788
$_$;
1789

    
1790

    
1791
--
1792
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794

    
1795
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1796
    LANGUAGE sql IMMUTABLE
1797
    AS $_$
1798
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1799
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1800
) END
1801
$_$;
1802

    
1803

    
1804
--
1805
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1806
--
1807

    
1808
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1809
ensures that an array will always have proper non-NULL dimensions
1810
';
1811

    
1812

    
1813
--
1814
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1815
--
1816

    
1817
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1818
    LANGUAGE sql IMMUTABLE
1819
    AS $_$
1820
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1821
$_$;
1822

    
1823

    
1824
--
1825
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1826
--
1827

    
1828
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1829
    LANGUAGE plpgsql STRICT
1830
    AS $_$
1831
DECLARE
1832
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1833
$$||query;
1834
BEGIN
1835
	EXECUTE mk_view;
1836
EXCEPTION
1837
WHEN invalid_table_definition THEN
1838
	IF SQLERRM = 'cannot drop columns from view'
1839
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1840
	THEN
1841
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1842
		EXECUTE mk_view;
1843
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1844
	END IF;
1845
END;
1846
$_$;
1847

    
1848

    
1849
--
1850
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1851
--
1852

    
1853
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1854
idempotent
1855
';
1856

    
1857

    
1858
--
1859
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1860
--
1861

    
1862
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1863
    LANGUAGE sql STABLE
1864
    AS $_$
1865
SELECT util.eval2val(
1866
$$SELECT NOT EXISTS( -- there is no row that is != 1
1867
	SELECT NULL
1868
	FROM $$||$1||$$
1869
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1870
	LIMIT 1
1871
)
1872
$$, NULL::boolean)
1873
$_$;
1874

    
1875

    
1876
--
1877
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1878
--
1879

    
1880
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1881
    LANGUAGE sql STABLE
1882
    AS $_$
1883
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1884
$_$;
1885

    
1886

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

    
1891
CREATE FUNCTION grants_users() RETURNS SETOF text
1892
    LANGUAGE sql IMMUTABLE
1893
    AS $$
1894
VALUES ('bien_read'), ('public_')
1895
$$;
1896

    
1897

    
1898
--
1899
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1900
--
1901

    
1902
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1903
    LANGUAGE sql IMMUTABLE
1904
    AS $_$
1905
SELECT substring($2 for length($1)) = $1
1906
$_$;
1907

    
1908

    
1909
--
1910
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1911
--
1912

    
1913
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1914
    LANGUAGE sql STABLE
1915
    AS $_$
1916
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1917
$_$;
1918

    
1919

    
1920
--
1921
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1922
--
1923

    
1924
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1925
    LANGUAGE sql IMMUTABLE
1926
    AS $_$
1927
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1928
$_$;
1929

    
1930

    
1931
--
1932
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1933
--
1934

    
1935
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1936
avoids repeating the same value for each key
1937
';
1938

    
1939

    
1940
--
1941
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1942
--
1943

    
1944
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1945
    LANGUAGE sql IMMUTABLE
1946
    AS $_$
1947
SELECT COALESCE($1, $2)
1948
$_$;
1949

    
1950

    
1951
--
1952
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1953
--
1954

    
1955
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1956
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1957
';
1958

    
1959

    
1960
--
1961
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
1962
--
1963

    
1964
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
1965
    LANGUAGE sql IMMUTABLE
1966
    AS $_$
1967
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
1968
$_$;
1969

    
1970

    
1971
--
1972
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1973
--
1974

    
1975
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1976
    LANGUAGE sql
1977
    AS $_$
1978
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1979
$_$;
1980

    
1981

    
1982
--
1983
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1984
--
1985

    
1986
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
1987
    LANGUAGE plpgsql IMMUTABLE
1988
    AS $$
1989
BEGIN
1990
	PERFORM util.cast(value, ret_type_null);
1991
	-- must happen *after* cast check, because NULL is not valid for some types
1992
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
1993
	RETURN true;
1994
EXCEPTION
1995
WHEN   data_exception
1996
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
1997
	THEN
1998
	RETURN false;
1999
END;
2000
$$;
2001

    
2002

    
2003
--
2004
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2005
--
2006

    
2007
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2008
passes NULL through. however, if NULL is not valid for the type, false will be
2009
returned instead.
2010

    
2011
ret_type_null: NULL::ret_type
2012
';
2013

    
2014

    
2015
--
2016
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2017
--
2018

    
2019
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2020
    LANGUAGE sql STABLE
2021
    AS $_$
2022
SELECT COALESCE(util.col_comment($1) LIKE '
2023
constant
2024
%', false)
2025
$_$;
2026

    
2027

    
2028
--
2029
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2030
--
2031

    
2032
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2033
    LANGUAGE sql IMMUTABLE
2034
    AS $_$
2035
SELECT util.array_length($1) = 0
2036
$_$;
2037

    
2038

    
2039
--
2040
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2041
--
2042

    
2043
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2044
    LANGUAGE sql IMMUTABLE
2045
    AS $_$
2046
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2047
$_$;
2048

    
2049

    
2050
--
2051
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2052
--
2053

    
2054
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2055
    LANGUAGE sql IMMUTABLE
2056
    AS $_$
2057
SELECT upper(util.first_word($1)) = ANY(
2058
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2059
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2060
)
2061
$_$;
2062

    
2063

    
2064
--
2065
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2066
--
2067

    
2068
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2069
    LANGUAGE sql IMMUTABLE
2070
    AS $_$
2071
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2072
$_$;
2073

    
2074

    
2075
--
2076
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2077
--
2078

    
2079
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2080
    LANGUAGE sql IMMUTABLE
2081
    AS $_$
2082
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2083
$_$;
2084

    
2085

    
2086
--
2087
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089

    
2090
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2091
    LANGUAGE sql IMMUTABLE
2092
    AS $_$
2093
SELECT upper(util.first_word($1)) = 'SET'
2094
$_$;
2095

    
2096

    
2097
--
2098
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2099
--
2100

    
2101
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2102
    LANGUAGE sql STABLE
2103
    AS $_$
2104
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2105
$_$;
2106

    
2107

    
2108
--
2109
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2110
--
2111

    
2112
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2113
    LANGUAGE sql STABLE
2114
    AS $_$
2115
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2116
$_$;
2117

    
2118

    
2119
--
2120
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2121
--
2122

    
2123
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2124
    LANGUAGE sql IMMUTABLE STRICT
2125
    AS $_$
2126
SELECT $1 || $3 || $2
2127
$_$;
2128

    
2129

    
2130
--
2131
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2132
--
2133

    
2134
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2135
must be declared STRICT to use the special handling of STRICT aggregating functions
2136
';
2137

    
2138

    
2139
--
2140
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2141
--
2142

    
2143
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2144
    LANGUAGE sql IMMUTABLE
2145
    AS $_$
2146
SELECT $1 -- compare on the entire value
2147
$_$;
2148

    
2149

    
2150
--
2151
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2152
--
2153

    
2154
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2155
    LANGUAGE sql IMMUTABLE
2156
    AS $_$
2157
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2158
$_$;
2159

    
2160

    
2161
--
2162
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2163
--
2164

    
2165
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2166
    LANGUAGE plpgsql
2167
    AS $$
2168
DECLARE
2169
	errors_ct integer = 0;
2170
	loop_var loop_type_null%TYPE;
2171
BEGIN
2172
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2173
	LOOP
2174
		BEGIN
2175
			EXECUTE loop_body_sql USING loop_var;
2176
		EXCEPTION
2177
		WHEN OTHERS THEN
2178
			errors_ct = errors_ct+1;
2179
			PERFORM util.raise_error_warning(SQLERRM);
2180
		END;
2181
	END LOOP;
2182
	IF errors_ct > 0 THEN
2183
		-- can't raise exception because this would roll back the transaction
2184
		PERFORM util.raise_error_warning('there were '||errors_ct
2185
			||' errors: see the WARNINGs for details');
2186
	END IF;
2187
END;
2188
$$;
2189

    
2190

    
2191
--
2192
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2193
--
2194

    
2195
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2196
    LANGUAGE sql IMMUTABLE
2197
    AS $_$
2198
SELECT ltrim($1, $$
2199
$$)
2200
$_$;
2201

    
2202

    
2203
--
2204
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2205
--
2206

    
2207
CREATE FUNCTION map_filter_insert() RETURNS trigger
2208
    LANGUAGE plpgsql
2209
    AS $$
2210
BEGIN
2211
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2212
	RETURN new;
2213
END;
2214
$$;
2215

    
2216

    
2217
--
2218
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2219
--
2220

    
2221
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2222
    LANGUAGE plpgsql STABLE STRICT
2223
    AS $_$
2224
DECLARE
2225
    value text;
2226
BEGIN
2227
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2228
        INTO value USING key;
2229
    RETURN value;
2230
END;
2231
$_$;
2232

    
2233

    
2234
--
2235
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2236
--
2237

    
2238
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2239
    LANGUAGE sql IMMUTABLE
2240
    AS $_$
2241
SELECT util._map(util.nulls_map($1), $2)
2242
$_$;
2243

    
2244

    
2245
--
2246
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2247
--
2248

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

    
2252
[1] inlining of function calls, which is different from constant folding
2253
[2] _map()''s profiling query
2254
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2255
and map_nulls()''s profiling query
2256
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2257
both take ~920 ms.
2258
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.
2259
';
2260

    
2261

    
2262
--
2263
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2264
--
2265

    
2266
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2267
    LANGUAGE plpgsql STABLE STRICT
2268
    AS $_$
2269
BEGIN
2270
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2271
END;
2272
$_$;
2273

    
2274

    
2275
--
2276
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2277
--
2278

    
2279
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2280
    LANGUAGE sql
2281
    AS $_$
2282
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2283
$$||util.ltrim_nl($2));
2284
-- make sure the created table has the correct estimated row count
2285
SELECT util.analyze_($1);
2286

    
2287
SELECT util.append_comment($1, '
2288
contents generated from:
2289
'||util.ltrim_nl(util.runnable_sql($2))||';
2290
');
2291
$_$;
2292

    
2293

    
2294
--
2295
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2296
--
2297

    
2298
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2299
idempotent
2300
';
2301

    
2302

    
2303
--
2304
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2305
--
2306

    
2307
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2308
    LANGUAGE sql
2309
    AS $_$
2310
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2311
$_$;
2312

    
2313

    
2314
--
2315
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2316
--
2317

    
2318
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2319
idempotent
2320
';
2321

    
2322

    
2323
--
2324
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2325
--
2326

    
2327
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2328
    LANGUAGE sql
2329
    AS $_$
2330
SELECT util.create_if_not_exists($$
2331
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2332
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2333
||quote_literal($2)||$$;
2334
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2335
constant
2336
';
2337
$$)
2338
$_$;
2339

    
2340

    
2341
--
2342
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2343
--
2344

    
2345
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2346
idempotent
2347
';
2348

    
2349

    
2350
--
2351
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2352
--
2353

    
2354
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2355
    LANGUAGE plpgsql STRICT
2356
    AS $_$
2357
DECLARE
2358
    type regtype = util.typeof(expr, col.table_::text::regtype);
2359
    col_name_sql text = quote_ident(col.name);
2360
BEGIN
2361
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2362
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2363
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2364
$$||expr||$$;
2365
$$);
2366
END;
2367
$_$;
2368

    
2369

    
2370
--
2371
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2372
--
2373

    
2374
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2375
idempotent
2376
';
2377

    
2378

    
2379
--
2380
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382

    
2383
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
2384
    LANGUAGE sql IMMUTABLE
2385
    AS $_$
2386
SELECT
2387
$$SELECT
2388
$$||$3||$$
2389
FROM      $$||$1||$$ left_
2390
FULL JOIN $$||$2||$$ right_
2391
ON $$||$4||$$
2392
WHERE $$||$5||$$
2393
ORDER BY left_, right_
2394
$$
2395
$_$;
2396

    
2397

    
2398
--
2399
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2400
--
2401

    
2402
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2403
    LANGUAGE sql IMMUTABLE
2404
    AS $_$
2405
SELECT (util.regexp_match($1,
2406
'(?m)^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS ?)?$'))[1]
2407
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2408
	works properly (due to nonstandard Postgres regexp behavior:
2409
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2410
$_$;
2411

    
2412

    
2413
--
2414
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2415
--
2416

    
2417
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2418
    LANGUAGE sql
2419
    AS $_$
2420
-- keys()
2421
SELECT util.mk_keys_func($1, ARRAY(
2422
SELECT col FROM util.typed_cols($1) col
2423
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2424
));
2425

    
2426
-- values_()
2427
SELECT util.mk_keys_func($1, COALESCE(
2428
	NULLIF(ARRAY(
2429
	SELECT col FROM util.typed_cols($1) col
2430
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2431
	), ARRAY[]::util.col_cast[])
2432
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2433
, 'values_');
2434
$_$;
2435

    
2436

    
2437
--
2438
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2439
--
2440

    
2441
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2442
    LANGUAGE sql
2443
    AS $_$
2444
SELECT util.create_if_not_exists($$
2445
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2446
($$||util.mk_typed_cols_list($2)||$$);
2447
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2448
autogenerated
2449
';
2450
$$);
2451

    
2452
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2453
$_$;
2454

    
2455

    
2456
--
2457
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2458
--
2459

    
2460
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2461
    LANGUAGE sql
2462
    AS $_$
2463
SELECT util.create_if_not_exists($$
2464
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2465
||util.qual_name($1)||$$)
2466
  RETURNS $$||util.qual_name($2)||$$ AS
2467
$BODY1$
2468
SELECT ROW($$||
2469
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2470
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2471
$BODY1$
2472
  LANGUAGE sql IMMUTABLE
2473
  COST 100;
2474
$$);
2475
$_$;
2476

    
2477

    
2478
--
2479
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2480
--
2481

    
2482
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2483
    LANGUAGE sql
2484
    AS $_$
2485
SELECT util.create_if_not_exists($$
2486
CREATE TABLE $$||$1||$$
2487
(
2488
    LIKE util.map INCLUDING ALL
2489
);
2490

    
2491
CREATE TRIGGER map_filter_insert
2492
  BEFORE INSERT
2493
  ON $$||$1||$$
2494
  FOR EACH ROW
2495
  EXECUTE PROCEDURE util.map_filter_insert();
2496
$$)
2497
$_$;
2498

    
2499

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

    
2504
CREATE FUNCTION mk_not_null(text) RETURNS text
2505
    LANGUAGE sql IMMUTABLE
2506
    AS $_$
2507
SELECT COALESCE($1, '<NULL>')
2508
$_$;
2509

    
2510

    
2511
--
2512
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2513
--
2514

    
2515
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2516
    LANGUAGE sql IMMUTABLE
2517
    AS $_$
2518
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2519
util.qual_name((unnest).type), ''), '')
2520
FROM unnest($1)
2521
$_$;
2522

    
2523

    
2524
--
2525
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2526
--
2527

    
2528
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2529
    LANGUAGE sql IMMUTABLE
2530
    AS $_$
2531
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2532
$_$;
2533

    
2534

    
2535
--
2536
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2537
--
2538

    
2539
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2540
auto-appends util to the search_path to enable use of util operators
2541
';
2542

    
2543

    
2544
--
2545
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2546
--
2547

    
2548
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2549
    LANGUAGE sql STABLE
2550
    AS $_$
2551
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2552
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2553
$_$;
2554

    
2555

    
2556
--
2557
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2558
--
2559

    
2560
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2561
    LANGUAGE sql STABLE
2562
    AS $_$
2563
SELECT util.show_grants_for($1)
2564
||util.show_set_comment($1)||$$
2565
$$
2566
$_$;
2567

    
2568

    
2569
--
2570
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2571
--
2572

    
2573
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2574
    LANGUAGE sql IMMUTABLE
2575
    AS $_$
2576
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2582
--
2583

    
2584
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2585
    LANGUAGE sql IMMUTABLE
2586
    AS $_$
2587
/* debug_print_return_value() needed because this function is used with EXECUTE
2588
rather than util.eval() (in order to affect the calling function), so the
2589
search_path would not otherwise be printed */
2590
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2591
||$$ search_path TO $$||$1
2592
$_$;
2593

    
2594

    
2595
--
2596
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2597
--
2598

    
2599
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2600
    LANGUAGE sql
2601
    AS $_$
2602
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2603
$_$;
2604

    
2605

    
2606
--
2607
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2608
--
2609

    
2610
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2611
idempotent
2612
';
2613

    
2614

    
2615
--
2616
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2617
--
2618

    
2619
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2620
    LANGUAGE plpgsql STRICT
2621
    AS $_$
2622
DECLARE
2623
	view_qual_name text = util.qual_name(view_);
2624
BEGIN
2625
	EXECUTE $$
2626
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2627
  RETURNS SETOF $$||view_||$$ AS
2628
$BODY1$
2629
SELECT * FROM $$||view_qual_name||$$
2630
ORDER BY sort_col
2631
LIMIT $1 OFFSET $2
2632
$BODY1$
2633
  LANGUAGE sql STABLE
2634
  COST 100
2635
  ROWS 1000
2636
$$;
2637
	
2638
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2639
END;
2640
$_$;
2641

    
2642

    
2643
--
2644
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2645
--
2646

    
2647
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2648
    LANGUAGE plpgsql STRICT
2649
    AS $_$
2650
DECLARE
2651
	view_qual_name text = util.qual_name(view_);
2652
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2653
BEGIN
2654
	EXECUTE $$
2655
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2656
  RETURNS integer AS
2657
$BODY1$
2658
SELECT $$||quote_ident(row_num_col)||$$
2659
FROM $$||view_qual_name||$$
2660
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2661
LIMIT 1
2662
$BODY1$
2663
  LANGUAGE sql STABLE
2664
  COST 100;
2665
$$;
2666
	
2667
	EXECUTE $$
2668
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2669
  RETURNS SETOF $$||view_||$$ AS
2670
$BODY1$
2671
SELECT * FROM $$||view_qual_name||$$
2672
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2673
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2674
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2675
ORDER BY $$||quote_ident(row_num_col)||$$
2676
$BODY1$
2677
  LANGUAGE sql STABLE
2678
  COST 100
2679
  ROWS 1000
2680
$$;
2681
	
2682
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2683
END;
2684
$_$;
2685

    
2686

    
2687
--
2688
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2689
--
2690

    
2691
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2692
    LANGUAGE plpgsql STRICT
2693
    AS $_$
2694
DECLARE
2695
	view_qual_name text = util.qual_name(view_);
2696
BEGIN
2697
	EXECUTE $$
2698
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2699
  RETURNS SETOF $$||view_||$$
2700
  SET enable_sort TO 'off'
2701
  AS
2702
$BODY1$
2703
SELECT * FROM $$||view_qual_name||$$($2, $3)
2704
$BODY1$
2705
  LANGUAGE sql STABLE
2706
  COST 100
2707
  ROWS 1000
2708
;
2709
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2710
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2711
If you want to run EXPLAIN and get expanded output, use the regular subset
2712
function instead. (When a config param is set on a function, EXPLAIN produces
2713
just a function scan.)
2714
';
2715
$$;
2716
END;
2717
$_$;
2718

    
2719

    
2720
--
2721
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2722
--
2723

    
2724
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2725
creates subset function which turns off enable_sort
2726
';
2727

    
2728

    
2729
--
2730
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2731
--
2732

    
2733
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2734
    LANGUAGE sql IMMUTABLE
2735
    AS $_$
2736
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2737
util.qual_name((unnest).type), ', '), '')
2738
FROM unnest($1)
2739
$_$;
2740

    
2741

    
2742
--
2743
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2744
--
2745

    
2746
CREATE FUNCTION name(table_ regclass) RETURNS text
2747
    LANGUAGE sql STABLE
2748
    AS $_$
2749
SELECT relname::text FROM pg_class WHERE oid = $1
2750
$_$;
2751

    
2752

    
2753
--
2754
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2755
--
2756

    
2757
CREATE FUNCTION name(type regtype) RETURNS text
2758
    LANGUAGE sql STABLE
2759
    AS $_$
2760
SELECT typname::text FROM pg_type WHERE oid = $1
2761
$_$;
2762

    
2763

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

    
2768
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2769
    LANGUAGE sql IMMUTABLE
2770
    AS $_$
2771
SELECT octet_length($1) >= util.namedatalen() - $2
2772
$_$;
2773

    
2774

    
2775
--
2776
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2777
--
2778

    
2779
CREATE FUNCTION namedatalen() RETURNS integer
2780
    LANGUAGE sql IMMUTABLE
2781
    AS $$
2782
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2783
$$;
2784

    
2785

    
2786
--
2787
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2788
--
2789

    
2790
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2791
    LANGUAGE sql IMMUTABLE
2792
    AS $_$
2793
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2794
$_$;
2795

    
2796

    
2797
--
2798
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2799
--
2800

    
2801
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2802
    LANGUAGE sql IMMUTABLE
2803
    AS $_$
2804
SELECT $1 IS NOT NULL
2805
$_$;
2806

    
2807

    
2808
--
2809
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2810
--
2811

    
2812
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2813
    LANGUAGE sql IMMUTABLE
2814
    AS $_$
2815
SELECT util.hstore($1, NULL) || '*=>*'
2816
$_$;
2817

    
2818

    
2819
--
2820
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2821
--
2822

    
2823
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2824
for use with _map()
2825
';
2826

    
2827

    
2828
--
2829
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2830
--
2831

    
2832
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2833
    LANGUAGE sql IMMUTABLE
2834
    AS $_$
2835
SELECT $2 + COALESCE($1, 0)
2836
$_$;
2837

    
2838

    
2839
--
2840
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2841
--
2842

    
2843
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2844
    LANGUAGE sql STABLE
2845
    AS $_$
2846
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2847
$_$;
2848

    
2849

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

    
2854
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2855
    LANGUAGE sql
2856
    AS $_$
2857
SELECT util.eval($$INSERT INTO $$||$1||$$
2858
$$||util.ltrim_nl($2));
2859
-- make sure the created table has the correct estimated row count
2860
SELECT util.analyze_($1);
2861
$_$;
2862

    
2863

    
2864
--
2865
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2866
--
2867

    
2868
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2869
    LANGUAGE sql IMMUTABLE
2870
    AS $_$
2871
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2872
$_$;
2873

    
2874

    
2875
--
2876
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2877
--
2878

    
2879
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2880
    LANGUAGE sql
2881
    AS $_$
2882
SELECT util.set_comment($1, concat($2, util.comment($1)))
2883
$_$;
2884

    
2885

    
2886
--
2887
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2888
--
2889

    
2890
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2891
comment: must start and end with a newline
2892
';
2893

    
2894

    
2895
--
2896
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2897
--
2898

    
2899
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2900
    LANGUAGE sql IMMUTABLE
2901
    AS $_$
2902
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2903
$_$;
2904

    
2905

    
2906
--
2907
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2908
--
2909

    
2910
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2911
    LANGUAGE sql STABLE
2912
    SET search_path TO pg_temp
2913
    AS $_$
2914
SELECT $1::text
2915
$_$;
2916

    
2917

    
2918
--
2919
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2920
--
2921

    
2922
CREATE FUNCTION qual_name(type regtype) RETURNS text
2923
    LANGUAGE sql STABLE
2924
    SET search_path TO pg_temp
2925
    AS $_$
2926
SELECT $1::text
2927
$_$;
2928

    
2929

    
2930
--
2931
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2932
--
2933

    
2934
COMMENT ON FUNCTION qual_name(type regtype) IS '
2935
a type''s schema-qualified name
2936
';
2937

    
2938

    
2939
--
2940
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2941
--
2942

    
2943
CREATE FUNCTION qual_name(type unknown) RETURNS text
2944
    LANGUAGE sql STABLE
2945
    AS $_$
2946
SELECT util.qual_name($1::text::regtype)
2947
$_$;
2948

    
2949

    
2950
--
2951
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2952
--
2953

    
2954
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2955
    LANGUAGE sql IMMUTABLE
2956
    AS $_$
2957
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2958
$_$;
2959

    
2960

    
2961
--
2962
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2963
--
2964

    
2965
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2966
    LANGUAGE sql IMMUTABLE
2967
    AS $_$
2968
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2969
$_$;
2970

    
2971

    
2972
--
2973
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2974
--
2975

    
2976
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2977
    LANGUAGE sql IMMUTABLE
2978
    AS $_$
2979
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2980
$_$;
2981

    
2982

    
2983
--
2984
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2985
--
2986

    
2987
CREATE FUNCTION raise(type text, msg text) RETURNS void
2988
    LANGUAGE sql IMMUTABLE
2989
    AS $_X$
2990
SELECT util.eval($$
2991
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2992
  RETURNS void AS
2993
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2994
$__BODY1$
2995
BEGIN
2996
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2997
END;
2998
$__BODY1$
2999
  LANGUAGE plpgsql IMMUTABLE
3000
  COST 100;
3001
$$, verbose_ := false);
3002

    
3003
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3004
$_X$;
3005

    
3006

    
3007
--
3008
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3009
--
3010

    
3011
COMMENT ON FUNCTION raise(type text, msg text) IS '
3012
type: a log level from
3013
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3014
or a condition name from
3015
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3016
';
3017

    
3018

    
3019
--
3020
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3021
--
3022

    
3023
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3024
    LANGUAGE sql IMMUTABLE
3025
    AS $_$
3026
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3027
$_$;
3028

    
3029

    
3030
--
3031
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3032
--
3033

    
3034
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3035
    LANGUAGE plpgsql IMMUTABLE STRICT
3036
    AS $$
3037
BEGIN
3038
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3039
END;
3040
$$;
3041

    
3042

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

    
3047
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3048
    LANGUAGE plpgsql
3049
    AS $_$
3050
DECLARE
3051
	PG_EXCEPTION_DETAIL text;
3052
	restore_views_info util.restore_views_info;
3053
BEGIN
3054
	restore_views_info = util.save_drop_views(users);
3055
	PERFORM util.eval(cmd);
3056
	PERFORM util.restore_views(restore_views_info);
3057
EXCEPTION
3058
WHEN dependent_objects_still_exist THEN
3059
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3060
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3061
	users = array(SELECT * FROM util.regexp_matches_group(
3062
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3063
		-- will be in forward dependency order
3064
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3065
	PERFORM util.debug_print_var('users', users);
3066
	IF util.is_empty(users) THEN RAISE; END IF;
3067
	PERFORM util.recreate(cmd, users);
3068
END;
3069
$_$;
3070

    
3071

    
3072
--
3073
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3074
--
3075

    
3076
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3077
usage:
3078
SELECT util.recreate($$
3079
-- trigger the dependent_objects_still_exist exception
3080
DROP VIEW schemas.main_view; -- *not* CASCADE; it must trigger an exception
3081

    
3082
CREATE VIEW schemas.main_view AS _;
3083

    
3084
-- manually restore views that need to be updated for the changes
3085
CREATE VIEW schemas.dependent_view AS _;
3086
$$);
3087

    
3088
idempotent
3089

    
3090
users: not necessary to provide this because it will be autopopulated
3091
';
3092

    
3093

    
3094
--
3095
-- Name: regexp_match(text, text); Type: FUNCTION; Schema: util; Owner: -
3096
--
3097

    
3098
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3099
    LANGUAGE sql IMMUTABLE
3100
    AS $_$
3101
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3102
$_$;
3103

    
3104

    
3105
--
3106
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3107
--
3108

    
3109
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3110
    LANGUAGE sql IMMUTABLE
3111
    AS $_$
3112
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3113
$_$;
3114

    
3115

    
3116
--
3117
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3118
--
3119

    
3120
CREATE FUNCTION regexp_quote(str text) RETURNS text
3121
    LANGUAGE sql IMMUTABLE
3122
    AS $_$
3123
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3124
$_$;
3125

    
3126

    
3127
--
3128
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3129
--
3130

    
3131
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3132
    LANGUAGE sql IMMUTABLE
3133
    AS $_$
3134
SELECT (CASE WHEN right($1, 1) = ')'
3135
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3136
$_$;
3137

    
3138

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

    
3143
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3144
    LANGUAGE sql STABLE
3145
    AS $_$
3146
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3147
$_$;
3148

    
3149

    
3150
--
3151
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3152
--
3153

    
3154
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3155
    LANGUAGE sql STABLE
3156
    AS $_$
3157
SELECT util.relation_type(util.relation_type_char($1))
3158
$_$;
3159

    
3160

    
3161
--
3162
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3163
--
3164

    
3165
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3166
    LANGUAGE sql IMMUTABLE
3167
    AS $_$
3168
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3169
$_$;
3170

    
3171

    
3172
--
3173
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3174
--
3175

    
3176
CREATE FUNCTION relation_type(type regtype) RETURNS text
3177
    LANGUAGE sql IMMUTABLE
3178
    AS $$
3179
SELECT 'TYPE'::text
3180
$$;
3181

    
3182

    
3183
--
3184
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3185
--
3186

    
3187
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3188
    LANGUAGE sql STABLE
3189
    AS $_$
3190
SELECT relkind FROM pg_class WHERE oid = $1
3191
$_$;
3192

    
3193

    
3194
--
3195
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3196
--
3197

    
3198
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3199
    LANGUAGE sql
3200
    AS $_$
3201
/* can't have in_table/out_table inherit from *each other*, because inheritance
3202
also causes the rows of the parent table to be included in the child table.
3203
instead, they need to inherit from a common, empty table. */
3204
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3205
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3206
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3207
SELECT util.inherit($2, $4);
3208
SELECT util.inherit($3, $4);
3209

    
3210
SELECT util.rematerialize_query($1, $$
3211
SELECT * FROM util.diff(
3212
  $$||util.quote_typed($2)||$$
3213
, $$||util.quote_typed($3)||$$
3214
, NULL::$$||$4||$$)
3215
$$);
3216

    
3217
/* the table unfortunately cannot be *materialized* in human-readable form,
3218
because this would create column name collisions between the two sides */
3219
SELECT util.prepend_comment($1, '
3220
to view this table in human-readable form (with each side''s tuple column
3221
expanded to its component fields):
3222
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3223

    
3224
to display NULL values that are extra or missing:
3225
SELECT * FROM '||$1||';
3226
');
3227
$_$;
3228

    
3229

    
3230
--
3231
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3232
--
3233

    
3234
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3235
type_table (*required*): table to create as the shared base type
3236
';
3237

    
3238

    
3239
--
3240
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3241
--
3242

    
3243
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3244
    LANGUAGE sql
3245
    AS $_$
3246
SELECT util.drop_table($1);
3247
SELECT util.materialize_query($1, $2);
3248
$_$;
3249

    
3250

    
3251
--
3252
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3253
--
3254

    
3255
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3256
idempotent, but repeats action each time
3257
';
3258

    
3259

    
3260
--
3261
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3262
--
3263

    
3264
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3265
    LANGUAGE sql
3266
    AS $_$
3267
SELECT util.drop_table($1);
3268
SELECT util.materialize_view($1, $2);
3269
$_$;
3270

    
3271

    
3272
--
3273
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3274
--
3275

    
3276
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3277
idempotent, but repeats action each time
3278
';
3279

    
3280

    
3281
--
3282
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3283
--
3284

    
3285
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3286
    LANGUAGE sql
3287
    AS $_$
3288
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3289
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3290
FROM util.col_names($1::text::regtype) f (name);
3291
SELECT NULL::void; -- don't fold away functions called in previous query
3292
$_$;
3293

    
3294

    
3295
--
3296
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3297
--
3298

    
3299
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3300
idempotent
3301
';
3302

    
3303

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

    
3308
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3309
    LANGUAGE sql
3310
    AS $_$
3311
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3312
included in the debug SQL */
3313
SELECT util.rename_relation(util.qual_name($1), $2)
3314
$_$;
3315

    
3316

    
3317
--
3318
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3319
--
3320

    
3321
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3322
    LANGUAGE sql
3323
    AS $_$
3324
/* 'ALTER TABLE can be used with views too'
3325
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3326
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3327
||quote_ident($2))
3328
$_$;
3329

    
3330

    
3331
--
3332
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3333
--
3334

    
3335
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3336
idempotent
3337
';
3338

    
3339

    
3340
--
3341
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3342
--
3343

    
3344
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3345
    LANGUAGE sql IMMUTABLE
3346
    AS $_$
3347
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3348
$_$;
3349

    
3350

    
3351
--
3352
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3353
--
3354

    
3355
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3356
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 
3357
';
3358

    
3359

    
3360
--
3361
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3362
--
3363

    
3364
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3365
    LANGUAGE sql
3366
    AS $_$
3367
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3368
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3369
SELECT util.set_col_names($1, $2);
3370
$_$;
3371

    
3372

    
3373
--
3374
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3375
--
3376

    
3377
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3378
idempotent.
3379
alters the names table, so it will need to be repopulated after running this function.
3380
';
3381

    
3382

    
3383
--
3384
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3385
--
3386

    
3387
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3388
    LANGUAGE sql
3389
    AS $_$
3390
SELECT util.drop_table($1);
3391
SELECT util.mk_map_table($1);
3392
$_$;
3393

    
3394

    
3395
--
3396
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3397
--
3398

    
3399
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3400
    LANGUAGE sql
3401
    AS $_$
3402
SELECT util.debug_print_var('views', $1);
3403
SELECT util.create_if_not_exists((view_).def, (view_).path)
3404
	/* need to specify view name for manual existence check, in case view def
3405
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3406
FROM unnest($1.views) view_; -- in forward dependency order
3407
	/* create_if_not_exists() rather than eval(), because cmd might manually
3408
	re-create a deleted dependent view, causing it to already exist */
3409
SELECT NULL::void; -- don't fold away functions called in previous query
3410
$_$;
3411

    
3412

    
3413
--
3414
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3415
--
3416

    
3417
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3418
    LANGUAGE sql
3419
    AS $_$
3420
SELECT util.drop_column($1, $2, force := true)
3421
$_$;
3422

    
3423

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

    
3428
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3429
    LANGUAGE sql IMMUTABLE
3430
    AS $_$
3431
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3432
$_$;
3433

    
3434

    
3435
--
3436
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3437
--
3438

    
3439
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3440
    LANGUAGE sql IMMUTABLE
3441
    AS $_$
3442
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3443
ELSE util.mk_set_search_path(for_printing := true)||$$;
3444
$$ END)||$1
3445
$_$;
3446

    
3447

    
3448
--
3449
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3450
--
3451

    
3452
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3453
    LANGUAGE plpgsql STRICT
3454
    AS $$
3455
DECLARE
3456
	result text = NULL;
3457
BEGIN
3458
	BEGIN
3459
		result = util.show_create_view(view_, replace := false);
3460
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3461
			(eg. invalid_table_definition), instead of the standard
3462
			duplicate_table exception caught by util.create_if_not_exists() */
3463
		PERFORM util.drop_view(view_);
3464
	EXCEPTION
3465
		WHEN undefined_table THEN NULL;
3466
	END;
3467
	RETURN result;
3468
END;
3469
$$;
3470

    
3471

    
3472
--
3473
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3474
--
3475

    
3476
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3477
    LANGUAGE sql
3478
    AS $_$
3479
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3480
SELECT (view_, util.save_drop_view(view_))::util.db_item
3481
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3482
)))::util.restore_views_info
3483
$_$;
3484

    
3485

    
3486
--
3487
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3488
--
3489

    
3490
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3491
    LANGUAGE sql STABLE
3492
    AS $_$
3493
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3494
$_$;
3495

    
3496

    
3497
--
3498
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3499
--
3500

    
3501
CREATE FUNCTION schema(table_ regclass) RETURNS text
3502
    LANGUAGE sql STABLE
3503
    AS $_$
3504
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3505
$_$;
3506

    
3507

    
3508
--
3509
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3510
--
3511

    
3512
CREATE FUNCTION schema(type regtype) RETURNS text
3513
    LANGUAGE sql STABLE
3514
    AS $_$
3515
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3516
$_$;
3517

    
3518

    
3519
--
3520
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3521
--
3522

    
3523
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3524
    LANGUAGE sql STABLE
3525
    AS $_$
3526
SELECT util.schema(pg_typeof($1))
3527
$_$;
3528

    
3529

    
3530
--
3531
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3532
--
3533

    
3534
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3535
    LANGUAGE sql STABLE
3536
    AS $_$
3537
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3538
$_$;
3539

    
3540

    
3541
--
3542
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3543
--
3544

    
3545
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3546
a schema bundle is a group of schemas with a common prefix
3547
';
3548

    
3549

    
3550
--
3551
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3552
--
3553

    
3554
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3555
    LANGUAGE sql
3556
    AS $_$
3557
SELECT util.schema_rename(old_schema,
3558
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3559
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3560
SELECT NULL::void; -- don't fold away functions called in previous query
3561
$_$;
3562

    
3563

    
3564
--
3565
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3566
--
3567

    
3568
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3569
    LANGUAGE plpgsql
3570
    AS $$
3571
BEGIN
3572
	-- don't schema_bundle_rm() the schema_bundle to keep!
3573
	IF replace = with_ THEN RETURN; END IF;
3574
	
3575
	PERFORM util.schema_bundle_rm(replace);
3576
	PERFORM util.schema_bundle_rename(with_, replace);
3577
END;
3578
$$;
3579

    
3580

    
3581
--
3582
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3583
--
3584

    
3585
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3586
    LANGUAGE sql
3587
    AS $_$
3588
SELECT util.schema_rm(schema)
3589
FROM util.schema_bundle_get_schemas($1) f (schema);
3590
SELECT NULL::void; -- don't fold away functions called in previous query
3591
$_$;
3592

    
3593

    
3594
--
3595
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3596
--
3597

    
3598
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3599
    LANGUAGE sql STABLE
3600
    AS $_$
3601
SELECT quote_ident(util.schema($1))
3602
$_$;
3603

    
3604

    
3605
--
3606
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3607
--
3608

    
3609
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3610
    LANGUAGE sql IMMUTABLE
3611
    AS $_$
3612
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3613
$_$;
3614

    
3615

    
3616
--
3617
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3618
--
3619

    
3620
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3621
    LANGUAGE sql STABLE
3622
    AS $_$
3623
SELECT oid FROM pg_namespace WHERE nspname = $1
3624
$_$;
3625

    
3626

    
3627
--
3628
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3629
--
3630

    
3631
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3632
    LANGUAGE sql IMMUTABLE
3633
    AS $_$
3634
SELECT util.schema_regexp(schema_anchor := $1)
3635
$_$;
3636

    
3637

    
3638
--
3639
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3640
--
3641

    
3642
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3643
    LANGUAGE sql IMMUTABLE
3644
    AS $_$
3645
SELECT util.str_equality_regexp(util.schema($1))
3646
$_$;
3647

    
3648

    
3649
--
3650
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3651
--
3652

    
3653
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3654
    LANGUAGE sql
3655
    AS $_$
3656
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3657
$_$;
3658

    
3659

    
3660
--
3661
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3662
--
3663

    
3664
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3665
    LANGUAGE plpgsql
3666
    AS $$
3667
BEGIN
3668
	-- don't schema_rm() the schema to keep!
3669
	IF replace = with_ THEN RETURN; END IF;
3670
	
3671
	PERFORM util.schema_rm(replace);
3672
	PERFORM util.schema_rename(with_, replace);
3673
END;
3674
$$;
3675

    
3676

    
3677
--
3678
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3679
--
3680

    
3681
CREATE FUNCTION schema_rm(schema text) RETURNS void
3682
    LANGUAGE sql
3683
    AS $_$
3684
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3685
$_$;
3686

    
3687

    
3688
--
3689
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3690
--
3691

    
3692
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3693
    LANGUAGE sql
3694
    AS $_$
3695
SELECT util.eval(
3696
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3697
$_$;
3698

    
3699

    
3700
--
3701
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3702
--
3703

    
3704
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3705
    LANGUAGE plpgsql STRICT
3706
    AS $_$
3707
DECLARE
3708
    old text[] = ARRAY(SELECT util.col_names(table_));
3709
    new text[] = ARRAY(SELECT util.map_values(names));
3710
BEGIN
3711
    old = old[1:array_length(new, 1)]; -- truncate to same length
3712
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3713
||$$ TO $$||quote_ident(value))
3714
    FROM each(hstore(old, new))
3715
    WHERE value != key -- not same name
3716
    ;
3717
END;
3718
$_$;
3719

    
3720

    
3721
--
3722
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3723
--
3724

    
3725
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3726
idempotent
3727
';
3728

    
3729

    
3730
--
3731
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3732
--
3733

    
3734
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3735
    LANGUAGE plpgsql STRICT
3736
    AS $_$
3737
DECLARE
3738
	row_ util.map;
3739
BEGIN
3740
	-- rename any metadata cols rather than re-adding them with new names
3741
	BEGIN
3742
		PERFORM util.set_col_names(table_, names);
3743
	EXCEPTION
3744
		WHEN array_subscript_error THEN -- selective suppress
3745
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3746
				-- metadata cols not yet added
3747
			ELSE RAISE;
3748
			END IF;
3749
	END;
3750
	
3751
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3752
	LOOP
3753
		PERFORM util.mk_const_col((table_, row_."to"),
3754
			substring(row_."from" from 2));
3755
	END LOOP;
3756
	
3757
	PERFORM util.set_col_names(table_, names);
3758
END;
3759
$_$;
3760

    
3761

    
3762
--
3763
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3764
--
3765

    
3766
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3767
idempotent.
3768
the metadata mappings must be *last* in the names table.
3769
';
3770

    
3771

    
3772
--
3773
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3774
--
3775

    
3776
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3777
    LANGUAGE sql
3778
    AS $_$
3779
SELECT util.eval(COALESCE(
3780
$$ALTER TABLE $$||$1||$$
3781
$$||(
3782
	SELECT
3783
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3784
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3785
, $$)
3786
	FROM
3787
	(
3788
		SELECT
3789
		  quote_ident(col_name) AS col_name_sql
3790
		, util.col_type(($1, col_name)) AS curr_type
3791
		, type AS target_type
3792
		FROM unnest($2)
3793
	) s
3794
	WHERE curr_type != target_type
3795
), ''))
3796
$_$;
3797

    
3798

    
3799
--
3800
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3801
--
3802

    
3803
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3804
idempotent
3805
';
3806

    
3807

    
3808
--
3809
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3810
--
3811

    
3812
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3813
    LANGUAGE sql
3814
    AS $_$
3815
SELECT util.eval(util.mk_set_comment($1, $2))
3816
$_$;
3817

    
3818

    
3819
--
3820
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3821
--
3822

    
3823
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3824
    LANGUAGE sql
3825
    AS $_$
3826
SELECT util.eval(util.mk_set_search_path($1, $2))
3827
$_$;
3828

    
3829

    
3830
--
3831
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3832
--
3833

    
3834
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
3835
    LANGUAGE sql STABLE
3836
    AS $_$
3837
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
3838
||$1||$$ AS
3839
$$||pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
3840
$$||util.mk_set_relation_metadata($1)
3841
$_$;
3842

    
3843

    
3844
--
3845
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3846
--
3847

    
3848
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3849
    LANGUAGE sql STABLE
3850
    AS $_$
3851
SELECT string_agg(cmd, '')
3852
FROM
3853
(
3854
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3855
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3856
$$ ELSE '' END) AS cmd
3857
	FROM util.grants_users() f (user_)
3858
) s
3859
$_$;
3860

    
3861

    
3862
--
3863
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3864
--
3865

    
3866
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['c'::text, 'r'::text, 'v'::text]) RETURNS SETOF regclass
3867
    LANGUAGE sql STABLE
3868
    AS $_$
3869
SELECT oid FROM pg_class
3870
WHERE relkind = ANY($3) AND relname ~ $1
3871
AND util.schema_matches(util.schema(relnamespace), $2)
3872
ORDER BY relname
3873
$_$;
3874

    
3875

    
3876
--
3877
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
3878
--
3879

    
3880
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
3881
    LANGUAGE sql STABLE
3882
    AS $_$
3883
SELECT util.mk_set_comment($1, util.comment($1))
3884
$_$;
3885

    
3886

    
3887
--
3888
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3889
--
3890

    
3891
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3892
    LANGUAGE sql STABLE
3893
    AS $_$
3894
SELECT oid
3895
FROM pg_type
3896
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3897
ORDER BY typname
3898
$_$;
3899

    
3900

    
3901
--
3902
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3903
--
3904

    
3905
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3906
    LANGUAGE sql STABLE
3907
    AS $_$
3908
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3909
$_$;
3910

    
3911

    
3912
--
3913
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3914
--
3915

    
3916
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3917
    LANGUAGE sql IMMUTABLE
3918
    AS $_$
3919
SELECT '^'||util.regexp_quote($1)||'$'
3920
$_$;
3921

    
3922

    
3923
--
3924
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3925
--
3926

    
3927
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3928
    LANGUAGE plpgsql STABLE STRICT
3929
    AS $_$
3930
DECLARE
3931
    hstore hstore;
3932
BEGIN
3933
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3934
        table_||$$))$$ INTO STRICT hstore;
3935
    RETURN hstore;
3936
END;
3937
$_$;
3938

    
3939

    
3940
--
3941
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3942
--
3943

    
3944
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3945
    LANGUAGE sql STABLE
3946
    AS $_$
3947
SELECT COUNT(*) > 0 FROM pg_constraint
3948
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3949
$_$;
3950

    
3951

    
3952
--
3953
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3954
--
3955

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

    
3960

    
3961
--
3962
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3963
--
3964

    
3965
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3966
    LANGUAGE sql
3967
    AS $_$
3968
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3969
||quote_ident($2)||$$ CHECK (true)$$)
3970
$_$;
3971

    
3972

    
3973
--
3974
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3975
--
3976

    
3977
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3978
stores a status flag by the presence of a table constraint.
3979
idempotent.
3980
';
3981

    
3982

    
3983
--
3984
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3985
--
3986

    
3987
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3988
    LANGUAGE sql STABLE
3989
    AS $_$
3990
SELECT util.table_flag__get($1, 'nulls_mapped')
3991
$_$;
3992

    
3993

    
3994
--
3995
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3996
--
3997

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

    
4002

    
4003
--
4004
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4005
--
4006

    
4007
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4008
    LANGUAGE sql
4009
    AS $_$
4010
SELECT util.table_flag__set($1, 'nulls_mapped')
4011
$_$;
4012

    
4013

    
4014
--
4015
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4016
--
4017

    
4018
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4019
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4020
idempotent.
4021
';
4022

    
4023

    
4024
--
4025
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
4026
--
4027

    
4028
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4029
    LANGUAGE sql
4030
    AS $_$
4031
-- save data before truncating main table
4032
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4033

    
4034
-- repopulate main table w/ copies column
4035
SELECT util.truncate($1);
4036
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4037
SELECT util.populate_table($1, $$
4038
SELECT (table_).*, copies
4039
FROM (
4040
	SELECT table_, COUNT(*) AS copies
4041
	FROM pg_temp.__copy table_
4042
	GROUP BY table_
4043
) s
4044
$$);
4045

    
4046
-- delete temp table so it doesn't stay around until end of connection
4047
SELECT util.drop_table('pg_temp.__copy');
4048
$_$;
4049

    
4050

    
4051
--
4052
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4053
--
4054

    
4055
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4056
    LANGUAGE plpgsql STRICT
4057
    AS $_$
4058
DECLARE
4059
    row record;
4060
BEGIN
4061
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4062
    LOOP
4063
        IF row.global_name != row.name THEN
4064
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4065
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4066
        END IF;
4067
    END LOOP;
4068
END;
4069
$_$;
4070

    
4071

    
4072
--
4073
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4074
--
4075

    
4076
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4077
idempotent
4078
';
4079

    
4080

    
4081
--
4082
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4083
--
4084

    
4085
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4086
    LANGUAGE sql
4087
    AS $_$
4088
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4089
SELECT NULL::void; -- don't fold away functions called in previous query
4090
$_$;
4091

    
4092

    
4093
--
4094
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4095
--
4096

    
4097
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
4098
trims table_ to include only columns in the original data
4099

    
4100
by default, cascadingly drops dependent columns so that they don''t prevent
4101
trim() from succeeding. note that this requires the dependent columns to then be
4102
manually re-created.
4103

    
4104
idempotent
4105
';
4106

    
4107

    
4108
--
4109
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4110
--
4111

    
4112
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4113
    LANGUAGE plpgsql STRICT
4114
    AS $_$
4115
BEGIN
4116
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4117
END;
4118
$_$;
4119

    
4120

    
4121
--
4122
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4123
--
4124

    
4125
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4126
idempotent
4127
';
4128

    
4129

    
4130
--
4131
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4132
--
4133

    
4134
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4135
    LANGUAGE sql IMMUTABLE
4136
    AS $_$
4137
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4138
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4139
$_$;
4140

    
4141

    
4142
--
4143
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4144
--
4145

    
4146
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4147
    LANGUAGE plpgsql IMMUTABLE
4148
    AS $$
4149
BEGIN
4150
	/* need explicit cast because some types not implicitly-castable, and also
4151
	to make the cast happen inside the try block. (*implicit* casts to the
4152
	return type happen at the end of the function, outside any block.) */
4153
	RETURN util.cast(value, ret_type_null);
4154
EXCEPTION
4155
WHEN   data_exception
4156
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4157
	THEN
4158
	PERFORM util.raise('WARNING', SQLERRM);
4159
	RETURN NULL;
4160
END;
4161
$$;
4162

    
4163

    
4164
--
4165
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4166
--
4167

    
4168
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4169
ret_type_null: NULL::ret_type
4170
';
4171

    
4172

    
4173
--
4174
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4175
--
4176

    
4177
CREATE FUNCTION try_create(sql text) RETURNS void
4178
    LANGUAGE plpgsql STRICT
4179
    AS $$
4180
BEGIN
4181
	PERFORM util.eval(sql);
4182
EXCEPTION
4183
WHEN   not_null_violation
4184
		/* trying to add NOT NULL column to parent table, which cascades to
4185
		child table whose values for the new column will be NULL */
4186
	OR wrong_object_type -- trying to alter a view's columns
4187
	OR undefined_column
4188
	OR duplicate_column
4189
THEN NULL;
4190
WHEN datatype_mismatch THEN
4191
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4192
	ELSE RAISE; -- rethrow
4193
	END IF;
4194
END;
4195
$$;
4196

    
4197

    
4198
--
4199
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4200
--
4201

    
4202
COMMENT ON FUNCTION try_create(sql text) IS '
4203
idempotent
4204
';
4205

    
4206

    
4207
--
4208
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4209
--
4210

    
4211
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4212
    LANGUAGE sql
4213
    AS $_$
4214
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4215
$_$;
4216

    
4217

    
4218
--
4219
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4220
--
4221

    
4222
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4223
idempotent
4224
';
4225

    
4226

    
4227
--
4228
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4229
--
4230

    
4231
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4232
    LANGUAGE sql IMMUTABLE
4233
    AS $_$
4234
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4235
$_$;
4236

    
4237

    
4238
--
4239
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4240
--
4241

    
4242
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4243
a type''s NOT NULL qualifier
4244
';
4245

    
4246

    
4247
--
4248
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4249
--
4250

    
4251
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4252
    LANGUAGE sql STABLE
4253
    AS $_$
4254
SELECT (attname::text, atttypid)::util.col_cast
4255
FROM pg_attribute
4256
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4257
ORDER BY attnum
4258
$_$;
4259

    
4260

    
4261
--
4262
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4263
--
4264

    
4265
CREATE FUNCTION typeof(value anyelement) RETURNS text
4266
    LANGUAGE sql IMMUTABLE
4267
    AS $_$
4268
SELECT util.qual_name(pg_typeof($1))
4269
$_$;
4270

    
4271

    
4272
--
4273
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4274
--
4275

    
4276
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4277
    LANGUAGE plpgsql STABLE
4278
    AS $_$
4279
DECLARE
4280
    type regtype;
4281
BEGIN
4282
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4283
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4284
    RETURN type;
4285
END;
4286
$_$;
4287

    
4288

    
4289
--
4290
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4291
--
4292

    
4293
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4294
    LANGUAGE sql
4295
    AS $_$
4296
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4297
$_$;
4298

    
4299

    
4300
--
4301
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4302
--
4303

    
4304
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4305
auto-appends util to the search_path to enable use of util operators
4306
';
4307

    
4308

    
4309
--
4310
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4311
--
4312

    
4313
CREATE AGGREGATE all_same(anyelement) (
4314
    SFUNC = all_same_transform,
4315
    STYPE = anyarray,
4316
    FINALFUNC = all_same_final
4317
);
4318

    
4319

    
4320
--
4321
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4322
--
4323

    
4324
COMMENT ON AGGREGATE all_same(anyelement) IS '
4325
includes NULLs in comparison
4326
';
4327

    
4328

    
4329
--
4330
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4331
--
4332

    
4333
CREATE AGGREGATE join_strs(text, text) (
4334
    SFUNC = join_strs_transform,
4335
    STYPE = text
4336
);
4337

    
4338

    
4339
--
4340
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4341
--
4342

    
4343
CREATE OPERATOR %== (
4344
    PROCEDURE = "%==",
4345
    LEFTARG = anyelement,
4346
    RIGHTARG = anyelement
4347
);
4348

    
4349

    
4350
--
4351
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4352
--
4353

    
4354
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4355
returns whether the map-keys of the compared values are the same
4356
(mnemonic: % is the Perl symbol for a hash map)
4357

    
4358
should be overridden for types that store both keys and values
4359

    
4360
used in a FULL JOIN to select which columns to join on
4361
';
4362

    
4363

    
4364
--
4365
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4366
--
4367

    
4368
CREATE OPERATOR -> (
4369
    PROCEDURE = map_get,
4370
    LEFTARG = regclass,
4371
    RIGHTARG = text
4372
);
4373

    
4374

    
4375
--
4376
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4377
--
4378

    
4379
CREATE OPERATOR => (
4380
    PROCEDURE = hstore,
4381
    LEFTARG = text[],
4382
    RIGHTARG = text
4383
);
4384

    
4385

    
4386
--
4387
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4388
--
4389

    
4390
COMMENT ON OPERATOR => (text[], text) IS '
4391
usage: array[''key1'', ...]::text[] => ''value''
4392
';
4393

    
4394

    
4395
--
4396
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4397
--
4398

    
4399
CREATE OPERATOR ?*>= (
4400
    PROCEDURE = is_populated_more_often_than,
4401
    LEFTARG = anyelement,
4402
    RIGHTARG = anyelement
4403
);
4404

    
4405

    
4406
--
4407
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4408
--
4409

    
4410
CREATE OPERATOR ?>= (
4411
    PROCEDURE = is_more_complete_than,
4412
    LEFTARG = anyelement,
4413
    RIGHTARG = anyelement
4414
);
4415

    
4416

    
4417
--
4418
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4419
--
4420

    
4421
CREATE OPERATOR ||% (
4422
    PROCEDURE = concat_esc,
4423
    LEFTARG = text,
4424
    RIGHTARG = text
4425
);
4426

    
4427

    
4428
--
4429
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4430
--
4431

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

    
4436

    
4437
--
4438
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4439
--
4440

    
4441
CREATE TABLE map (
4442
    "from" text NOT NULL,
4443
    "to" text,
4444
    filter text,
4445
    notes text
4446
);
4447

    
4448

    
4449
--
4450
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4451
--
4452

    
4453

    
4454

    
4455
--
4456
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4457
--
4458

    
4459

    
4460

    
4461
--
4462
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4463
--
4464

    
4465
ALTER TABLE ONLY map
4466
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4467

    
4468

    
4469
--
4470
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4471
--
4472

    
4473
ALTER TABLE ONLY map
4474
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4475

    
4476

    
4477
--
4478
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4479
--
4480

    
4481
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4482

    
4483

    
4484
--
4485
-- PostgreSQL database dump complete
4486
--
4487

    
(21-21/31)