Project

General

Profile

1 2094 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7 6213 aaronmk
SET standard_conforming_strings = on;
8 2094 aaronmk
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10
11
--
12
-- Name: functions; Type: SCHEMA; Schema: -; Owner: -
13
--
14
15
CREATE SCHEMA functions;
16
17
18 4982 aaronmk
--
19
-- Name: SCHEMA functions; Type: COMMENT; Schema: -; Owner: -
20
--
21
22
COMMENT ON SCHEMA functions IS 'IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.';
23
24
25 2107 aaronmk
SET search_path = functions, pg_catalog;
26
27 2094 aaronmk
--
28 7673 aaronmk
-- Name: compass_dir; Type: TYPE; Schema: functions; Owner: -
29
--
30
31
CREATE TYPE compass_dir AS ENUM (
32
    'N',
33
    'E',
34
    'S',
35
    'W'
36
);
37
38
39
--
40 2610 aaronmk
-- Name: datatype; Type: TYPE; Schema: functions; Owner: -
41
--
42
43
CREATE TYPE datatype AS ENUM (
44
    'str',
45
    'float'
46
);
47
48
49
--
50 4501 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
51 2596 aaronmk
--
52
53 4501 aaronmk
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
54 3422 aaronmk
    LANGUAGE sql IMMUTABLE
55
    AS $_$
56 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
57 3422 aaronmk
$_$;
58
59
60
--
61 5956 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: functions; Owner: -
62 5937 aaronmk
--
63
64 5956 aaronmk
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
65 5937 aaronmk
    LANGUAGE sql IMMUTABLE
66
    AS $_$
67
SELECT bool_and(value)
68
FROM
69
(VALUES
70
      ($1)
71
    , ($2)
72 5956 aaronmk
    , ($3)
73
    , ($4)
74
    , ($5)
75 5937 aaronmk
)
76
AS v (value)
77
$_$;
78
79
80
--
81 5956 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: functions; Owner: -
82 5937 aaronmk
--
83
84 6437 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_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.';
85 5937 aaronmk
86
87
--
88 7679 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: functions; Owner: -
89
--
90
91
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
92
    LANGUAGE sql IMMUTABLE STRICT
93
    AS $_$
94
SELECT (g[1]||'1')::integer*functions._dms_to_dd(deg := g[2]::double precision, min := g[3]::double precision, sec := g[4]::double precision, dir := g[5]::functions.compass_dir)
95
FROM regexp_matches($1, '^ *(-?)([\d.]+)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$') matches (g)
96
$_$;
97
98
99
--
100 7674 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: functions; Owner: -
101 7672 aaronmk
--
102
103 7674 aaronmk
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
104 7672 aaronmk
    LANGUAGE sql IMMUTABLE
105
    AS $_$
