Project

General

Profile

1
--
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
SET SESSION AUTHORIZATION 'bien';
13

    
14
--
15
-- Name: py_functions; Type: SCHEMA; Schema: -; Owner: bien
16
--
17

    
18
CREATE SCHEMA py_functions;
19

    
20

    
21
SET search_path = py_functions, pg_catalog;
22

    
23
--
24
-- 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
--
38
-- Name: __dateRangeStart(); Type: FUNCTION; Schema: py_functions; Owner: bien
39
--
40

    
41
CREATE FUNCTION "__dateRangeStart"() RETURNS trigger
42
    LANGUAGE plpgsql IMMUTABLE
43
    AS $$
44
BEGIN
45
    new.result := py_functions."_dateRangeStart"(new.value);
46
    RETURN new;
47
END;
48
$$;
49

    
50

    
51
--
52
-- Name: __namePart(); Type: FUNCTION; Schema: py_functions; Owner: bien
53
--
54

    
55
CREATE FUNCTION "__namePart"() RETURNS trigger
56
    LANGUAGE plpgsql IMMUTABLE
57
    AS $$
58
BEGIN
59
    new.result := py_functions."_namePart"(new.first, new.middle, new.last);
60
    RETURN new;
61
END;
62
$$;
63

    
64

    
65
--
66
-- Name: _date(text, text, text, text); Type: FUNCTION; Schema: py_functions; Owner: bien
67
--
68

    
69
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
70
    LANGUAGE plpythonu IMMUTABLE
71
    AS $$
72
global date, year, month, day
73

    
74
import datetime
75
import dateutil.tz
76

    
77
def e_str(e):
78
    msg = e.__class__.__name__+': '+e.args[0]
79
    return msg.rstrip()
80

    
81
class ExceptionWithCause(Exception):
82
    def __init__(self, msg, cause):
83
        msg += ': '+e_str(cause)
84
        Exception.__init__(self, msg)
85

    
86
utc = dateutil.tz.tzutc()
87

    
88
def naive2utc(datetime_):
89
    assert datetime_.tzinfo == None
90
    return datetime_.replace(tzinfo=utc)
91

    
92
def from_timestamp(utc_timestamp):
93
    return naive2utc(datetime.datetime.utcfromtimestamp(utc_timestamp))
94

    
95
epoch = from_timestamp(0)
96

    
97
def strtotime(str_, default=epoch):
98
    import dateutil.parser
99
    return dateutil.parser.parse(str_, default=default)
100

    
101
class FormatException(ExceptionWithCause):
102
    def __init__(self, cause):
103
        ExceptionWithCause.__init__(self, 'Invalid input value', cause)
104

    
105
if date != None:
106
    str_ = date
107
    try: year = float(str_)
108
    except ValueError:
109
        try: date = strtotime(str_)
110
        except ImportError: return str_
111
        except ValueError, e: raise FormatException(e)
112
    else: date = (datetime.date(int(year), 1, 1) +
113
        datetime.timedelta(round((year % 1.)*365)))
114
else:
115
    # Year is required
116
    if year == None:
117
        if month == None and day == None: return None # entire date is empty
118
        else: raise FormatException(ValueError('Year is required'))
119
    
120
    # Convert month name to number
121
    if month != None and not month.isdigit(): # month is name
122
        try: month = str(strtotime(month).month)
123
        except ValueError, e: raise FormatException(e)
124
    
125
    if month == None: month = 1
126
    if day == None: day = 1
127
    year, month, day = map(int, (year, month, day))
128
    
129
    for try_num in xrange(2):
130
        try:
131
            date = datetime.date(year, month, day)
132
            break
133
        except ValueError, e:
134
            if try_num > 0: raise FormatException(e)
135
                # exception still raised after retry
136
            msg = e_str(e)
137
            if msg == 'month must be in 1..12': # try swapping month and day
138
                month, day = day, month
139
            else: raise FormatException(e)
140

    
141
return str(date)
142
$$;
143

    
144

    
145
--
146
-- Name: _dateRangeEnd(text); Type: FUNCTION; Schema: py_functions; Owner: bien
147
--
148

    
149
CREATE FUNCTION "_dateRangeEnd"(value text) RETURNS text
150
    LANGUAGE sql IMMUTABLE
151
    AS $_$
152
SELECT (py_functions.parse_date_range($1))[2]
153
$_$;
154

    
155

    
156
--
157
-- Name: _dateRangeStart(text); Type: FUNCTION; Schema: py_functions; Owner: bien
158
--
159

    
160
CREATE FUNCTION "_dateRangeStart"(value text) RETURNS text
161
    LANGUAGE sql IMMUTABLE
162
    AS $_$
163
SELECT (py_functions.parse_date_range($1))[1]
164
$_$;
165

    
166

    
167
--
168
-- Name: _namePart(text, text, text); Type: FUNCTION; Schema: py_functions; Owner: bien
169
--
170

    
171
CREATE FUNCTION "_namePart"(first text DEFAULT NULL::text, middle text DEFAULT NULL::text, last text DEFAULT NULL::text) RETURNS text
172
    LANGUAGE plpythonu IMMUTABLE
173
    AS $$
174
params = dict(first=first, middle=middle, last=last)
175

    
176
_name_parts_slices_items = [
177
    ('first', slice(None, 1)),
178
    ('middle', slice(1, -1)),
179
    ('last', slice(-1, None)),
180
]
181
name_parts_slices = dict(_name_parts_slices_items)
182
name_parts = [name for name, slice_ in _name_parts_slices_items]
183

    
184
def _name(items):
185
    items = dict(items)
