Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

    
26
NOTE: SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding. avoiding use of STRICT also makes functions *much* easier to troubleshoot, because they won''t mysteriously do nothing if called with only NULL arguments, even when you have added debug-print statements.
27
';
28

    
29

    
30
SET search_path = util, pg_catalog;
31

    
32
--
33
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34
--
35

    
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40

    
41

    
42
--
43
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44
--
45

    
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50

    
51

    
52
--
53
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54
--
55

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

    
63

    
64
--
65
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66
--
67

    
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72

    
73

    
74
--
75
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

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

    
84

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

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

    
93

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

    
98
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
99
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102
$_$;
103

    
104

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

    
109
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
110
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117
    , ($3)
118
    , ($4)
119
    , ($5)
120
)
121
AS v (value)
122
$_$;
123

    
124

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

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

    
133

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

    
138
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152

    
153

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

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

    
172

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

    
177
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181
FROM
182
(VALUES
183
      ($1)
184
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189

    
190

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

    
195
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199
$_$;
200

    
201

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

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

    
212

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

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

    
225

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

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

    
236

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

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

    
247

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

    
252
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256
$_$;
257

    
258

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

    
263
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
264
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267
$_$;
268

    
269

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

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

    
280

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

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

    
291

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

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

    
306

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

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

    
331

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

    
336
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
337
    LANGUAGE sql IMMUTABLE
338
    AS $_$
339
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
340
$_$;
341

    
342

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

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

    
381

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

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

    
392

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

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

    
431

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

    
436
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
437
    LANGUAGE sql IMMUTABLE
438
    AS $_$
439
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
440
$_$;
441

    
442

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

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

    
453

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

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

    
464

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

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

    
475

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

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

    
501

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

    
506
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT bool_or(value)
510
FROM
511
(VALUES
512
      ($1)
513
    , ($2)
514
    , ($3)
515
    , ($4)
516
    , ($5)
517
)
518
AS v (value)
519
$_$;
520

    
521

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

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

    
530

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

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

    
541

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

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

    
552

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

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

    
570

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

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

    
579

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

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

    
590

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

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

    
607

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

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

    
618

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

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

    
629

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

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

    
638

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

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

    
649

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

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

    
660

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

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

    
671

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

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

    
680

    
681
--
682
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
683
--
684

    
685
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
686
    LANGUAGE sql
687
    AS $_$
688
SELECT CASE WHEN util.freq_always_1($1, $2)
689
THEN util.drop_column($1, $2, force := true)
690
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
691
END
692
$_$;
693

    
694

    
695
--
696
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
697
--
698

    
699
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
700
    LANGUAGE sql STABLE
701
    AS $_$
702
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
703
$_$;
704

    
705

    
706
--
707
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
708
--
709

    
710
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
711
    LANGUAGE plpgsql STRICT
712
    AS $_$
713
BEGIN
714
    -- not yet clustered (ARRAY[] compares NULLs literally)
715
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
716
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
717
    END IF;
718
END;
719
$_$;
720

    
721

    
722
--
723
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
724
--
725

    
726
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
727
idempotent
728
';
729

    
730

    
731
--
732
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
733
--
734

    
735
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
736
    LANGUAGE sql IMMUTABLE
737
    AS $_$
738
SELECT value
739
FROM unnest($1) value
740
WHERE value IS NOT NULL
741
LIMIT 1
742
$_$;
743

    
744

    
745
--
746
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
747
--
748

    
749
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
750
uses:
751
* coalescing array elements or rows together
752
* forcing evaluation of all values of a COALESCE()
753
';
754

    
755

    
756
--
757
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
758
--
759

    
760
CREATE FUNCTION col__min(col col_ref) RETURNS integer
761
    LANGUAGE sql STABLE
762
    AS $_$
763
SELECT util.eval2val($$
764
SELECT $$||quote_ident($1.name)||$$
765
FROM $$||$1.table_||$$
766
ORDER BY $$||quote_ident($1.name)||$$ ASC
767
LIMIT 1
768
$$, NULL::integer)
769
$_$;
770

    
771

    
772
--
773
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
774
--
775

    
776
CREATE FUNCTION col_comment(col col_ref) RETURNS text
777
    LANGUAGE plpgsql STABLE STRICT
778
    AS $$
779
DECLARE
780
	comment text;
781
BEGIN
782
	SELECT description
783
	FROM pg_attribute
784
	LEFT JOIN pg_description ON objoid = attrelid
785
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
786
	WHERE attrelid = col.table_ AND attname = col.name
787
	INTO STRICT comment
788
	;
789
	RETURN comment;
790
EXCEPTION
791
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
792
END;
793
$$;
794

    
795

    
796
--
797
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
798
--
799

    
800
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
801
    LANGUAGE plpgsql STABLE STRICT
802
    AS $$
803
DECLARE
804
	default_sql text;
805
BEGIN
806
	SELECT adsrc
807
	FROM pg_attribute
808
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
809
	WHERE attrelid = col.table_ AND attname = col.name
810
	INTO STRICT default_sql
811
	;
812
	RETURN default_sql;
813
EXCEPTION
814
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
815
END;
816
$$;
817

    
818

    
819
--
820
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
821
--
822

    
823
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
824
    LANGUAGE sql STABLE
825
    AS $_$
826
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
827
$_$;
828

    
829

    
830
--
831
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
832
--
833

    
834
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
835
ret_type_null: NULL::ret_type
836
';
837

    
838

    
839
--
840
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
841
--
842

    
843
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
844
    LANGUAGE plpgsql STRICT
845
    AS $$
846
BEGIN
847
    PERFORM util.col_type(col);
848
    RETURN true;
849
EXCEPTION
850
    WHEN undefined_column THEN RETURN false;
851
END;
852
$$;
853

    
854

    
855
--
856
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
857
--
858

    
859
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
860
    LANGUAGE plpgsql STABLE STRICT
861
    AS $$
862
DECLARE
863
    prefix text := util.name(type)||'.';
864
BEGIN
865
    RETURN QUERY
866
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
867
        FROM util.col_names(type) f (name_);
868
END;
869
$$;
870

    
871

    
872
--
873
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
874
--
875

    
876
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
877
    LANGUAGE sql STABLE
878
    AS $_$
879
SELECT attname::text
880
FROM pg_attribute
881
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
882
ORDER BY attnum
883
$_$;
884

    
885

    
886
--
887
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
888
--
889

    
890
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
891
    LANGUAGE plpgsql STABLE STRICT
892
    AS $_$
893
BEGIN
894
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
895
END;
896
$_$;
897

    
898

    
899
--
900
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
901
--
902

    
903
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
904
    LANGUAGE plpgsql STABLE STRICT
905
    AS $$
906
DECLARE
907
    type regtype;
908
BEGIN
909
    SELECT atttypid FROM pg_attribute
910
    WHERE attrelid = col.table_ AND attname = col.name
911
    INTO STRICT type
912
    ;
913
    RETURN type;
914
EXCEPTION
915
    WHEN no_data_found THEN
916
        RAISE undefined_column USING MESSAGE =
917
            concat('undefined column: ', col.name);
918
END;
919
$$;
920

    
921

    
922
--
923
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
924
--
925

    
926
CREATE FUNCTION comment(element oid) RETURNS text
927
    LANGUAGE sql STABLE
928
    AS $_$
929
SELECT description FROM pg_description WHERE objoid = $1
930
$_$;
931

    
932

    
933
--
934
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
935
--
936

    
937
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
938
    LANGUAGE sql IMMUTABLE
939
    AS $_$
940
SELECT util.esc_name__append($2, $1)
941
$_$;
942

    
943

    
944
--
945
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
946
--
947

    
948
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
949
    LANGUAGE sql IMMUTABLE
950
    AS $_$
951
SELECT position($1 in $2) > 0 /*1-based offset*/
952
$_$;
953

    
954

    
955
--
956
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
957
--
958

    
959
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
960
    LANGUAGE sql
961
    AS $_$
962
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
963
$_$;
964

    
965

    
966
--
967
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
968
--
969

    
970
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
971
    LANGUAGE sql
972
    AS $_$
973
SELECT util.materialize_view($2, $1)
974
$_$;
975

    
976

    
977
--
978
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
979
--
980

    
981
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
982
    LANGUAGE plpgsql STRICT
983
    AS $$
984
BEGIN
985
	PERFORM util.eval(sql);
986
EXCEPTION
987
WHEN   duplicate_table
988
	OR duplicate_object -- eg. constraint
989
	OR duplicate_column
990
	OR duplicate_function
991
THEN NULL;
992
WHEN invalid_table_definition THEN
993
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
994
	ELSE RAISE;
995
	END IF;
996
END;
997
$$;
998

    
999

    
1000
--
1001
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
1002
--
1003

    
1004
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
1005
idempotent
1006
';
1007

    
1008

    
1009
--
1010
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1011
--
1012

    
1013
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1014
    LANGUAGE sql STABLE
1015
    AS $$
1016
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1017
$$;
1018

    
1019

    
1020
--
1021
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1022
--
1023

    
1024
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1025
    LANGUAGE sql IMMUTABLE
1026
    AS $_$
1027
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1028
$_$;
1029

    
1030

    
1031
--
1032
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1033
--
1034

    
1035
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1036
    LANGUAGE sql IMMUTABLE
1037
    AS $_$
1038
SELECT util.raise('NOTICE', 'returns: '
1039
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
1040
SELECT $1;
1041
$_$;
1042

    
1043

    
1044
--
1045
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047

    
1048
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1049
    LANGUAGE sql IMMUTABLE
1050
    AS $_$
1051
/* newline before so the query starts at the beginning of the line.
1052
newline after to visually separate queries from one another. */
1053
SELECT util.raise('NOTICE', $$
1054
$$||util.runnable_sql($1)||$$
1055
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1056
$_$;
1057

    
1058

    
1059
--
1060
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1061
--
1062

    
1063
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1064
    LANGUAGE sql STABLE
1065
    AS $_$
1066
SELECT util.eval2set($$
1067
SELECT col
1068
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1069
LEFT JOIN $$||$2||$$ ON "to" = col
1070
WHERE "from" IS NULL
1071
$$, NULL::text)
1072
$_$;
1073

    
1074

    
1075
--
1076
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1077
--
1078

    
1079
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1080
gets table_''s derived columns (all the columns not in the names table)
1081
';
1082

    
1083

    
1084
--
1085
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1086
--
1087

    
1088
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1089
    LANGUAGE sql
1090
    AS $_$
1091
-- create a diff when the # of copies of a row differs between the tables
1092
SELECT util.to_freq($1);
1093
SELECT util.to_freq($2);
1094
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1095

    
1096
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1097
$_$;
1098

    
1099

    
1100
--
1101
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1102
--
1103

    
1104
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1105
usage:
1106
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1107

    
1108
col_type_null (*required*): NULL::shared_base_type
1109
';
1110

    
1111

    
1112
--
1113
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1114
--
1115

    
1116
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
1117
    LANGUAGE plpgsql
1118
    SET search_path TO pg_temp
1119
    AS $_$
1120
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1121
changes of search_path (schema elements are bound at inline time rather than
1122
runtime) */
1123
/* function option search_path is needed to limit the effects of
1124
`SET LOCAL search_path` to the current function */
1125
BEGIN
1126
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1127
	
1128
	PERFORM util.mk_keys_func(pg_typeof($3));
1129
	RETURN QUERY
1130
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1131
$$/* need to explicitly cast each side to the return type because this does not
1132
happen automatically even when an implicit cast is available */
1133
  left_::$$||util.typeof($3)||$$
1134
, right_::$$||util.typeof($3)
1135
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1136
the *same* base type, *even though* this is optional when using a custom %== */
1137
, util._if($4, $$true/*= CROSS JOIN*/$$,
1138
$$ left_::$$||util.typeof($3)||$$
1139
%== right_::$$||util.typeof($3)||$$
1140
	-- refer to EXPLAIN output for expansion of %==$$
1141
)
1142
,     $$         left_::$$||util.typeof($3)||$$
1143
IS DISTINCT FROM right_::$$||util.typeof($3)
1144
), $3)
1145
	;
1146
END;
1147
$_$;
1148

    
1149

    
1150
--
1151
-- 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: -
1152
--
1153

    
1154
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1155
col_type_null (*required*): NULL::col_type
1156
single_row: whether the tables consist of a single row, which should be
1157
	displayed side-by-side
1158

    
1159
to match up rows using a subset of the columns, create a custom keys() function
1160
which returns this subset as a record:
1161
-- note that OUT parameters for the returned fields are *not* needed
1162
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1163
  RETURNS record AS
1164
$BODY$
1165
SELECT ($1.key_field_0, $1.key_field_1)
1166
$BODY$
1167
  LANGUAGE sql IMMUTABLE
1168
  COST 100;
1169

    
1170

    
1171
to run EXPLAIN on the FULL JOIN query:
1172
# run this function
1173
# look for a NOTICE containing the expanded query that it ran
1174
# run EXPLAIN on this expanded query
1175
';
1176

    
1177

    
1178
--
1179
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1180
--
1181

    
1182
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
1183
    LANGUAGE sql
1184
    AS $_$
1185
SELECT * FROM util.diff($1::text, $2::text, $3,
1186
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1187
$_$;
1188

    
1189

    
1190
--
1191
-- 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: -
1192
--
1193

    
1194
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1195
helper function used by diff(regclass, regclass)
1196

    
1197
usage:
1198
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1199

    
1200
col_type_null (*required*): NULL::shared_base_type
1201
';
1202

    
1203

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

    
1208
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1209
    LANGUAGE sql
1210
    AS $_$
1211
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1212
$_$;
1213

    
1214

    
1215
--
1216
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1217
--
1218

    
1219
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1220
idempotent
1221
';
1222

    
1223

    
1224
--
1225
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1226
--
1227

    
1228
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1229
    LANGUAGE sql
1230
    AS $_$
1231
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1232
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1233
$_$;
1234

    
1235

    
1236
--
1237
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1238
--
1239

    
1240
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1241
idempotent
1242
';
1243

    
1244

    
1245
--
1246
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1247
--
1248

    
1249
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1250
    LANGUAGE sql
1251
    AS $_$
1252
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_
1253
$_$;
1254

    
1255

    
1256
--
1257
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1258
--
1259

    
1260
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1261
idempotent
1262
';
1263

    
1264

    
1265
--
1266
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1267
--
1268

    
1269
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1270
    LANGUAGE sql
1271
    AS $_$
1272
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1273
included in the debug SQL */
1274
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1275
$_$;
1276

    
1277

    
1278
--
1279
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1280
--
1281

    
1282
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1283
    LANGUAGE sql
1284
    AS $_$
1285
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1286
||util._if($3, $$ CASCADE$$, ''::text))
1287
$_$;
1288

    
1289

    
1290
--
1291
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1292
--
1293

    
1294
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1295
idempotent
1296
';
1297

    
1298

    
1299
--
1300
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1301
--
1302

    
1303
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1304
    LANGUAGE sql
1305
    AS $_$
1306
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1307
$_$;
1308

    
1309

    
1310
--
1311
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1312
--
1313

    
1314
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1315
    LANGUAGE sql
1316
    AS $_$
1317
SELECT util.debug_print_func_call(util.quote_func_call(
1318
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1319
util.quote_typed($3)))
1320
;
1321
SELECT util.drop_relation(relation, $3)
1322
FROM util.show_relations_like($1, $2) relation
1323
;
1324
SELECT NULL::void; -- don't fold away functions called in previous query
1325
$_$;
1326

    
1327

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

    
1332
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1333
    LANGUAGE sql
1334
    AS $_$
1335
SELECT util.drop_relation('TABLE', $1, $2)
1336
$_$;
1337

    
1338

    
1339
--
1340
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1341
--
1342

    
1343
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1344
idempotent
1345
';
1346

    
1347

    
1348
--
1349
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1350
--
1351

    
1352
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1353
    LANGUAGE sql
1354
    AS $_$
1355
SELECT util.drop_relation('VIEW', $1, $2)
1356
$_$;
1357

    
1358

    
1359
--
1360
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1361
--
1362

    
1363
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1364
idempotent
1365
';
1366

    
1367

    
1368
--
1369
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1370
--
1371

    
1372
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1373
    LANGUAGE sql IMMUTABLE
1374
    AS $_$
1375
SELECT util.array_fill($1, 0)
1376
$_$;
1377

    
1378

    
1379
--
1380
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1381
--
1382

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

    
1387

    
1388
--
1389
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1390
--
1391

    
1392
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1393
    LANGUAGE sql IMMUTABLE
1394
    AS $_$
1395
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1396
$_$;
1397

    
1398

    
1399
--
1400
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1401
--
1402

    
1403
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1404
    LANGUAGE sql IMMUTABLE
1405
    AS $_$
1406
SELECT regexp_replace($2, '("?)$', $1||'\1')
1407
$_$;
1408

    
1409

    
1410
--
1411
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1412
--
1413

    
1414
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1415
    LANGUAGE plpgsql
1416
    AS $$
1417
BEGIN
1418
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1419
	EXECUTE sql;
1420
END;
1421
$$;
1422

    
1423

    
1424
--
1425
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1426
--
1427

    
1428
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1429
    LANGUAGE plpgsql
1430
    AS $$
1431
BEGIN
1432
	PERFORM util.debug_print_sql(sql);
1433
	RETURN QUERY EXECUTE sql;
1434
END;
1435
$$;
1436

    
1437

    
1438
--
1439
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1440
--
1441

    
1442
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1443
col_type_null (*required*): NULL::col_type
1444
';
1445

    
1446

    
1447
--
1448
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1449
--
1450

    
1451
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1452
    LANGUAGE plpgsql
1453
    AS $$
1454
BEGIN
1455
	PERFORM util.debug_print_sql(sql);
1456
	RETURN QUERY EXECUTE sql;
1457
END;
1458
$$;
1459

    
1460

    
1461
--
1462
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1463
--
1464

    
1465
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1466
    LANGUAGE plpgsql
1467
    AS $$
1468
BEGIN
1469
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1470
	RETURN QUERY EXECUTE sql;
1471
END;
1472
$$;
1473

    
1474

    
1475
--
1476
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1477
--
1478

    
1479
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1480
    LANGUAGE plpgsql STABLE
1481
    AS $$
1482
DECLARE
1483
	ret_val ret_type_null%TYPE;
1484
BEGIN
1485
	PERFORM util.debug_print_sql(sql);
1486
	EXECUTE sql INTO STRICT ret_val;
1487
	RETURN ret_val;
1488
END;
1489
$$;
1490

    
1491

    
1492
--
1493
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1494
--
1495

    
1496
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1497
ret_type_null: NULL::ret_type
1498
';
1499

    
1500

    
1501
--
1502
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1503
--
1504

    
1505
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1506
    LANGUAGE sql
1507
    AS $_$
1508
SELECT util.eval2val($$SELECT $$||$1, $2)
1509
$_$;
1510

    
1511

    
1512
--
1513
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1514
--
1515

    
1516
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1517
ret_type_null: NULL::ret_type
1518
';
1519

    
1520

    
1521
--
1522
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1523
--
1524

    
1525
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1526
    LANGUAGE sql
1527
    AS $_$
1528
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1529
$_$;
1530

    
1531

    
1532
--
1533
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1534
--
1535

    
1536
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1537
sql: can be NULL, which will be passed through
1538
ret_type_null: NULL::ret_type
1539
';
1540

    
1541

    
1542
--
1543
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1544
--
1545

    
1546
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1547
    LANGUAGE sql STABLE
1548
    AS $_$
1549
SELECT col_name
1550
FROM unnest($2) s (col_name)
1551
WHERE util.col_exists(($1, col_name))
1552
$_$;
1553

    
1554

    
1555
--
1556
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1557
--
1558

    
1559
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1560
    LANGUAGE sql
1561
    AS $_$
1562
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1563
$_$;
1564

    
1565

    
1566
--
1567
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1568
--
1569

    
1570
CREATE FUNCTION explain2notice(sql text) RETURNS void
1571
    LANGUAGE sql
1572
    AS $_$
1573
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1574
$_$;
1575

    
1576

    
1577
--
1578
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1579
--
1580

    
1581
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1582
    LANGUAGE sql
1583
    AS $_$
1584
-- newline before and after to visually separate it from other debug info
1585
SELECT $$
1586
EXPLAIN:
1587
$$||util.explain2str($1)||$$
1588
$$
1589
$_$;
1590

    
1591

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

    
1596
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1597
    LANGUAGE sql
1598
    AS $_$
1599
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1600
$_$;
1601

    
1602

    
1603
--
1604
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1605
--
1606

    
1607
CREATE FUNCTION explain2str(sql text) RETURNS text
1608
    LANGUAGE sql
1609
    AS $_$
1610
SELECT util.join_strs(explain, $$
1611
$$) FROM util.explain($1)
1612
$_$;
1613

    
1614

    
1615
SET default_tablespace = '';
1616

    
1617
SET default_with_oids = false;
1618

    
1619
--
1620
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1621
--
1622

    
1623
CREATE TABLE explain (
1624
    line text NOT NULL
1625
);
1626

    
1627

    
1628
--
1629
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1630
--
1631

    
1632
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1633
    LANGUAGE sql
1634
    AS $_$
1635
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1636
$$||quote_nullable($1)||$$
1637
)$$)
1638
$_$;
1639

    
1640

    
1641
--
1642
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1643
--
1644

    
1645
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1646
usage:
1647
PERFORM util.explain2table($$
1648
query
1649
$$);
1650
';
1651

    
1652

    
1653
--
1654
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1655
--
1656

    
1657
CREATE FUNCTION first_word(str text) RETURNS text
1658
    LANGUAGE sql IMMUTABLE
