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: _date(text, text, text, text); Type: FUNCTION; Schema: py_functions; Owner: bien
25
--
26

    
27
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
28
    LANGUAGE plpythonu IMMUTABLE
29
    AS $$
30
global date, year, month, day
31

    
32
import datetime
33
import dateutil.tz
34

    
35
def e_str(e):
36
    msg = e.__class__.__name__+': '+e.args[0]
37
    return msg.rstrip()
38

    
39
class ExceptionWithCause(Exception):
40
    def __init__(self, msg, cause):
41
        msg += ': '+e_str(cause)
42
        Exception.__init__(self, msg)
43

    
44
utc = dateutil.tz.tzutc()
45

    
46
def naive2utc(datetime_):
47
    assert datetime_.tzinfo == None
48
    return datetime_.replace(tzinfo=utc)
49

    
50
def from_timestamp(utc_timestamp):
51
    return naive2utc(datetime.datetime.utcfromtimestamp(utc_timestamp))
52

    
53
epoch = from_timestamp(0)
54

    
55
def strftime(format, datetime_):
56
    '''datetime.strftime() can't handle years before 1900'''
57
    return (datetime_.replace(year=epoch.year, day=1).strftime(format
58
        .replace('%Y', '%%Y')
59
        .replace('%d', '%%d')
60
        )
61
        .replace('%Y', '%04d' % datetime_.year)
62
        .replace('%d', '%02d' % datetime_.day)
63
        )
64

    
65
def strtotime(str_, default=epoch):
66
    import dateutil.parser
67
    return dateutil.parser.parse(str_, default=default)
68

    
69
class FormatException(ExceptionWithCause):
70
    def __init__(self, cause):
71
        ExceptionWithCause.__init__(self, 'Invalid input value', cause)
72

    
73
if date != None:
74
    str_ = date
75
    try: year = float(str_)
76
    except ValueError:
77
        try: date = strtotime(str_)
78
        except ImportError: return str_
79
        except ValueError, e: raise FormatException(e)
80
    else: date = (datetime.date(int(year), 1, 1) +
81
        datetime.timedelta(round((year % 1.)*365)))
82
else:
83
    # Year is required
84
    if year == None:
85
        if month == None and day == None: return None # entire date is empty
86
        else: raise FormatException(ValueError('Year is required'))
87
    
88
    # Convert month name to number
89
    if month != None and not month.isdigit(): # month is name
90
        try: month = str(strtotime(month).month)
91
        except ValueError, e: raise FormatException(e)
92
    
93
    if month == None: month = 1
94
    if day == None: day = 1
95
    year, month, day = map(int, (year, month, day))
96
    
97
    for try_num in xrange(2):
98
        try:
99
            date = datetime.date(year, month, day)
100
            break
101
        except ValueError, e:
102
            if try_num > 0: raise FormatException(e)
103
                # exception still raised after retry
104
            msg = e_str(e)
105
            if msg == 'month must be in 1..12': # try swapping month and day
106
                month, day = day, month
107
            else: raise FormatException(e)
108

    
109
try: return strftime('%Y-%m-%d', date)
110
except ValueError, e: raise FormatException(e)
111
$$;
112

    
113

    
114
--
115
-- Name: _dateRangeEnd(); Type: FUNCTION; Schema: py_functions; Owner: bien
116
--
117

    
118
CREATE FUNCTION "_dateRangeEnd"() RETURNS trigger
119
    LANGUAGE plpgsql IMMUTABLE
120
    AS $$
121
BEGIN
122
    new.result := py_functions."_dateRangeEnd"(new.value);
123
    RETURN new;
124
END;
125
$$;
126

    
127

    
128
--
129
-- Name: _dateRangeEnd(text); Type: FUNCTION; Schema: py_functions; Owner: bien
130
--
131

    
132
CREATE FUNCTION "_dateRangeEnd"(value text) RETURNS text
133
    LANGUAGE sql IMMUTABLE
134
    AS $_$
135
SELECT (py_functions.parse_date_range($1))[2]
136
$_$;
137

    
138

    
139
--
140
-- Name: _dateRangeStart(); Type: FUNCTION; Schema: py_functions; Owner: bien
141
--
142

    
143
CREATE FUNCTION "_dateRangeStart"() RETURNS trigger
144
    LANGUAGE plpgsql IMMUTABLE
145
    AS $$
146
BEGIN
147
    new.result := py_functions."_dateRangeStart"(new.value);
148
    RETURN new;
149
END;
150
$$;
151

    
152

    
153
--
154
-- Name: _dateRangeStart(text); Type: FUNCTION; Schema: py_functions; Owner: bien
155
--
156

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

    
163

    
164
--
165
-- Name: _namePart(); Type: FUNCTION; Schema: py_functions; Owner: bien
166
--
167

    
168
CREATE FUNCTION "_namePart"() RETURNS trigger
169
    LANGUAGE plpgsql IMMUTABLE
170
    AS $$
171
BEGIN
172
    new.result := py_functions."_namePart"(new.first, new.middle, new.last);
173
    RETURN new;
