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