1659
    AS $_$
1660
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1661
$_$;
1662

    
1663

    
1664
--
1665
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1666
--
1667

    
1668
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1669
    LANGUAGE sql IMMUTABLE
1670
    AS $_$
1671
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1672
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1673
) END
1674
$_$;
1675

    
1676

    
1677
--
1678
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1679
--
1680

    
1681
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1682
ensures that an array will always have proper non-NULL dimensions
1683
';
1684

    
1685

    
1686
--
1687
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1688
--
1689

    
1690
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1691
    LANGUAGE plpgsql
1692
    AS $_$
1693
DECLARE
1694
	PG_EXCEPTION_DETAIL text;
1695
	recreate_users_cmd text = util.save_drop_views(users);
1696
BEGIN
1697
	PERFORM util.eval(cmd);
1698
	PERFORM util.eval(recreate_users_cmd);
1699
EXCEPTION
1700
WHEN dependent_objects_still_exist THEN
1701
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1702
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1703
	users = array(SELECT * FROM util.regexp_matches_group(
1704
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1705
	IF util.is_empty(users) THEN RAISE; END IF;
1706
	PERFORM util.force_recreate(cmd, users);
1707
END;
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1713
--
1714

    
1715
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1716
idempotent
1717

    
1718
users: not necessary to provide this because it will be autopopulated
1719
';
1720

    
1721

    
1722
--
1723
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1724
--
1725

    
1726
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1727
    LANGUAGE plpgsql STRICT
1728
    AS $_$
1729
DECLARE
1730
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1731
$$||query;
1732
BEGIN
1733
	EXECUTE mk_view;
1734
EXCEPTION
1735
WHEN invalid_table_definition THEN
1736
	IF SQLERRM = 'cannot drop columns from view'
1737
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1738
	THEN
1739
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1740
		EXECUTE mk_view;
1741
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1742
	END IF;
1743
END;
1744
$_$;
1745

    
1746

    
1747
--
1748
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1749
--
1750

    
1751
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1752
idempotent
1753
';
1754

    
1755

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

    
1760
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1761
    LANGUAGE sql STABLE
1762
    AS $_$
1763
SELECT util.eval2val(
1764
$$SELECT NOT EXISTS( -- there is no row that is != 1
1765
	SELECT NULL
1766
	FROM $$||$1||$$
1767
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1768
	LIMIT 1
1769
)
1770
$$, NULL::boolean)
1771
$_$;
1772

    
1773

    
1774
--
1775
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1776
--
1777

    
1778
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1779
    LANGUAGE sql STABLE
1780
    AS $_$
1781
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1782
$_$;
1783

    
1784

    
1785
--
1786
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1787
--
1788

    
1789
CREATE FUNCTION grants_users() RETURNS SETOF text
1790
    LANGUAGE sql IMMUTABLE
1791
    AS $$
1792
VALUES ('bien_read'), ('public_')
1793
$$;
1794

    
1795

    
1796
--
1797
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1798
--
1799

    
1800
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1801
    LANGUAGE sql IMMUTABLE
1802
    AS $_$
1803
SELECT substring($2 for length($1)) = $1
1804
$_$;
1805

    
1806

    
1807
--
1808
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1809
--
1810

    
1811
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1812
    LANGUAGE sql STABLE
1813
    AS $_$
1814
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1815
$_$;
1816

    
1817

    
1818
--
1819
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1820
--
1821

    
1822
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1823
    LANGUAGE sql IMMUTABLE
1824
    AS $_$
1825
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1826
$_$;
1827

    
1828

    
1829
--
1830
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1831
--
1832

    
1833
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1834
avoids repeating the same value for each key
1835
';
1836

    
1837

    
1838
--
1839
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1840
--
1841

    
1842
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1843
    LANGUAGE sql IMMUTABLE
1844
    AS $_$
1845
SELECT COALESCE($1, $2)
1846
$_$;
1847

    
1848

    
1849
--
1850
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1851
--
1852

    
1853
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1854
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1855
';
1856

    
1857

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

    
1862
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1863
    LANGUAGE sql
1864
    AS $_$
1865
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1866
$_$;
1867

    
1868

    
1869
--
1870
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1871
--
1872

    
1873
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1874
    LANGUAGE sql STABLE
1875
    AS $_$
1876
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1877
$_$;
1878

    
1879

    
1880
--
1881
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1882
--
1883

    
1884
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1885
    LANGUAGE sql IMMUTABLE
1886
    AS $_$
1887
SELECT util.array_length($1) = 0
1888
$_$;
1889

    
1890

    
1891
--
1892
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1893
--
1894

    
1895
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1896
    LANGUAGE sql IMMUTABLE
1897
    AS $_$
1898
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1899
$_$;
1900

    
1901

    
1902
--
1903
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1904
--
1905

    
1906
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1907
    LANGUAGE sql IMMUTABLE
1908
    AS $_$
1909
SELECT upper(util.first_word($1)) = ANY(
1910
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1911
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1912
)
1913
$_$;
1914

    
1915

    
1916
--
1917
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1918
--
1919

    
1920
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1921
    LANGUAGE sql IMMUTABLE
1922
    AS $_$
1923
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1924
$_$;
1925

    
1926

    
1927
--
1928
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1929
--
1930

    
1931
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1932
    LANGUAGE sql IMMUTABLE
1933
    AS $_$
1934
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1935
$_$;
1936

    
1937

    
1938
--
1939
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1940
--
1941

    
1942
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1943
    LANGUAGE sql IMMUTABLE
1944
    AS $_$
1945
SELECT upper(util.first_word($1)) = 'SET'
1946
$_$;
1947

    
1948

    
1949
--
1950
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1951
--
1952

    
1953
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1954
    LANGUAGE sql STABLE
1955
    AS $_$
1956
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1957
$_$;
1958

    
1959

    
1960
--
1961
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1962
--
1963

    
1964
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1965
    LANGUAGE sql STABLE
1966
    AS $_$
1967
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1968
$_$;
1969

    
1970

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

    
1975
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1976
    LANGUAGE sql IMMUTABLE STRICT
1977
    AS $_$
1978
SELECT $1 || $3 || $2
1979
$_$;
1980

    
1981

    
1982
--
1983
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1984
--
1985

    
1986
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1987
must be declared STRICT to use the special handling of STRICT aggregating functions
1988
';
1989

    
1990

    
1991
--
1992
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1993
--
1994

    
1995
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1996
    LANGUAGE sql IMMUTABLE
1997
    AS $_$
1998
SELECT $1 -- compare on the entire value
1999
$_$;
2000

    
2001

    
2002
--
2003
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2004
--
2005

    
2006
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2007
    LANGUAGE sql IMMUTABLE
2008
    AS $_$
2009
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2010
$_$;
2011

    
2012

    
2013
--
2014
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2015
--
2016

    
2017
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2018
    LANGUAGE sql IMMUTABLE
2019
    AS $_$
2020
SELECT ltrim($1, $$
2021
$$)
2022
$_$;
2023

    
2024

    
2025
--
2026
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2027
--
2028

    
2029
CREATE FUNCTION map_filter_insert() RETURNS trigger
2030
    LANGUAGE plpgsql
2031
    AS $$
2032
BEGIN
2033
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2034
	RETURN new;
2035
END;
2036
$$;
2037

    
2038

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

    
2043
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2044
    LANGUAGE plpgsql STABLE STRICT
2045
    AS $_$
2046
DECLARE
2047
    value text;
2048
BEGIN
2049
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2050
        INTO value USING key;
2051
    RETURN value;
2052
END;
2053
$_$;
2054

    
2055

    
2056
--
2057
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2058
--
2059

    
2060
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2061
    LANGUAGE sql IMMUTABLE
2062
    AS $_$
2063
SELECT util._map(util.nulls_map($1), $2)
2064
$_$;
2065

    
2066

    
2067
--
2068
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2069
--
2070

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

    
2074
[1] inlining of function calls, which is different from constant folding
2075
[2] _map()''s profiling query
2076
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2077
and map_nulls()''s profiling query
2078
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2079
both take ~920 ms.
2080
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.
2081
';
2082

    
2083

    
2084
--
2085
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2086
--
2087

    
2088
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2089
    LANGUAGE plpgsql STABLE STRICT
2090
    AS $_$
2091
BEGIN
2092
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2093
END;
2094
$_$;
2095

    
2096

    
2097
--
2098
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2099
--
2100

    
2101
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2102
    LANGUAGE sql
2103
    AS $_$
2104
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2105
$$||util.ltrim_nl($2));
2106
-- make sure the created table has the correct estimated row count
2107
SELECT util.analyze_($1);
2108

    
2109
SELECT util.append_comment($1, '
2110
contents generated from:
2111
'||util.ltrim_nl($2)||';
2112
');
2113
$_$;
2114

    
2115

    
2116
--
2117
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2118
--
2119

    
2120
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2121
idempotent
2122
';
2123

    
2124

    
2125
--
2126
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2127
--
2128

    
2129
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2130
    LANGUAGE sql
2131
    AS $_$
2132
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2133
$_$;
2134

    
2135

    
2136
--
2137
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2138
--
2139

    
2140
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2141
idempotent
2142
';
2143

    
2144

    
2145
--
2146
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2147
--
2148

    
2149
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2150
    LANGUAGE sql
2151
    AS $_$
2152
SELECT util.create_if_not_exists($$
2153
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2154
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2155
||quote_literal($2)||$$;
2156
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2157
constant
2158
';
2159
$$)
2160
$_$;
2161

    
2162

    
2163
--
2164
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2165
--
2166

    
2167
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2168
idempotent
2169
';
2170

    
2171

    
2172
--
2173
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2174
--
2175

    
2176
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2177
    LANGUAGE plpgsql STRICT
2178
    AS $_$
2179
DECLARE
2180
    type regtype = util.typeof(expr, col.table_::text::regtype);
2181
    col_name_sql text = quote_ident(col.name);
2182
BEGIN
2183
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2184
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2185
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2186
$$||expr||$$;
2187
$$);
2188
END;
2189
$_$;
2190

    
2191

    
2192
--
2193
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2194
--
2195

    
2196
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2197
idempotent
2198
';
2199

    
2200

    
2201
--
2202
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2203
--
2204

    
2205
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
2206
    LANGUAGE sql IMMUTABLE
2207
    AS $_$
2208
SELECT
2209
$$SELECT
2210
$$||$3||$$
2211
FROM      $$||$1||$$ left_
2212
FULL JOIN $$||$2||$$ right_
2213
ON $$||$4||$$
2214
WHERE $$||$5||$$
2215
ORDER BY left_, right_
2216
$$
2217
$_$;
2218

    
2219

    
2220
--
2221
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2222
--
2223

    
2224
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2225
    LANGUAGE sql
2226
    AS $_$
2227
-- keys()
2228
SELECT util.mk_keys_func($1, ARRAY(
2229
SELECT col FROM util.typed_cols($1) col
2230
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2231
));
2232

    
2233
-- values_()
2234
SELECT util.mk_keys_func($1, COALESCE(
2235
	NULLIF(ARRAY(
2236
	SELECT col FROM util.typed_cols($1) col
2237
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2238
	), ARRAY[]::util.col_cast[])
2239
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2240
, 'values_');
2241
$_$;
2242

    
2243

    
2244
--
2245
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2246
--
2247

    
2248
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2249
    LANGUAGE sql
2250
    AS $_$
2251
SELECT util.create_if_not_exists($$
2252
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2253
($$||util.mk_typed_cols_list($2)||$$);
2254
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2255
autogenerated
2256
';
2257
$$);
2258

    
2259
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2260
$_$;
2261

    
2262

    
2263
--
2264
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2265
--
2266

    
2267
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2268
    LANGUAGE sql
2269
    AS $_$
2270
SELECT util.create_if_not_exists($$
2271
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2272
||util.qual_name($1)||$$)
2273
  RETURNS $$||util.qual_name($2)||$$ AS
2274
$BODY1$
2275
SELECT ROW($$||
2276
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2277
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2278
$BODY1$
2279
  LANGUAGE sql IMMUTABLE
2280
  COST 100;
2281
$$);
2282
$_$;
2283

    
2284

    
2285
--
2286
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288

    
2289
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2290
    LANGUAGE sql
2291
    AS $_$
2292
SELECT util.create_if_not_exists($$
2293
CREATE TABLE $$||$1||$$
2294
(
2295
    LIKE util.map INCLUDING ALL
2296
);
2297

    
2298
CREATE TRIGGER map_filter_insert
2299
  BEFORE INSERT
2300
  ON $$||$1||$$
2301
  FOR EACH ROW
2302
  EXECUTE PROCEDURE util.map_filter_insert();
2303
$$)
2304
$_$;
2305

    
2306

    
2307
--
2308
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2309
--
2310

    
2311
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2312
    LANGUAGE sql IMMUTABLE
2313
    AS $_$
2314
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2315
util.qual_name((unnest).type), ''), '')
2316
FROM unnest($1)
2317
$_$;
2318

    
2319

    
2320
--
2321
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2322
--
2323

    
2324
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2325
    LANGUAGE sql IMMUTABLE
