Project

General

Profile

1 2620 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7
SET standard_conforming_strings = off;
8
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10
SET escape_string_warning = off;
11
12
--
13 2623 aaronmk
-- Name: py_functions; Type: SCHEMA; Schema: -; Owner: bien
14 2620 aaronmk
--
15
16
CREATE SCHEMA py_functions;
17
18
19 3430 aaronmk
ALTER SCHEMA py_functions OWNER TO bien;
20
21 2630 aaronmk
SET search_path = py_functions, pg_catalog;
22
23 2620 aaronmk
--
24 3422 aaronmk
-- Name: __dateRangeEnd(); Type: FUNCTION; Schema: py_functions; Owner: bien
25
--
26
27
CREATE FUNCTION "__dateRangeEnd"() RETURNS trigger
28
    LANGUAGE plpgsql IMMUTABLE
29
    AS $$
30
BEGIN
31
    new.result := py_functions."_dateRangeEnd"(new.value);
32
    RETURN new;
33
END;
34
$$;
35
36
37 3430 aaronmk
ALTER FUNCTION py_functions."__dateRangeEnd"() OWNER TO bien;
38
39 3422 aaronmk
--
40
-- Name: __dateRangeStart(); Type: FUNCTION; Schema: py_functions; Owner: bien
41
--
42
43
CREATE FUNCTION "__dateRangeStart"() RETURNS trigger
44
    LANGUAGE plpgsql IMMUTABLE
45
    AS $$
46
BEGIN
47
    new.result := py_functions."_dateRangeStart"(new.value);
48
    RETURN new;
49
END;
50
$$;
51
52
53 3430 aaronmk
ALTER FUNCTION py_functions."__dateRangeStart"() OWNER TO bien;
54
55 3422 aaronmk
--
56
-- Name: __namePart(); Type: FUNCTION; Schema: py_functions; Owner: bien
57
--
58
59
CREATE FUNCTION "__namePart"() RETURNS trigger
60
    LANGUAGE plpgsql IMMUTABLE
61
    AS $$
62
BEGIN
63
    new.result := py_functions."_namePart"(new.first, new.middle, new.last);
64
    RETURN new;
65
END;
66
$$;
67
68
69 3430 aaronmk
ALTER FUNCTION py_functions."__namePart"() OWNER TO bien;
70
71 3422 aaronmk
--
72 3435 aaronmk
-- Name: _date!(text, text, text, text); Type: FUNCTION; Schema: py_functions; Owner: bien
73 3415 aaronmk
--
74
75 3435 aaronmk
CREATE FUNCTION "_date!"(date text DEFAULT NULL::text, year text DEFAULT NULL::text, month text DEFAULT NULL::text, day text DEFAULT NULL::text) RETURNS text
76 3415 aaronmk
    LANGUAGE plpythonu IMMUTABLE
77
    AS $$
78
global date, year, month, day
79
80
import datetime
81
import dateutil.tz
82
83
def e_str(e):
84
    msg = e.__class__.__name__+': '+e.args[0]
85
    return msg.rstrip()
86
87
class ExceptionWithCause(Exception):
88
    def __init__(self, msg, cause):
89
        msg += ': '+e_str(cause)
90
        Exception.__init__(self, msg)
91
92
utc = dateutil.tz.tzutc()
93
94
def naive2utc(datetime_):
95
    assert datetime_.tzinfo == None
96
    return datetime_.replace(tzinfo=utc)
97
98
def from_timestamp(utc_timestamp):
99
    return naive2utc(datetime.datetime.utcfromtimestamp(utc_timestamp))
100
101
epoch = from_timestamp(0)
102
103
def strtotime(str_, default=epoch):
104
    import dateutil.parser
105
    return dateutil.parser.parse(str_, default=default)
106
107
class FormatException(ExceptionWithCause):
108
    def __init__(self, cause):
109
        ExceptionWithCause.__init__(self, 'Invalid input value', cause)
110
111
if date != None:
112
    str_ = date
113
    try: year = float(str_)
114
    except ValueError:
115
        try: date = strtotime(str_)
116
        except ImportError: return str_
117
        except ValueError, e: raise FormatException(e)
118
    else: date = (datetime.date(int(year), 1, 1) +
119
        datetime.timedelta(round((year % 1.)*365)))
120
else:
121
    # Year is required
122
    if year == None:
123
        if month == None and day == None: return None # entire date is empty
124
        else: raise FormatException(ValueError('Year is required'))
125
126
    # Convert month name to number
127
    if month != None and not month.isdigit(): # month is name