174
END;
175
$$;
176

    
177

    
178
--
179
-- Name: _namePart(text, text, text); Type: FUNCTION; Schema: py_functions; Owner: bien
180
--
181

    
182
CREATE FUNCTION "_namePart"(first text DEFAULT NULL::text, middle text DEFAULT NULL::text, last text DEFAULT NULL::text) RETURNS text
183
    LANGUAGE plpythonu IMMUTABLE
184
    AS $$
185
params = dict(first=first, middle=middle, last=last)
186

    
187
_name_parts_slices_items = [
188
    ('first', slice(None, 1)),
189
    ('middle', slice(1, -1)),
190
    ('last', slice(-1, None)),
191
]
192
name_parts_slices = dict(_name_parts_slices_items)
193
name_parts = [name for name, slice_ in _name_parts_slices_items]
194

    
195
def _name(items):
196
    items = dict(items)
197
    parts = []
198
    for part in name_parts:
199
        if part in items: parts.append(items[part])
200
    return ' '.join(parts)
201

    
202
out_items = []
203
for part, value in params.iteritems():
204
    if value == None: continue
205
    
206
    try: slice_ = name_parts_slices[part]
207
    except KeyError: pass # a non-value column
208
    else: out_items.append((part, ' '.join(value.split(' ')[slice_])))
209

    
210
return _name(out_items)
211
$$;
212

    
213

    
214
--
215
-- Name: parse_date_range(text); Type: FUNCTION; Schema: py_functions; Owner: bien
216
--
217

    
218
CREATE FUNCTION parse_date_range(str_ text) RETURNS text[]
219
    LANGUAGE plpythonu IMMUTABLE STRICT
220
    AS $$
221
import re
222

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

    
225
def could_be_year(str_): return str_.isdigit() and len(str_) == 4
226

    
227
def could_be_day(str_): return str_.isdigit() and len(str_) <= 2
228

    
229
range_sep='-'
230
part_sep=' '
231

    
232
default = (str_, None)
233
# range_sep might be used as date part separator instead
234
if str_.find(part_sep) < 0: return default
235

    
236
start, sep, end = str_.partition(range_sep)
237
if sep == '': return default # not a range
238
start, end = (single_space(d).split(part_sep) for d in (start, end))
239

    
240
# Has form M D1-D2 or M D1-D2 Y (not M1 Y1-M2 Y2 or M1 D1-M2 D2)
241
if len(start) == 2 and (len(end) == 1 or (
242
        len(end) == 2 and could_be_day(start[-1]) and could_be_day(end[0])
243
        and could_be_year(end[-1])
244
    )):
245
    end.insert(0, start[0]) # make end fully specified
246
ct_diff = len(end) - len(start)
247
# Has form D1-D2 M Y, M1 D1-M2 D2 Y, M1-M2 Y, etc.
248
if ct_diff > 0: start += end[-ct_diff:] # make start fully specified
249
# Other forms are invalid and will be left as-is
250

    
251
return [part_sep.join(d) for d in (start, end)]
252
$$;
253

    
254

    
255
SET default_tablespace = '';
256

    
257
SET default_with_oids = false;
258

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

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

    
269

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

    
274
CREATE TABLE "_dateRangeStart" (
275
    result text,
276
    not_null_col boolean DEFAULT true NOT NULL,
277
    value text
278
);
279

    
280

    
281
--
282
-- Name: _namePart; Type: TABLE; Schema: py_functions; Owner: bien; Tablespace: 
283
--
284

    
285
CREATE TABLE "_namePart" (
286
    result text,
287
    not_null_col boolean DEFAULT true NOT NULL,
288
    first text,
289
    middle text,
290
    last text
291
);
292

    
293

    
294
--
295
-- Name: _dateRangeEnd_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace: 
296
--
297

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

    
300

    
301
--
302
-- Name: _dateRangeStart_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace: 
303
--
304

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

    
307

    
308
--
309
-- Name: _namePart_unique; Type: INDEX; Schema: py_functions; Owner: bien; Tablespace: 
310
--
311

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

    
314

    
315
--
316
-- Name: _dateRangeEnd; Type: TRIGGER; Schema: py_functions; Owner: bien
317
--
318

    
319
CREATE TRIGGER "_dateRangeEnd" BEFORE INSERT OR UPDATE ON "_dateRangeEnd" FOR EACH ROW EXECUTE PROCEDURE "_dateRangeEnd"();
320

    
321

    
322
--
323
-- Name: _dateRangeStart; Type: TRIGGER; Schema: py_functions; Owner: bien
324
--
325

    
326
CREATE TRIGGER "_dateRangeStart" BEFORE INSERT OR UPDATE ON "_dateRangeStart" FOR EACH ROW EXECUTE PROCEDURE "_dateRangeStart"();
327

    
328

    
329
--
330
-- Name: _namePart; Type: TRIGGER; Schema: py_functions; Owner: bien
331
--
332

    
333
CREATE TRIGGER "_namePart" BEFORE INSERT OR UPDATE ON "_namePart" FOR EACH ROW EXECUTE PROCEDURE py_functions."_namePart"();
334

    
335

    
336
--
337
-- PostgreSQL database dump complete
338
--
339

    
(8-8/19)