2326
    AS $_$
2327
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2328
$_$;
2329

    
2330

    
2331
--
2332
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2333
--
2334

    
2335
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2336
auto-appends util to the search_path to enable use of util operators
2337
';
2338

    
2339

    
2340
--
2341
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2342
--
2343

    
2344
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2345
    LANGUAGE sql IMMUTABLE
2346
    AS $_$
2347
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2348
$_$;
2349

    
2350

    
2351
--
2352
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2353
--
2354

    
2355
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2356
    LANGUAGE sql IMMUTABLE
2357
    AS $_$
2358
/* debug_print_return_value() needed because this function is used with EXECUTE
2359
rather than util.eval() (in order to affect the calling function), so the
2360
search_path would not otherwise be printed */
2361
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2362
||$$ search_path TO $$||$1
2363
$_$;
2364

    
2365

    
2366
--
2367
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2368
--
2369

    
2370
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2371
    LANGUAGE sql
2372
    AS $_$
2373
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2374
$_$;
2375

    
2376

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

    
2381
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2382
idempotent
2383
';
2384

    
2385

    
2386
--
2387
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2388
--
2389

    
2390
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2391
    LANGUAGE plpgsql STRICT
2392
    AS $_$
2393
DECLARE
2394
	view_qual_name text = util.qual_name(view_);