128
        try: month = str(strtotime(month).month)
129
        except ValueError, e: raise FormatException(e)
130
131
    if month == None: month = 1
132
    if day == None: day = 1
133
    year, month, day = map(int, (year, month, day))
134
135
    for try_num in xrange(2):
136
        try:
137
            date = datetime.date(year, month, day)
138
            break
139
        except ValueError, e:
140
            if try_num > 0: raise FormatException(e)
141
                # exception still raised after retry
142
            msg = e_str(e)
143
            if msg == 'month must be in 1..12': # try swapping month and day
144
                month, day = day, month
145
            else: raise FormatException(e)
146
147 3416 aaronmk
return str(date)
148 3415 aaronmk
$$;
149
150
151 3435 aaronmk
ALTER FUNCTION py_functions."_date!"(date text, year text, month text, day text) OWNER TO bien;
152 3430 aaronmk
153 3415 aaronmk
--
154 2951 aaronmk
-- Name: _dateRangeEnd(text); Type: FUNCTION; Schema: py_functions; Owner: bien
155
--
156
157
CREATE FUNCTION "_dateRangeEnd"(value text) RETURNS text
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT (py_functions.parse_date_range($1))[2]
161
$_$;
162
163
164 3430 aaronmk
ALTER FUNCTION py_functions."_dateRangeEnd"(value text) OWNER TO bien;
165
166 2951 aaronmk
--
167
-- Name: _dateRangeStart(text); Type: FUNCTION; Schema: py_functions; Owner: bien
168
--
169
170
CREATE FUNCTION "_dateRangeStart"(value text) RETURNS text
171
    LANGUAGE sql IMMUTABLE
172
    AS $_$
173
SELECT (py_functions.parse_date_range($1))[1]
174
$_$;
175
176
177 3430 aaronmk
ALTER FUNCTION py_functions."_dateRangeStart"(value text) OWNER TO bien;
178
179 2951 aaronmk
--
180 2952 aaronmk
-- Name: _namePart(text, text, text); Type: FUNCTION; Schema: py_functions; Owner: bien
181
--
182
183
CREATE FUNCTION "_namePart"(first text DEFAULT NULL::text, middle text DEFAULT NULL::text, last text DEFAULT NULL::text) RETURNS text
184 2635 aaronmk
    LANGUAGE plpythonu IMMUTABLE
185
    AS $$
186 2952 aaronmk
params = dict(first=first, middle=middle, last=last)
187 2635 aaronmk
188
_name_parts_slices_items = [
189
    ('first', slice(None, 1)),
190
    ('middle', slice(1, -1)),
191
    ('last', slice(-1, None)),
192
]
193
name_parts_slices = dict(_name_parts_slices_items)
194
name_parts = [name for name, slice_ in _name_parts_slices_items]
195
196
def _name(items):
197
    items = dict(items)
198
    parts = []
199
    for part in name_parts:
200
        if part in items: parts.append(items[part])
201
    return ' '.join(parts)
202
203
out_items = []
204 2952 aaronmk
for part, value in params.iteritems():
205 2635 aaronmk
    if value == None: continue
206
207
    try: slice_ = name_parts_slices[part]
208
    except KeyError: pass # a non-value column
209
    else: out_items.append((part, ' '.join(value.split(' ')[slice_])))
210
211 2952 aaronmk
return _name(out_items)
212 2635 aaronmk
$$;
213
214
215 3430 aaronmk
ALTER FUNCTION py_functions."_namePart"(first text, middle text, last text) OWNER TO bien;
216
217 2635 aaronmk
--
218 2630 aaronmk
-- Name: parse_date_range(text); Type: FUNCTION; Schema: py_functions; Owner: bien
219
--
220
221
CREATE FUNCTION parse_date_range(str_ text) RETURNS text[]
222
    LANGUAGE plpythonu IMMUTABLE STRICT
223
    AS $$
224
import re
225
226
def single_space(str_): return re.sub(r' {2,}', r' ', str_.strip())
227
228
def could_be_year(str_): return str_.isdigit() and len(str_) == 4
229
230
def could_be_day(str_): return str_.isdigit() and len(str_) <= 2
231
232
range_sep='-'
233
part_sep=' '
234
235
default = (str_, None)
236
# range_sep might be used as date part separator instead
237
if str_.find(part_sep) < 0: return default
238
239
start, sep, end = str_.partition(range_sep)
240
if sep == '': return default # not a range
241
start, end = (single_space(d).split(part_sep) for d in (start, end))
242
243
# Has form M D1-D2 or M D1-D2 Y (not M1 Y1-M2 Y2 or M1 D1-M2 D2)
244
if len(start) == 2 and (len(end) == 1 or (
245
        len(end) == 2 and could_be_day(start[-1]) and could_be_day(end[0])
246
        and could_be_year(end[-1])
247
    )):