106 7678 aaronmk
SELECT sum(value)*COALESCE(functions._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
107 7672 aaronmk
FROM
108
(VALUES
109 7677 aaronmk
      ($1)
110 7672 aaronmk
    , ($2/60)
111
    , ($3/60/60)
112
)
113
AS v (value)
114
$_$;
115
116
117
--
118 4142 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
119
--
120
121
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
122
    LANGUAGE sql IMMUTABLE
123
    AS $_$
124
SELECT $1 = $2
125
$_$;
126
127
128
--
129 7396 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: functions; Owner: -
130
--
131
132
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
133
    LANGUAGE sql IMMUTABLE
134
    AS $_$
135
-- Fix dates after threshold date
136
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
137
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
138
$_$;
139
140
141
--
142 4147 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
143
--
144
145
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
146
    LANGUAGE sql IMMUTABLE
147
    AS $_$
148
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
149
$_$;
150
151
152
--
153
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
154
--
155
156
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
157
    LANGUAGE sql IMMUTABLE
158
    AS $_$
159
SELECT functions._if($1 != '', $2, $3)
160
$_$;
161
162
163
--
164 4325 aaronmk
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
165
--
166
167
CREATE FUNCTION _join("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
168
    LANGUAGE sql IMMUTABLE
169
    AS $_$
170 5395 aaronmk
SELECT nullif(array_to_string(ARRAY[$1, $2, $3, $4, $5, $6, $7, $8, $9, $10], '; '), '')
171 4325 aaronmk
$_$;
172
173
174
--
175 5009 aaronmk
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
176
--
177
178
CREATE FUNCTION _join_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
179
    LANGUAGE sql IMMUTABLE
180
    AS $_$
181 5395 aaronmk
SELECT nullif(array_to_string(ARRAY[$1, $2, $3, $4, $5, $6, $7, $8, $9, $10], ' '), '')
182 5009 aaronmk
$_$;
183
184
185
--
186 4683 aaronmk
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
187 3422 aaronmk
--
188
189 4683 aaronmk
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
190 4682 aaronmk
    LANGUAGE sql IMMUTABLE
191
    AS $_$
192
SELECT coalesce($1 || ': ', '') || $2
193
$_$;
194 2596 aaronmk
195
196
--
197 6222 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: functions; Owner: -
198
--
199
200
CREATE FUNCTION _map(map hstore, value text) RETURNS text
201
    LANGUAGE plpgsql IMMUTABLE
202
    AS $$
203
DECLARE
204 6271 aaronmk
    match text := map -> value;
205 6222 aaronmk
BEGIN
206 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
207
        match := map -> '*'; -- use default entry
208
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
209
        END IF;
210
    END IF;
211
212
    -- Interpret result
213 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
214
    ELSIF match = '*' THEN RETURN value;
215
    ELSE RETURN match;
216 6222 aaronmk
    END IF;
217
END;
218
$$;
219
220
221
--
222 5408 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
223
--
224
225
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
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
229 5408 aaronmk
$_$;
230
231
232
--
233 4150 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
234 2940 aaronmk
--
235
236 4150 aaronmk
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
237 2940 aaronmk
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239 4053 aaronmk
SELECT functions.join_strs(value, '; ')
240 2940 aaronmk
FROM
241
(
242
    SELECT *
243
    FROM
244
    (
245
        SELECT
246
        DISTINCT ON (value)
247
        *
248
        FROM
249
        (VALUES
250 4012 aaronmk
              (1, $1)
251
            , (2, $2)
252
            , (3, $3)
253
            , (4, $4)
254
            , (5, $5)
255
            , (6, $6)
256
            , (7, $7)
257
            , (8, $8)
258
            , (9, $9)
259
            , (10, $10)
260 2940 aaronmk
        )
261
        AS v (sort_order, value)
262 4011 aaronmk
        WHERE value IS NOT NULL
263 2940 aaronmk
    )
264
    AS v
265
    ORDER BY sort_order
266
)
267
AS v
268
$_$;
269
270
271
--
272 7140 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: functions; Owner: -
273
--
274
275
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
276
    LANGUAGE sql IMMUTABLE
277
    AS $_$
278
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
279
$_$;
280
281
282
--
283 6354 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
284
--
285
286
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
287
    LANGUAGE sql IMMUTABLE
288
    AS $_$
289
SELECT functions.join_strs(value, ' ')
290
FROM
291
(
292
    SELECT *
293
    FROM
294
    (
295
        SELECT
296
        DISTINCT ON (value)
297
        *
298
        FROM
299
        (VALUES
300
              (1, $1)
301
            , (2, $2)
302
            , (3, $3)
303
            , (4, $4)
304
            , (5, $5)
305
            , (6, $6)
306
            , (7, $7)
307
            , (8, $8)
308
            , (9, $9)
309
            , (10, $10)
310
        )
311
        AS v (sort_order, value)
312
        WHERE value IS NOT NULL
313
    )
314
    AS v
315
    ORDER BY sort_order
316
)
317
AS v
318
$_$;
319
320
321
--
322 5408 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
323
--
324
325
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
326
    LANGUAGE sql IMMUTABLE
327
    AS $_$
328 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
329 5408 aaronmk
$_$;
330
331
332
--
333 6316 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: functions; Owner: -
334
--
335
336
CREATE FUNCTION _not(value boolean) RETURNS boolean
337
    LANGUAGE sql IMMUTABLE STRICT
338
    AS $_$
339
SELECT NOT $1
340
$_$;
341
342
343
--
344 7104 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: functions; Owner: -
345
--
346
347
CREATE FUNCTION _now() RETURNS timestamp with time zone
348
    LANGUAGE sql STABLE
349
    AS $$
350
SELECT now()
351
$$;
352
353
354
--
355 4475 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: functions; Owner: -
356 2949 aaronmk
--
357
358 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
359 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
360
    AS $$
361
DECLARE
362
    type functions.datatype NOT NULL := type; -- add NOT NULL
363
BEGIN
364 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
365 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
366 2949 aaronmk
    ELSIF type = 'float' THEN
367 2722 aaronmk
        DECLARE
368
            -- Outside the try block so that invalid null value generates error
369 2949 aaronmk
            "null" double precision := "null"::double precision;
370 2722 aaronmk
        BEGIN
371 2949 aaronmk
            RETURN nullif(value::double precision, "null");
372 2722 aaronmk
        EXCEPTION
373 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
374 2722 aaronmk
        END;
375 2610 aaronmk
    END IF;
376
END;
377
$$;
378
379
380
--
381 4479 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: functions; Owner: -
382
--
383
384
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
385
    LANGUAGE sql IMMUTABLE
386
    AS $_$
387
SELECT functions."_nullIf"($1, $2, $3::functions.datatype)
388
$_$;
389
390
391
--
392 6355 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: functions; Owner: -
393
--
394
395
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
396
    LANGUAGE sql IMMUTABLE
397
    AS $_$
398
SELECT bool_or(value)
399
FROM
400
(VALUES
401
      ($1)
402
    , ($2)
403
    , ($3)
404
    , ($4)
405
    , ($5)
406
)
407
AS v (value)
408
$_$;
409
410
411
--
412 6437 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: functions; Owner: -
413
--
414
415
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_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.';
416
417
418
--
419 6793 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: functions; Owner: -
420
--
421
422
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
423
    LANGUAGE sql IMMUTABLE STRICT
424
    AS $_$
425
SELECT regexp_split_to_table($1, $2)
426
$_$;
427
428
429
--
430 4052 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: functions; Owner: -
431 4009 aaronmk
--
432
433 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
434 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
435 4009 aaronmk
    AS $_$
436 4054 aaronmk
SELECT $1 || $3 || $2
437 2595 aaronmk
$_$;
438
439
440
--
441
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: functions; Owner: -
442
--
443
444
CREATE AGGREGATE join_strs(text, text) (
445 4052 aaronmk
    SFUNC = join_strs_transform,
446 4010 aaronmk
    STYPE = text
447 2595 aaronmk
);
448
449
450 2107 aaronmk
--
451 2136 aaronmk
-- PostgreSQL database dump complete
452
--