2395
BEGIN
2396
	EXECUTE $$
2397
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2398
  RETURNS SETOF $$||view_||$$ AS
2399
$BODY1$
2400
SELECT * FROM $$||view_qual_name||$$
2401
ORDER BY sort_col
2402
LIMIT $1 OFFSET $2
2403
$BODY1$
2404
  LANGUAGE sql STABLE
2405
  COST 100
2406
  ROWS 1000
2407
$$;
2408
	
2409
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2410
END;
2411
$_$;
2412

    
2413

    
2414
--
2415
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2416
--
2417

    
2418
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2419
    LANGUAGE plpgsql STRICT
2420
    AS $_$
2421
DECLARE
2422
	view_qual_name text = util.qual_name(view_);
2423
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2424
BEGIN
2425
	EXECUTE $$
2426
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2427
  RETURNS integer AS
2428
$BODY1$
2429
SELECT $$||quote_ident(row_num_col)||$$
2430
FROM $$||view_qual_name||$$
2431
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2432
LIMIT 1
2433
$BODY1$
2434
  LANGUAGE sql STABLE
2435
  COST 100;
2436
$$;
2437
	
2438
	EXECUTE $$
2439
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2440
  RETURNS SETOF $$||view_||$$ AS
2441
$BODY1$
2442
SELECT * FROM $$||view_qual_name||$$
2443
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2444
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2445
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2446
ORDER BY $$||quote_ident(row_num_col)||$$
2447
$BODY1$
2448
  LANGUAGE sql STABLE