186
    parts = []
187
    for part in name_parts:
188
        if part in items: parts.append(items[part])
189
    return ' '.join(parts)
190

    
191
out_items = []
192
for part, value in params.iteritems():
193
    if value == None: continue
194
    
195
    try: slice_ = name_parts_slices[part]
196
    except KeyError: pass # a non-value column
197
    else: out_items.append((part, ' '.join(value.split(' ')[slice_])))
198

    
199
return _name(out_items)
200
$$;
201

    
202

    
203
--
204
-- Name: parse_date_range(text); Type: FUNCTION; Schema: py_functions; Owner: bien
205
--
206

    
207
CREATE FUNCTION parse_date_range(str_ text) RETURNS text[]
208
    LANGUAGE plpythonu IMMUTABLE STRICT
209
    AS $$
210
import re
211

    
212
def single_space(str_): return re.sub(r' {2,}', r' ', str_.strip())
213

    
214
def could_be_year(str_): return str_.isdigit() and len(str_) == 4
215

    
216
def could_be_day(str_): return str_.isdigit() and len(str_) <= 2
217

    
218
range_sep='-'
219
part_sep=' '
220

    
221
default = (str_, None)
222
# range_sep might be used as date part separator instead
223
if str_.find(part_sep) < 0: return default
224

    
225
start, sep, end = str_.partition(range_sep)
226
if sep == '': return default # not a range
227
start, end = (single_space(d).split(part_sep) for d in (start, end))
228

    
229
# Has form M D1-D2 or M D1-D2 Y (not M1 Y1-M2 Y2 or M1 D1-M2 D2)
230
if len(start) == 2 and (len(end) == 1 or (
231
        len(end) == 2 and could_be_day(start[-1]) and could_be_day(end[0])
232
        and could_be_year(end[-1])
233
    )):
234
    end.insert(0, start[0]) # make end fully specified
235
ct_diff = len(end) - len(start)
236
# Has form D1-D2 M Y, M1 D1-M2 D2 Y, M1-M2 Y, etc.
237
if ct_diff > 0: start += end[-ct_diff:] # make start fully specified
238
# Other forms are invalid and will be left as-is
239

    
240
return [part_sep.join(d) for d in (start, end)]
241
$$;
242

    
243

    
244
SET default_tablespace = '';
245

    
246
SET default_with_oids = false;
247

    
248
--
249
-- Name: _dateRangeEnd; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace: 
250
--
251

    
252
CREATE TABLE "_dateRangeEnd" (
253
    result text,
254
    not_null_col boolean DEFAULT true NOT NULL,
255
    value text
256
);
257

    
258

    
259
--
260
-- Name: _dateRangeStart; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace: 
261
--
262

    
263
CREATE TABLE "_dateRangeStart" (
264
    result text,
265
    not_null_col boolean DEFAULT true NOT NULL,
266
    value text
267
);
268

    
269

    
270
--
271
-- Name: _namePart; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace: 
272
--
273

    
274
CREATE TABLE "_namePart" (
275
    result text,
276
    not_null_col boolean DEFAULT true NOT NULL,
277
    first text,
278
    middle text,
279
    last text
280
);
281

    
282

    
283
--
284
-- Name: _dateRangeEnd_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace: 
285
--
286

    
287
CREATE UNIQUE INDEX "_dateRangeEnd_unique" ON "_dateRangeEnd" USING btree ((COALESCE(value, '\\N'::text)));
288

    
289

    
290
--
291
-- Name: _dateRangeStart_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace: 
292
--
293

    
294
CREATE UNIQUE INDEX "_dateRangeStart_unique" ON "_dateRangeStart" USING btree ((COALESCE(value, '\\N'::text)));
295

    
296

    
297
--
298
-- Name: _namePart_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace: 
299
--
300

    
301
CREATE UNIQUE INDEX "_namePart_unique" ON "_namePart" USING btree ((COALESCE(first, '\\N'::text)), (COALESCE(middle, '\\N'::text)), (COALESCE(last, '\\N'::text)));
302

    
303

    
304
--
305
-- Name: _dateRangeEnd; Type: TRIGGER; Schema: py_functions; Owner: bien
306
--
307

    
308
CREATE TRIGGER "_dateRangeEnd" BEFORE INSERT OR UPDATE ON "_dateRangeEnd" FOR EACH ROW EXECUTE PROCEDURE "__dateRangeEnd"();
309

    
310

    
311
--
312
-- Name: _dateRangeStart; Type: TRIGGER; Schema: py_functions; Owner: bien
313
--
314

    
315
CREATE TRIGGER "_dateRangeStart" BEFORE INSERT OR UPDATE ON "_dateRangeStart" FOR EACH ROW EXECUTE PROCEDURE "__dateRangeStart"();
316

    
317

    
318
--
319
-- Name: _namePart; Type: TRIGGER; Schema: py_functions; Owner: bien
320
--
321

    
322
CREATE TRIGGER "_namePart" BEFORE INSERT OR UPDATE ON "_namePart" FOR EACH ROW EXECUTE PROCEDURE "__namePart"();
323

    
324

    
325
--
326
-- PostgreSQL database dump complete
327
--
328

    
(8-8/19)