248
    end.insert(0, start[0]) # make end fully specified
249
ct_diff = len(end) - len(start)
250
# Has form D1-D2 M Y, M1 D1-M2 D2 Y, M1-M2 Y, etc.
251
if ct_diff > 0: start += end[-ct_diff:] # make start fully specified
252
# Other forms are invalid and will be left as-is
253
254
return [part_sep.join(d) for d in (start, end)]
255
$$;
256
257
258 3430 aaronmk
ALTER FUNCTION py_functions.parse_date_range(str_ text) OWNER TO bien;
259
260 2630 aaronmk
SET default_tablespace = '';
261
262
SET default_with_oids = false;
263
264
--
265 2634 aaronmk
-- Name: _dateRangeEnd; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace:
266
--
267
268
CREATE TABLE "_dateRangeEnd" (
269
    result text,
270
    not_null_col boolean DEFAULT true NOT NULL,
271
    value text
272
);
273
274
275 3430 aaronmk
ALTER TABLE py_functions."_dateRangeEnd" OWNER TO bien;
276
277 2634 aaronmk
--
278 2630 aaronmk
-- Name: _dateRangeStart; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace:
279
--
280
281
CREATE TABLE "_dateRangeStart" (
282
    result text,
283
    not_null_col boolean DEFAULT true NOT NULL,
284
    value text
285
);
286
287
288 3430 aaronmk
ALTER TABLE py_functions."_dateRangeStart" OWNER TO bien;
289
290 2630 aaronmk
--
291 2635 aaronmk
-- Name: _namePart; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace:
292
--
293
294
CREATE TABLE "_namePart" (
295
    result text,
296
    not_null_col boolean DEFAULT true NOT NULL,
297
    first text,
298
    middle text,
299
    last text
300
);
301
302
303 3430 aaronmk
ALTER TABLE py_functions."_namePart" OWNER TO bien;
304
305 2635 aaronmk
--
306 2634 aaronmk
-- Name: _dateRangeEnd_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace:
307
--
308
309 2867 aaronmk
CREATE UNIQUE INDEX "_dateRangeEnd_unique" ON "_dateRangeEnd" USING btree ((COALESCE(value, '\\N'::text)));
310 2634 aaronmk
311
312
--
313 2630 aaronmk
-- Name: _dateRangeStart_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace:
314
--
315
316 2867 aaronmk
CREATE UNIQUE INDEX "_dateRangeStart_unique" ON "_dateRangeStart" USING btree ((COALESCE(value, '\\N'::text)));
317 2630 aaronmk
318
319
--
320 2635 aaronmk
-- Name: _namePart_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace:
321
--
322
323 2866 aaronmk
CREATE UNIQUE INDEX "_namePart_unique" ON "_namePart" USING btree ((COALESCE(first, '\\N'::text)), (COALESCE(middle, '\\N'::text)), (COALESCE(last, '\\N'::text)));
324 2635 aaronmk
325
326
--
327 2634 aaronmk
-- Name: _dateRangeEnd; Type: TRIGGER; Schema: py_functions; Owner: bien
328
--
329
330 3422 aaronmk
CREATE TRIGGER "_dateRangeEnd" BEFORE INSERT OR UPDATE ON "_dateRangeEnd" FOR EACH ROW EXECUTE PROCEDURE "__dateRangeEnd"();
331 2634 aaronmk
332
333
--
334 2630 aaronmk
-- Name: _dateRangeStart; Type: TRIGGER; Schema: py_functions; Owner: bien
335
--
336
337 3422 aaronmk
CREATE TRIGGER "_dateRangeStart" BEFORE INSERT OR UPDATE ON "_dateRangeStart" FOR EACH ROW EXECUTE PROCEDURE "__dateRangeStart"();
338 2630 aaronmk
339
340
--
341 2635 aaronmk
-- Name: _namePart; Type: TRIGGER; Schema: py_functions; Owner: bien
342
--
343
344 3422 aaronmk
CREATE TRIGGER "_namePart" BEFORE INSERT OR UPDATE ON "_namePart" FOR EACH ROW EXECUTE PROCEDURE "__namePart"();
345 2635 aaronmk
346
347
--
348 2620 aaronmk
-- PostgreSQL database dump complete
349
--