2449
  COST 100
2450
  ROWS 1000
2451
$$;
2452
	
2453
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2454
END;
2455
$_$;
2456

    
2457

    
2458
--
2459
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2460
--
2461

    
2462
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2463
    LANGUAGE plpgsql STRICT
2464
    AS $_$
2465
DECLARE
2466
	view_qual_name text = util.qual_name(view_);
2467
BEGIN
2468
	EXECUTE $$
2469
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2470
  RETURNS SETOF $$||view_||$$
2471
  SET enable_sort TO 'off'
2472
  AS
2473
$BODY1$
2474
SELECT * FROM $$||view_qual_name||$$($2, $3)
2475
$BODY1$
2476
  LANGUAGE sql STABLE
2477
  COST 100
2478
  ROWS 1000
2479
;
2480
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2481
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2482
If you want to run EXPLAIN and get expanded output, use the regular subset
2483
function instead. (When a config param is set on a function, EXPLAIN produces
2484
just a function scan.)
2485
';
2486
$$;
2487
END;
2488
$_$;
2489

    
2490

    
2491
--
2492
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2493
--
2494

    
2495
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2496
creates subset function which turns off enable_sort
2497
';
2498

    
2499

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

    
2504
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2505
    LANGUAGE sql IMMUTABLE
2506
    AS $_$
2507
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2508
util.qual_name((unnest).type), ', '), '')
2509
FROM unnest($1)
2510
$_$;
2511

    
2512

    
2513
--
2514
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2515
--
2516

    
2517
CREATE FUNCTION name(table_ regclass) RETURNS text
2518
    LANGUAGE sql STABLE
2519
    AS $_$
2520
SELECT relname::text FROM pg_class WHERE oid = $1
2521
$_$;
2522

    
2523

    
2524
--
2525
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2526
--
2527

    
2528
CREATE FUNCTION name(type regtype) RETURNS text
2529
    LANGUAGE sql STABLE
2530
    AS $_$
2531
SELECT typname::text FROM pg_type WHERE oid = $1
2532
$_$;
2533

    
2534

    
2535
--
2536
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2537
--
2538

    
2539
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2540
    LANGUAGE sql IMMUTABLE
2541
    AS $_$
2542
SELECT octet_length($1) >= util.namedatalen() - $2
2543
$_$;
2544

    
2545

    
2546
--
2547
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2548
--
2549

    
2550
CREATE FUNCTION namedatalen() RETURNS integer
2551
    LANGUAGE sql IMMUTABLE
2552
    AS $$
2553
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2554
$$;
2555

    
2556

    
2557
--
2558
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2559
--
2560

    
2561
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2562
    LANGUAGE sql IMMUTABLE
2563
    AS $_$
2564
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2565
$_$;
2566

    
2567

    
2568
--
2569
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2570
--
2571

    
2572
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2573
    LANGUAGE sql IMMUTABLE
2574
    AS $_$
2575
SELECT $1 IS NOT NULL
2576
$_$;
2577

    
2578

    
2579
--
2580
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2581
--
2582

    
2583
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2584
    LANGUAGE sql IMMUTABLE
2585
    AS $_$
2586
SELECT util.hstore($1, NULL) || '*=>*'
2587
$_$;
2588

    
2589

    
2590
--
2591
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2592
--
2593

    
2594
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2595
for use with _map()
2596
';
2597

    
2598

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

    
2603
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2604
    LANGUAGE sql IMMUTABLE
2605
    AS $_$
2606
SELECT $2 + COALESCE($1, 0)
2607
$_$;
2608

    
2609

    
2610
--
2611
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2612
--
2613

    
2614
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2615
    LANGUAGE sql STABLE
2616
    AS $_$
2617
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2618
$_$;
2619

    
2620

    
2621
--
2622
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2623
--
2624

    
2625
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2626
    LANGUAGE sql
2627
    AS $_$
2628
SELECT util.eval($$INSERT INTO $$||$1||$$
2629
$$||util.ltrim_nl($2));
2630
-- make sure the created table has the correct estimated row count
2631
SELECT util.analyze_($1);
2632
$_$;
2633

    
2634

    
2635
--
2636
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2637
--
2638

    
2639
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2640
    LANGUAGE sql IMMUTABLE
2641
    AS $_$
2642
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2643
$_$;
2644

    
2645

    
2646
--
2647
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2648
--
2649

    
2650
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2651
    LANGUAGE sql
2652
    AS $_$
2653
SELECT util.set_comment($1, concat($2, util.comment($1)))
2654
$_$;
2655

    
2656

    
2657
--
2658
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2659
--
2660

    
2661
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2662
comment: must start and end with a newline
2663
';
2664

    
2665

    
2666
--
2667
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2668
--
2669

    
2670
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2671
    LANGUAGE sql IMMUTABLE
2672
    AS $_$
2673
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2674
$_$;
2675

    
2676

    
2677
--
2678
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2679
--
2680

    
2681
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2682
    LANGUAGE sql STABLE
2683
    SET search_path TO pg_temp
2684
    AS $_$
2685
SELECT $1::text
2686
$_$;
2687

    
2688

    
2689
--
2690
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2691
--
2692

    
2693
CREATE FUNCTION qual_name(type regtype) RETURNS text
2694
    LANGUAGE sql STABLE
2695
    SET search_path TO pg_temp
2696
    AS $_$
2697
SELECT $1::text
2698
$_$;
2699

    
2700

    
2701
--
2702
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2703
--
2704

    
2705
COMMENT ON FUNCTION qual_name(type regtype) IS '
2706
a type''s schema-qualified name
2707
';
2708

    
2709

    
2710
--
2711
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2712
--
2713

    
2714
CREATE FUNCTION qual_name(type unknown) RETURNS text
2715
    LANGUAGE sql STABLE
2716
    AS $_$
2717
SELECT util.qual_name($1::text::regtype)
2718
$_$;
2719

    
2720

    
2721
--
2722
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2723
--
2724

    
2725
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2726
    LANGUAGE sql IMMUTABLE
2727
    AS $_$
2728
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2729
$_$;
2730

    
2731

    
2732
--
2733
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2734
--
2735

    
2736
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2737
    LANGUAGE sql IMMUTABLE
2738
    AS $_$
2739
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2740
$_$;
2741

    
2742

    
2743
--
2744
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2745
--
2746

    
2747
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2748
    LANGUAGE sql IMMUTABLE
2749
    AS $_$
2750
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2751
$_$;
2752

    
2753

    
2754
--
2755
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2756
--
2757

    
2758
CREATE FUNCTION raise(type text, msg text) RETURNS void
2759
    LANGUAGE sql IMMUTABLE
2760
    AS $_X$
2761
SELECT util.eval($$
2762
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2763
  RETURNS void AS
2764
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2765
$__BODY1$
2766
BEGIN
2767
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2768
END;
2769
$__BODY1$
2770
  LANGUAGE plpgsql IMMUTABLE
2771
  COST 100;
2772
$$, verbose_ := false);
2773

    
2774
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2775
$_X$;
2776

    
2777

    
2778
--
2779
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2780
--
2781

    
2782
COMMENT ON FUNCTION raise(type text, msg text) IS '
2783
type: a log level from
2784
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2785
or a condition name from
2786
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2787
';
2788

    
2789

    
2790
--
2791
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2792
--
2793

    
2794
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2795
    LANGUAGE sql IMMUTABLE
2796
    AS $_$
2797
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2798
$_$;
2799

    
2800

    
2801
--
2802
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2803
--
2804

    
2805
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2806
    LANGUAGE plpgsql IMMUTABLE STRICT
2807
    AS $$
2808
BEGIN
2809
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2810
END;
2811
$$;
2812

    
2813

    
2814
--
2815
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2816
--
2817

    
2818
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2819
    LANGUAGE sql IMMUTABLE
2820
    AS $_$
2821
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2822
$_$;
2823

    
2824

    
2825
--
2826
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2827
--
2828

    
2829
CREATE FUNCTION regexp_quote(str text) RETURNS text
2830
    LANGUAGE sql IMMUTABLE
2831
    AS $_$
2832
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2833
$_$;
2834

    
2835

    
2836
--
2837
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2838
--
2839

    
2840
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2841
    LANGUAGE sql IMMUTABLE
2842
    AS $_$
2843
SELECT (CASE WHEN right($1, 1) = ')'
2844
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2845
$_$;
2846

    
2847

    
2848
--
2849
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2850
--
2851

    
2852
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2853
    LANGUAGE sql STABLE
2854
    AS $_$
2855
SELECT util.relation_type(util.relation_type_char($1))
2856
$_$;
2857

    
2858

    
2859
--
2860
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2861
--
2862

    
2863
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2864
    LANGUAGE sql IMMUTABLE
2865
    AS $_$
2866
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2867
$_$;
2868

    
2869

    
2870
--
2871
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2872
--
2873

    
2874
CREATE FUNCTION relation_type(type regtype) RETURNS text
2875
    LANGUAGE sql IMMUTABLE
2876
    AS $$
2877
SELECT 'TYPE'::text
2878
$$;
2879

    
2880

    
2881
--
2882
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2883
--
2884

    
2885
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2886
    LANGUAGE sql STABLE
2887
    AS $_$
2888
SELECT relkind FROM pg_class WHERE oid = $1
2889
$_$;
2890

    
2891

    
2892
--
2893
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2894
--
2895

    
2896
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2897
    LANGUAGE sql
2898
    AS $_$
2899
/* can't have in_table/out_table inherit from *each other*, because inheritance
2900
also causes the rows of the parent table to be included in the child table.
2901
instead, they need to inherit from a common, empty table. */
2902
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2903
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2904
SELECT util.inherit($2, $4);
2905
SELECT util.inherit($3, $4);
2906

    
2907
SELECT util.rematerialize_query($1, $$
2908
SELECT * FROM util.diff(
2909
  $$||util.quote_typed($2)||$$
2910
, $$||util.quote_typed($3)||$$
2911
, NULL::$$||$4||$$)
2912
$$);
2913

    
2914
/* the table unfortunately cannot be *materialized* in human-readable form,
2915
because this would create column name collisions between the two sides */
2916
SELECT util.prepend_comment($1, '
2917
to view this table in human-readable form (with each side''s tuple column
2918
expanded to its component fields):
2919
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2920
');
2921
$_$;
2922

    
2923

    
2924
--
2925
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2926
--
2927

    
2928
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2929
type_table (*required*): table to create as the shared base type
2930
';
2931

    
2932

    
2933
--
2934
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2935
--
2936

    
2937
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2938
    LANGUAGE sql
2939
    AS $_$
2940
SELECT util.drop_table($1);
2941
SELECT util.materialize_query($1, $2);
2942
$_$;
2943

    
2944

    
2945
--
2946
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2947
--
2948

    
2949
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2950
idempotent, but repeats action each time
2951
';
2952

    
2953

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

    
2958
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2959
    LANGUAGE sql
2960
    AS $_$
2961
SELECT util.drop_table($1);
2962
SELECT util.materialize_view($1, $2);
2963
$_$;
2964

    
2965

    
2966
--
2967
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2968
--
2969

    
2970
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2971
idempotent, but repeats action each time
2972
';
2973

    
2974

    
2975
--
2976
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2977
--
2978

    
2979
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2980
    LANGUAGE sql
2981
    AS $_$
2982
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2983
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2984
FROM util.col_names($1::text::regtype) f (name);
2985
SELECT NULL::void; -- don't fold away functions called in previous query
2986
$_$;
2987

    
2988

    
2989
--
2990
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2991
--
2992

    
2993
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2994
idempotent
2995
';
2996

    
2997

    
2998
--
2999
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3000
--
3001

    
3002
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3003
    LANGUAGE sql
3004
    AS $_$
3005
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3006
included in the debug SQL */
3007
SELECT util.rename_relation(util.qual_name($1), $2)
3008
$_$;
3009

    
3010

    
3011
--
3012
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3013
--
3014

    
3015
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3016
    LANGUAGE sql
3017
    AS $_$
3018
/* 'ALTER TABLE can be used with views too'
3019
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3020
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3021
||quote_ident($2))
3022
$_$;
3023

    
3024

    
3025
--
3026
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3027
--
3028

    
3029
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3030
idempotent
3031
';
3032

    
3033

    
3034
--
3035
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3036
--
3037

    
3038
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3039
    LANGUAGE sql IMMUTABLE
3040
    AS $_$
3041
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3042
$_$;
3043

    
3044

    
3045
--
3046
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3047
--
3048

    
3049
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3050
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 
3051
';
3052

    
3053

    
3054
--
3055
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3056
--
3057

    
3058
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3059
    LANGUAGE sql
3060
    AS $_$
3061
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3062
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3063
SELECT util.set_col_names($1, $2);
3064
$_$;
3065

    
3066

    
3067
--
3068
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3069
--
3070

    
3071
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3072
idempotent.
3073
alters the names table, so it will need to be repopulated after running this function.
3074
';
3075

    
3076

    
3077
--
3078
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3079
--
3080

    
3081
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3082
    LANGUAGE sql
3083
    AS $_$
3084
SELECT util.drop_table($1);
3085
SELECT util.mk_map_table($1);
3086
$_$;
3087

    
3088

    
3089
--
3090
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3091
--
3092

    
3093
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3094
    LANGUAGE sql IMMUTABLE
3095
    AS $_$
3096
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3097
$_$;
3098

    
3099

    
3100
--
3101
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3102
--
3103

    
3104
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3105
    LANGUAGE sql IMMUTABLE
3106
    AS $_$
3107
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3108
ELSE util.mk_set_search_path(for_printing := true)||$$;
3109
$$ END)||$1
3110
$_$;
3111

    
3112

    
3113
--
3114
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3115
--
3116

    
3117
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3118
    LANGUAGE plpgsql STRICT
3119
    AS $_$
3120
DECLARE
3121
	result text = NULL;
3122
BEGIN
3123
	BEGIN
3124
		result = util.show_create_view(view_);
3125
		PERFORM util.eval($$DROP VIEW $$||view_);
3126
	EXCEPTION
3127
		WHEN undefined_table THEN NULL;
3128
	END;
3129
	RETURN result;
3130
END;
3131
$_$;
3132

    
3133

    
3134
--
3135
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3136
--
3137

    
3138
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3139
    LANGUAGE sql
3140
    AS $_$
3141
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3142
$_$;
3143

    
3144

    
3145
--
3146
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3147
--
3148

    
3149
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3150
    LANGUAGE sql STABLE
3151
    AS $_$
3152
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3153
$_$;
3154

    
3155

    
3156
--
3157
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3158
--
3159

    
3160
CREATE FUNCTION schema(table_ regclass) RETURNS text
3161
    LANGUAGE sql STABLE
3162
    AS $_$
3163
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3164
$_$;
3165

    
3166

    
3167
--
3168
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3169
--
3170

    
3171
CREATE FUNCTION schema(type regtype) RETURNS text
3172
    LANGUAGE sql STABLE
3173
    AS $_$
3174
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3175
$_$;
3176

    
3177

    
3178
--
3179
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3180
--
3181

    
3182
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3183
    LANGUAGE sql STABLE
3184
    AS $_$
3185
SELECT util.schema(pg_typeof($1))
3186
$_$;
3187

    
3188

    
3189
--
3190
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3191
--
3192

    
3193
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3194
    LANGUAGE sql STABLE
3195
    AS $_$
3196
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3197
$_$;
3198

    
3199

    
3200
--
3201
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3202
--
3203

    
3204
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3205
a schema bundle is a group of schemas with a common prefix
3206
';
3207

    
3208

    
3209
--
3210
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3211
--
3212

    
3213
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3214
    LANGUAGE sql
3215
    AS $_$
3216
SELECT util.schema_rename(old_schema,
3217
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3218
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3219
SELECT NULL::void; -- don't fold away functions called in previous query
3220
$_$;
3221

    
3222

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

    
3227
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3228
    LANGUAGE plpgsql
3229
    AS $$
3230
BEGIN
3231
	-- don't schema_bundle_rm() the schema_bundle to keep!
3232
	IF replace = with_ THEN RETURN; END IF;
3233
	
3234
	PERFORM util.schema_bundle_rm(replace);
3235
	PERFORM util.schema_bundle_rename(with_, replace);
3236
END;
3237
$$;
3238

    
3239

    
3240
--
3241
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3242
--
3243

    
3244
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3245
    LANGUAGE sql
3246
    AS $_$
3247
SELECT util.schema_rm(schema)
3248
FROM util.schema_bundle_get_schemas($1) f (schema);
3249
SELECT NULL::void; -- don't fold away functions called in previous query
3250
$_$;
3251

    
3252

    
3253
--
3254
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3255
--
3256

    
3257
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3258
    LANGUAGE sql STABLE
3259
    AS $_$
3260
SELECT quote_ident(util.schema($1))
3261
$_$;
3262

    
3263

    
3264
--
3265
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3266
--
3267

    
3268
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3269
    LANGUAGE sql IMMUTABLE
3270
    AS $_$
3271
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3272
$_$;
3273

    
3274

    
3275
--
3276
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3277
--
3278

    
3279
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3280
    LANGUAGE sql STABLE
3281
    AS $_$
3282
SELECT oid FROM pg_namespace WHERE nspname = $1
3283
$_$;
3284

    
3285

    
3286
--
3287
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3288
--
3289

    
3290
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3291
    LANGUAGE sql IMMUTABLE
3292
    AS $_$
3293
SELECT util.schema_regexp(schema_anchor := $1)
3294
$_$;
3295

    
3296

    
3297
--
3298
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3299
--
3300

    
3301
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3302
    LANGUAGE sql IMMUTABLE
3303
    AS $_$
3304
SELECT util.str_equality_regexp(util.schema($1))
3305
$_$;
3306

    
3307

    
3308
--
3309
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3310
--
3311

    
3312
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3313
    LANGUAGE sql
3314
    AS $_$
3315
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3316
$_$;
3317

    
3318

    
3319
--
3320
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3321
--
3322

    
3323
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3324
    LANGUAGE plpgsql
3325
    AS $$
3326
BEGIN
3327
	-- don't schema_rm() the schema to keep!
3328
	IF replace = with_ THEN RETURN; END IF;
3329
	
3330
	PERFORM util.schema_rm(replace);
3331
	PERFORM util.schema_rename(with_, replace);
3332
END;
3333
$$;
3334

    
3335

    
3336
--
3337
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3338
--
3339

    
3340
CREATE FUNCTION schema_rm(schema text) RETURNS void
3341
    LANGUAGE sql
3342
    AS $_$
3343
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3344
$_$;
3345

    
3346

    
3347
--
3348
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3349
--
3350

    
3351
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3352
    LANGUAGE sql
3353
    AS $_$
3354
SELECT util.eval(
3355
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3356
$_$;
3357

    
3358

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

    
3363
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3364
    LANGUAGE plpgsql STRICT
3365
    AS $_$
3366
DECLARE
3367
    old text[] = ARRAY(SELECT util.col_names(table_));
3368
    new text[] = ARRAY(SELECT util.map_values(names));
3369
BEGIN
3370
    old = old[1:array_length(new, 1)]; -- truncate to same length
3371
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3372
||$$ TO $$||quote_ident(value))
3373
    FROM each(hstore(old, new))
3374
    WHERE value != key -- not same name
3375
    ;
3376
END;
3377
$_$;
3378

    
3379

    
3380
--
3381
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3382
--
3383

    
3384
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3385
idempotent
3386
';
3387

    
3388

    
3389
--
3390
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3391
--
3392

    
3393
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3394
    LANGUAGE plpgsql STRICT
3395
    AS $_$
3396
DECLARE
3397
	row_ util.map;
3398
BEGIN
3399
	-- rename any metadata cols rather than re-adding them with new names
3400
	BEGIN
3401
		PERFORM util.set_col_names(table_, names);
3402
	EXCEPTION
3403
		WHEN array_subscript_error THEN -- selective suppress
3404
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3405
				-- metadata cols not yet added
3406
			ELSE RAISE;
3407
			END IF;
3408
	END;
3409
	
3410
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3411
	LOOP
3412
		PERFORM util.mk_const_col((table_, row_."to"),
3413
			substring(row_."from" from 2));
3414
	END LOOP;
3415
	
3416
	PERFORM util.set_col_names(table_, names);
3417
END;
3418
$_$;
3419

    
3420

    
3421
--
3422
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3423
--
3424

    
3425
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3426
idempotent.
3427
the metadata mappings must be *last* in the names table.
3428
';
3429

    
3430

    
3431
--
3432
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3433
--
3434

    
3435
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3436
    LANGUAGE plpgsql STRICT
3437
    AS $_$
3438
DECLARE
3439
    sql text = $$ALTER TABLE $$||table_||$$
3440
$$||NULLIF(array_to_string(ARRAY(
3441
    SELECT
3442
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3443
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3444
    FROM
3445
    (
3446
        SELECT
3447
          quote_ident(col_name) AS col_name_sql
3448
        , util.col_type((table_, col_name)) AS curr_type
3449
        , type AS target_type
3450
        FROM unnest(col_casts)
3451
    ) s
3452
    WHERE curr_type != target_type
3453
), '
3454
, '), '');
3455
BEGIN
3456
    PERFORM util.debug_print_sql(sql);
3457
    EXECUTE COALESCE(sql, '');
3458
END;
3459
$_$;
3460

    
3461

    
3462
--
3463
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3464
--
3465

    
3466
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3467
idempotent
3468
';
3469

    
3470

    
3471
--
3472
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3473
--
3474

    
3475
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3476
    LANGUAGE sql
3477
    AS $_$
3478
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3479
$_$;
3480

    
3481

    
3482
--
3483
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3484
--
3485

    
3486
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3487
    LANGUAGE sql
3488
    AS $_$
3489
SELECT util.eval(util.mk_set_search_path($1, $2))
3490
$_$;
3491

    
3492

    
3493
--
3494
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3495
--
3496

    
3497
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3498
    LANGUAGE sql STABLE
3499
    AS $_$
3500
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3501
$$||util.show_grants_for($1)
3502
$_$;
3503

    
3504

    
3505
--
3506
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3507
--
3508

    
3509
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3510
    LANGUAGE sql STABLE
3511
    AS $_$
3512
SELECT string_agg(cmd, '')
3513
FROM
3514
(
3515
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3516
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3517
$$ ELSE '' END) AS cmd
3518
	FROM util.grants_users() f (user_)
3519
) s
3520
$_$;
3521

    
3522

    
3523
--
3524
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3525
--
3526

    
3527
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
3528
    LANGUAGE sql STABLE
3529
    AS $_$
3530
SELECT oid FROM pg_class
3531
WHERE relkind = ANY($3) AND relname ~ $1
3532
AND util.schema_matches(util.schema(relnamespace), $2)
3533
ORDER BY relname
3534
$_$;
3535

    
3536

    
3537
--
3538
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3539
--
3540

    
3541
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3542
    LANGUAGE sql STABLE
3543
    AS $_$
3544
SELECT oid
3545
FROM pg_type
3546
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3547
ORDER BY typname
3548
$_$;
3549

    
3550

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

    
3555
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3556
    LANGUAGE sql STABLE
3557
    AS $_$
3558
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3559
$_$;
3560

    
3561

    
3562
--
3563
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3564
--
3565

    
3566
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3567
    LANGUAGE sql IMMUTABLE
3568
    AS $_$
3569
SELECT '^'||util.regexp_quote($1)||'$'
3570
$_$;
3571

    
3572

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

    
3577
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3578
    LANGUAGE plpgsql STABLE STRICT
3579
    AS $_$
3580
DECLARE
3581
    hstore hstore;
3582
BEGIN
3583
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3584
        table_||$$))$$ INTO STRICT hstore;
3585
    RETURN hstore;
3586
END;
3587
$_$;
3588

    
3589

    
3590
--
3591
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3592
--
3593

    
3594
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3595
    LANGUAGE sql STABLE
3596
    AS $_$
3597
SELECT COUNT(*) > 0 FROM pg_constraint
3598
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3599
$_$;
3600

    
3601

    
3602
--
3603
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3604
--
3605

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

    
3610

    
3611
--
3612
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3613
--
3614

    
3615
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3616
    LANGUAGE sql
3617
    AS $_$
3618
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3619
||quote_ident($2)||$$ CHECK (true)$$)
3620
$_$;
3621

    
3622

    
3623
--
3624
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3625
--
3626

    
3627
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3628
stores a status flag by the presence of a table constraint.
3629
idempotent.
3630
';
3631

    
3632

    
3633
--
3634
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3635
--
3636

    
3637
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3638
    LANGUAGE sql STABLE
3639
    AS $_$
3640
SELECT util.table_flag__get($1, 'nulls_mapped')
3641
$_$;
3642

    
3643

    
3644
--
3645
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3646
--
3647

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

    
3652

    
3653
--
3654
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3655
--
3656

    
3657
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3658
    LANGUAGE sql
3659
    AS $_$
3660
SELECT util.table_flag__set($1, 'nulls_mapped')
3661
$_$;
3662

    
3663

    
3664
--
3665
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3666
--
3667

    
3668
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3669
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3670
idempotent.
3671
';
3672

    
3673

    
3674
--
3675
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3676
--
3677

    
3678
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3679
    LANGUAGE sql
3680
    AS $_$
3681
-- save data before truncating main table
3682
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3683

    
3684
-- repopulate main table w/ copies column
3685
SELECT util.truncate($1);
3686
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3687
SELECT util.populate_table($1, $$
3688
SELECT (table_).*, copies
3689
FROM (
3690
	SELECT table_, COUNT(*) AS copies
3691
	FROM pg_temp.__copy table_
3692
	GROUP BY table_
3693
) s
3694
$$);
3695

    
3696
-- delete temp table so it doesn't stay around until end of connection
3697
SELECT util.drop_table('pg_temp.__copy');
3698
$_$;
3699

    
3700

    
3701
--
3702
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3703
--
3704

    
3705
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3706
    LANGUAGE plpgsql STRICT
3707
    AS $_$
3708
DECLARE
3709
    row record;
3710
BEGIN
3711
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3712
    LOOP
3713
        IF row.global_name != row.name THEN
3714
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3715
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3716
        END IF;
3717
    END LOOP;
3718
END;
3719
$_$;
3720

    
3721

    
3722
--
3723
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3724
--
3725

    
3726
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3727
idempotent
3728
';
3729

    
3730

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

    
3735
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3736
    LANGUAGE sql
3737
    AS $_$
3738
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3739
SELECT NULL::void; -- don't fold away functions called in previous query
3740
$_$;
3741

    
3742

    
3743
--
3744
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3745
--
3746

    
3747
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3748
trims table_ to include only columns in the original data.
3749
idempotent.
3750
';
3751

    
3752

    
3753
--
3754
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3755
--
3756

    
3757
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3758
    LANGUAGE plpgsql STRICT
3759
    AS $_$
3760
BEGIN
3761
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3762
END;
3763
$_$;
3764

    
3765

    
3766
--
3767
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3768
--
3769

    
3770
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3771
idempotent
3772
';
3773

    
3774

    
3775
--
3776
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3777
--
3778

    
3779
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3780
    LANGUAGE sql IMMUTABLE
3781
    AS $_$
3782
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3783
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3784
$_$;
3785

    
3786

    
3787
--
3788
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3789
--
3790

    
3791
CREATE FUNCTION try_create(sql text) RETURNS void
3792
    LANGUAGE plpgsql STRICT
3793
    AS $$
3794
BEGIN
3795
	PERFORM util.eval(sql);
3796
EXCEPTION
3797
WHEN   not_null_violation
3798
		/* trying to add NOT NULL column to parent table, which cascades to
3799
		child table whose values for the new column will be NULL */
3800
	OR wrong_object_type -- trying to alter a view's columns
3801
	OR undefined_column
3802
	OR duplicate_column
3803
THEN NULL;
3804
WHEN datatype_mismatch THEN
3805
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
3806
	ELSE RAISE; -- rethrow
3807
	END IF;
3808
END;
3809
$$;
3810

    
3811

    
3812
--
3813
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3814
--
3815

    
3816
COMMENT ON FUNCTION try_create(sql text) IS '
3817
idempotent
3818
';
3819

    
3820

    
3821
--
3822
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3823
--
3824

    
3825
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3826
    LANGUAGE sql
3827
    AS $_$
3828
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3829
$_$;
3830

    
3831

    
3832
--
3833
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3834
--
3835

    
3836
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3837
idempotent
3838
';
3839

    
3840

    
3841
--
3842
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3843
--
3844

    
3845
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3846
    LANGUAGE sql IMMUTABLE
3847
    AS $_$
3848
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3849
$_$;
3850

    
3851

    
3852
--
3853
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3854
--
3855

    
3856
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3857
a type''s NOT NULL qualifier
3858
';
3859

    
3860

    
3861
--
3862
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3863
--
3864

    
3865
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3866
    LANGUAGE sql STABLE
3867
    AS $_$
3868
SELECT (attname::text, atttypid)::util.col_cast
3869
FROM pg_attribute
3870
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3871
ORDER BY attnum
3872
$_$;
3873

    
3874

    
3875
--
3876
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3877
--
3878

    
3879
CREATE FUNCTION typeof(value anyelement) RETURNS text
3880
    LANGUAGE sql IMMUTABLE
3881
    AS $_$
3882
SELECT util.qual_name(pg_typeof($1))
3883
$_$;
3884

    
3885

    
3886
--
3887
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3888
--
3889

    
3890
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3891
    LANGUAGE plpgsql STABLE
3892
    AS $_$
3893
DECLARE
3894
    type regtype;
3895
BEGIN
3896
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3897
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3898
    RETURN type;
3899
END;
3900
$_$;
3901

    
3902

    
3903
--
3904
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3905
--
3906

    
3907
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3908
    LANGUAGE sql
3909
    AS $_$
3910
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3911
$_$;
3912

    
3913

    
3914
--
3915
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3916
--
3917

    
3918
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3919
auto-appends util to the search_path to enable use of util operators
3920
';
3921

    
3922

    
3923
--
3924
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3925
--
3926

    
3927
CREATE AGGREGATE all_same(anyelement) (
3928
    SFUNC = all_same_transform,
3929
    STYPE = anyarray,
3930
    FINALFUNC = all_same_final
3931
);
3932

    
3933

    
3934
--
3935
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3936
--
3937

    
3938
COMMENT ON AGGREGATE all_same(anyelement) IS '
3939
includes NULLs in comparison
3940
';
3941

    
3942

    
3943
--
3944
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3945
--
3946

    
3947
CREATE AGGREGATE join_strs(text, text) (
3948
    SFUNC = join_strs_transform,
3949
    STYPE = text
3950
);
3951

    
3952

    
3953
--
3954
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3955
--
3956

    
3957
CREATE OPERATOR %== (
3958
    PROCEDURE = "%==",
3959
    LEFTARG = anyelement,
3960
    RIGHTARG = anyelement
3961
);
3962

    
3963

    
3964
--
3965
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3966
--
3967

    
3968
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3969
returns whether the map-keys of the compared values are the same
3970
(mnemonic: % is the Perl symbol for a hash map)
3971

    
3972
should be overridden for types that store both keys and values
3973

    
3974
used in a FULL JOIN to select which columns to join on
3975
';
3976

    
3977

    
3978
--
3979
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3980
--
3981

    
3982
CREATE OPERATOR -> (
3983
    PROCEDURE = map_get,
3984
    LEFTARG = regclass,
3985
    RIGHTARG = text
3986
);
3987

    
3988

    
3989
--
3990
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3991
--
3992

    
3993
CREATE OPERATOR => (
3994
    PROCEDURE = hstore,
3995
    LEFTARG = text[],
3996
    RIGHTARG = text
3997
);
3998

    
3999

    
4000
--
4001
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4002
--
4003

    
4004
COMMENT ON OPERATOR => (text[], text) IS '
4005
usage: array[''key1'', ...]::text[] => ''value''
4006
';
4007

    
4008

    
4009
--
4010
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4011
--
4012

    
4013
CREATE OPERATOR ?*>= (
4014
    PROCEDURE = is_populated_more_often_than,
4015
    LEFTARG = anyelement,
4016
    RIGHTARG = anyelement
4017
);
4018

    
4019

    
4020
--
4021
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4022
--
4023

    
4024
CREATE OPERATOR ?>= (
4025
    PROCEDURE = is_more_complete_than,
4026
    LEFTARG = anyelement,
4027
    RIGHTARG = anyelement
4028
);
4029

    
4030

    
4031
--
4032
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4033
--
4034

    
4035
CREATE OPERATOR ||% (
4036
    PROCEDURE = concat_esc,
4037
    LEFTARG = text,
4038
    RIGHTARG = text
4039
);
4040

    
4041

    
4042
--
4043
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4044
--
4045

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

    
4050

    
4051
--
4052
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4053
--
4054

    
4055
CREATE TABLE map (
4056
    "from" text NOT NULL,
4057
    "to" text,
4058
    filter text,
4059
    notes text
4060
);
4061

    
4062

    
4063
--
4064
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4065
--
4066

    
4067

    
4068

    
4069
--
4070
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4071
--
4072

    
4073

    
4074

    
4075
--
4076
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4077
--
4078

    
4079
ALTER TABLE ONLY map
4080
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4081

    
4082

    
4083
--
4084
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4085
--
4086

    
4087
ALTER TABLE ONLY map
4088
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4089

    
4090

    
4091
--
4092
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4093
--
4094

    
4095
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4096

    
4097

    
4098
--
4099
-- PostgreSQL database dump complete
4100
--
4101

    
(19-19/29)