1 """GNUmed demographics object.
2
3 This is a patient object intended to let a useful client-side
4 API crystallize from actual use in true XP fashion.
5
6 license: GPL
7 """
8
9
10
11 __version__ = "$Revision: 1.106 $"
12 __author__ = "K.Hilbert <Karsten.Hilbert@gmx.net>, I.Haywood <ihaywood@gnu.org>"
13
14
15 import sys, os.path, time, string, logging
16
17
18
19 if __name__ == '__main__':
20 sys.path.insert(0, '../../')
21 from Gnumed.pycommon import gmDispatcher, gmBusinessDBObject, gmPG2, gmTools
22
23
24 _log = logging.getLogger('gm.business')
25 _log.info(__version__)
26
27
29 cmd = u"""
30 select
31 _(name) as l10n_country, name, code, deprecated
32 from dem.country
33 order by l10n_country"""
34 rows, idx = gmPG2.run_ro_queries(queries = [{'cmd': cmd}])
35 return rows
36
38 cmd = u"""
39 SELECT code_country, l10n_country FROM dem.v_state WHERE l10n_state = %(region)s
40 union
41 SELECT code_country, l10n_country FROM dem.v_state WHERE state = %(region)s
42 """
43 rows, idx = gmPG2.run_ro_queries(queries = [{'cmd': cmd, 'args': {'region': region}}])
44 return rows
45
47
48 args = {'prov': province}
49
50 queries = []
51 if delete_urbs:
52 queries.append ({
53 'cmd': u"""
54 delete from dem.urb du
55 where
56 du.id_state = %(prov)s
57 and
58 not exists (select 1 from dem.street ds where ds.id_urb = du.id)""",
59 'args': args
60 })
61
62 queries.append ({
63 'cmd': u"""
64 delete from dem.state ds
65 where
66 ds.id = %(prov)s
67 and
68 not exists (select 1 from dem.urb du where du.id_state = ds.id)""",
69 'args': args
70 })
71
72 gmPG2.run_rw_queries(queries = queries)
73
74 return True
75
77
78 args = {'code': code, 'country': country, 'name': name}
79
80 cmd = u"""SELECT EXISTS (SELECT 1 FROM dem.state WHERE name = %(name)s)"""
81 rows, idx = gmPG2.run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
82
83 if rows[0][0]:
84 return
85
86 cmd = u"""
87 INSERT INTO dem.state (
88 code, country, name
89 ) VALUES (
90 %(code)s, %(country)s, %(name)s
91 )"""
92 gmPG2.run_rw_queries(queries = [{'cmd': cmd, 'args': args}])
93
95 cmd = u"""
96 select
97 l10n_state, l10n_country, state, code_state, code_country, pk_state, country_deprecated
98 from dem.v_state
99 order by l10n_country, l10n_state"""
100 rows, idx = gmPG2.run_ro_queries(queries = [{'cmd': cmd}])
101 return rows
102
103
104
105 -class cAddress(gmBusinessDBObject.cBusinessDBObject):
106 """A class representing an address as an entity in itself.
107
108 We consider addresses to be self-complete "labels" for locations.
109 It does not depend on any people potentially living there. Thus
110 an address can get attached to as many people as we want to
111 signify that that is their place of residence/work/...
112
113 This class acts on the address as an entity. Therefore it can
114 modify the address fields. Think carefully about *modifying*
115 addresses attached to people, though. Most times when you think
116 person.modify_address() what you *really* want is as sequence of
117 person.unlink_address(old) and person.link_address(new).
118
119 Modifying an address may or may not be the proper thing to do as
120 it will transparently modify the address for *all* the people to
121 whom it is attached. In many cases you will want to create a *new*
122 address and link it to a person instead of the old address.
123 """
124 _cmd_fetch_payload = u"select * from dem.v_address where pk_address=%s"
125 _cmds_store_payload = [
126 u"""update dem.address set
127 aux_street = %(notes_street)s,
128 subunit = %(subunit)s,
129 addendum = %(notes_subunit)s,
130 lat_lon = %(lat_lon_street)s
131 where id=%(pk_address)s and xmin=%(xmin_address)s""",
132 u"select xmin as xmin_address from dem.address where id=%(pk_address)s"
133 ]
134 _updatable_fields = ['notes_street', 'subunit', 'notes_subunit', 'lat_lon_address']
135
136 -def address_exists(country=None, state=None, urb=None, suburb=None, postcode=None, street=None, number=None, subunit=None, notes_street=None, notes_subunit=None):
137
138 where_parts = [u"""
139 code_country = %(country)s and
140 code_state = %(state)s and
141 urb = %(urb)s and
142 postcode = %(postcode)s and
143 street = %(street)s and
144 number = %(number)s"""
145 ]
146
147 if suburb is None:
148 where_parts.append(u"suburb is %(suburb)s")
149 else:
150 where_parts.append(u"suburb = %(suburb)s")
151
152 if notes_street is None:
153 where_parts.append(u"notes_street is %(notes_street)s")
154 else:
155 where_parts.append(u"notes_street = %(notes_street)s")
156
157 if subunit is None:
158 where_parts.append(u"subunit is %(subunit)s")
159 else:
160 where_parts.append(u"subunit = %(subunit)s")
161
162 if notes_subunit is None:
163 where_parts.append(u"notes_subunit is %(notes_subunit)s")
164 else:
165 where_parts.append(u"notes_subunit = %(notes_subunit)s")
166
167 cmd = u"select pk_address from dem.v_address where %s" % u" and ".join(where_parts)
168 data = {
169 'country': country,
170 'state': state,
171 'urb': urb,
172 'suburb': suburb,
173 'postcode': postcode,
174 'street': street,
175 'notes_street': notes_street,
176 'number': number,
177 'subunit': subunit,
178 'notes_subunit': notes_subunit
179 }
180
181 rows, idx = gmPG2.run_ro_queries(queries = [{'cmd': cmd, 'args': data}])
182
183 if len(rows) == 0:
184 return None
185 return rows[0][0]
186
187 -def create_address(country=None, state=None, urb=None, suburb=None, postcode=None, street=None, number=None, subunit=None):
188
189 if suburb is not None:
190 suburb = gmTools.none_if(suburb.strip(), u'')
191
192 pk_address = address_exists (
193 country = country,
194 state = state,
195 urb = urb,
196 suburb = suburb,
197 postcode = postcode,
198 street = street,
199 number = number,
200 subunit = subunit
201 )
202 if pk_address is not None:
203 return cAddress(aPK_obj=pk_address)
204
205 cmd = u"""
206 select dem.create_address (
207 %(number)s,
208 %(street)s,
209 %(postcode)s,
210 %(urb)s,
211 %(state)s,
212 %(country)s,
213 %(subunit)s
214 )"""
215 args = {
216 'number': number,
217 'street': street,
218 'postcode': postcode,
219 'urb': urb,
220 'state': state,
221 'country': country,
222 'subunit': subunit
223 }
224 queries = [{'cmd': cmd, 'args': args}]
225
226 rows, idx = gmPG2.run_rw_queries(queries = queries, return_data = True)
227 adr = cAddress(aPK_obj=rows[0][0])
228
229 if suburb is not None:
230 queries = [{
231
232 'cmd': u"update dem.street set suburb = %(suburb)s where id=%(pk_street)s and suburb is Null",
233 'args': {'suburb': suburb, 'pk_street': adr['pk_street']}
234 }]
235 rows, idx = gmPG2.run_rw_queries(queries = queries)
236
237 return adr
238
240 cmd = u"delete from dem.address where id=%s"
241 rows, idx = gmPG2.run_rw_queries(queries=[{'cmd': cmd, 'args': [address['pk_address']]}])
242 return True
243
245 cmd = u'select id as pk, name, _(name) as l10n_name from dem.address_type'
246 rows, idx = gmPG2.run_rw_queries(queries=[{'cmd': cmd}])
247 return rows
248
250
251 _cmd_fetch_payload = u"select * from dem.v_pat_addresses where pk_address=%s"
252 _cmds_store_payload = [
253 u"""update dem.lnk_person_org_address set id_type=%(pk_address_type)s
254 where id=%(pk_lnk_person_org_address)s and xmin=%(xmin_lnk_person_org_address)s""",
255 u"""select xmin from dem.lnk_person_org_address where id=%(pk_lnk_person_org_address)s"""
256 ]
257 _updatable_fields = ['pk_address_type']
258
261
262
263
265
266 _cmd_fetch_payload = u"select * from dem.v_person_comms where pk_lnk_identity2comm = %s"
267 _cmds_store_payload = [
268 u"""update dem.lnk_identity2comm set
269 fk_address = %(pk_address)s,
270 fk_type = dem.create_comm_type(%(comm_type)s),
271 url = %(url)s,
272 is_confidential = %(is_confidential)s
273 where pk = %(pk_lnk_identity2comm)s and xmin = %(xmin_lnk_identity2comm)s
274 """,
275 u"select xmin as xmin_lnk_identity2comm from dem.lnk_identity2comm where pk = %(pk_lnk_identity2comm)s"
276 ]
277 _updatable_fields = ['pk_address', 'url', 'comm_type', 'is_confidential']
278
279 -def create_comm_channel(comm_medium=None, url=None, is_confidential=False, pk_channel_type=None, pk_identity=None):
280 """Create a communications channel for a patient."""
281
282 if url is None:
283 return None
284
285
286 args = {'pat': pk_identity, 'url': url, 'secret': is_confidential}
287
288 if pk_channel_type is None:
289 args['type'] = comm_medium
290 cmd = u"""insert into dem.lnk_identity2comm (
291 fk_identity,
292 url,
293 fk_type,
294 is_confidential
295 ) values (
296 %(pat)s,
297 %(url)s,
298 dem.create_comm_type(%(type)s),
299 %(secret)s
300 )"""
301 else:
302 args['type'] = pk_channel_type
303 cmd = u"""insert into dem.lnk_identity2comm (
304 fk_identity,
305 url,
306 fk_type,
307 is_confidential
308 ) values (
309 %(pat)s,
310 %(url)s,
311 %(type)s,
312 %(secret)s
313 )"""
314
315 rows, idx = gmPG2.run_rw_queries (
316 queries = [
317 {'cmd': cmd, 'args': args},
318 {'cmd': u"select * from dem.v_person_comms where pk_lnk_identity2comm = currval(pg_get_serial_sequence('dem.lnk_identity2comm', 'pk'))"}
319 ],
320 return_data = True,
321 get_col_idx = True
322 )
323
324 return cCommChannel(row = {'pk_field': 'pk_lnk_identity2comm', 'data': rows[0], 'idx': idx})
325
327 cmd = u"delete from dem.lnk_identity2comm where pk = %(pk)s and fk_identity = %(pat)s"
328 args = {'pk': pk, 'pat': pk_patient}
329 gmPG2.run_rw_queries(queries = [{'cmd': cmd, 'args': args}])
330
331 __comm_channel_types = None
332
340
341
342
343 -class cOrg (gmBusinessDBObject.cBusinessDBObject):
344 """
345 Organisations
346
347 This is also the common ancestor of cIdentity, self._table is used to
348 hide the difference.
349 The aim is to be able to sanely write code which doesn't care whether
350 its talking to an organisation or an individual"""
351 _table = "org"
352
353 _cmd_fetch_payload = "select *, xmin from dem.org where id=%s"
354 _cmds_lock_rows_for_update = ["select 1 from dem.org where id=%(id)s and xmin=%(xmin)s"]
355 _cmds_store_payload = [
356 """update dem.org set
357 description=%(description)s,
358 id_category=(select id from dem.org_category where description=%(occupation)s)
359 where id=%(id)s""",
360 "select xmin from dem.org where id=%(id)s"
361 ]
362 _updatable_fields = ["description", "occupation"]
363 _service = 'personalia'
364
367
369 if not self.__cache.has_key ('addresses'):
370 self['addresses']
371 if not self.__cache.has_key ('comms'):
372 self['comms']
373 return self.__cache
374
376 """
377 Returns a list of (address dict, cIdentity) tuples
378 """
379 cmd = """select
380 vba.id,
381 vba.number,
382 vba.addendum,
383 vba.street,
384 vba.urb,
385 vba.postcode,
386 at.name,
387 lpoa.id_type,
388 vbp.pk_identity,
389 title,
390 firstnames,
391 lastnames,
392 dob,
393 cob,
394 gender,
395 pupic,
396 pk_marital_status,
397 marital_status,
398 karyotype,
399 xmin_identity,
400 preferred
401 from
402 dem.v_basic_address vba,
403 dem.lnk_person_org_address lpoa,
404 dem.address_type at,
405 dem.v_basic_person vbp
406 where
407 lpoa.id_address = vba.id
408 and lpoa.id_type = at.id
409 and lpoa.id_identity = vbp.pk_identity
410 and lpoa.id_org = %%s
411 """
412
413 rows, idx = gmPG.run_ro_query('personalia', cmd, 1, self.getId ())
414 if rows is None:
415 return []
416 elif len(rows) == 0:
417 return []
418 else:
419 return [({'pk':i[0], 'number':i[1], 'addendum':i[2], 'street':i[3], 'city':i[4], 'postcode':i[5], 'type':i[6], 'id_type':i[7]}, cIdentity (row = {'data':i[8:], 'id':idx[8:], 'pk_field':'id'})) for i in rows]
420
422 """
423 Binds a person to this organisation at this address.
424 person is a cIdentity object
425 address is a dict of {'number', 'street', 'addendum', 'city', 'postcode', 'type'}
426 type is one of the IDs returned by getAddressTypes
427 """
428 cmd = "insert into dem.lnk_person_org_address (id_type, id_address, id_org, id_identity) values (%(type)s, dem.create_address (%(number)s, %(addendum)s, %(street)s, %(city)s, %(postcode)s), %(org_id)s, %(pk_identity)s)"
429 address['pk_identity'] = person['pk_identity']
430 address['org_id'] = self.getId()
431 if not id_addr:
432 return (False, None)
433 return gmPG.run_commit2 ('personalia', [(cmd, [address])])
434
438
440 """
441 Hide the difference between org.id and v_basic_person.pk_identity
442 """
443 return self['id']
444
446 """
447 wrap mx.DateTime brokenness
448 Returns 9-tuple for use with pyhon time functions
449 """
450 return [ int(x) for x in str(mx).split(' ')[0].split('-') ] + [0,0,0, 0,0,0]
451
453 """Gets a dict matching address types to their ID"""
454 row_list = gmPG.run_ro_query('personalia', "select name, id from dem.address_type")
455 if row_list is None:
456 return {}
457 if len(row_list) == 0:
458 return {}
459 return dict (row_list)
460
462 """Gets a dictionary matching marital status types to their internal ID"""
463 row_list = gmPG.run_ro_query('personalia', "select name, pk from dem.marital_status")
464 if row_list is None:
465 return {}
466 if len(row_list) == 0:
467 return {}
468 return dict(row_list)
469
471 """Gets a dictionary of relationship types to internal id"""
472 row_list = gmPG.run_ro_query('personalia', "select description, id from dem.relation_types")
473 if row_list is None:
474 return None
475 if len (row_list) == 0:
476 return None
477 return dict(row_list)
478
479
481 cmd = """
482 select
483 dem.state.name,
484 dem.urb.postcode
485 from
486 dem.urb,
487 dem.state
488 where
489 dem.urb.id = %s and
490 dem.urb.id_state = dem.state.id"""
491 row_list = gmPG.run_ro_query('personalia', cmd, None, id_urb)
492 if not row_list:
493 return None
494 else:
495 return (row_list[0][0], row_list[0][1])
496
498 cmd = """
499 select
500 dem.state.name,
501 coalesce (dem.street.postcode, dem.urb.postcode),
502 dem.urb.name
503 from
504 dem.urb,
505 dem.state,
506 dem.street
507 where
508 dem.street.id = %s and
509 dem.street.id_urb = dem.urb.id and
510 dem.urb.id_state = dem.state.id
511 """
512 row_list = gmPG.run_ro_query('personalia', cmd, None, id_street)
513 if not row_list:
514 return None
515 else:
516 return (row_list[0][0], row_list[0][1], row_list[0][2])
517
519 row_list = gmPG.run_ro_query('personalia', "select name from dem.country where code = %s", None, country_code)
520 if not row_list:
521 return None
522 else:
523 return row_list[0][0]
524
526 row_list = gmPG.run_ro_query ('personalia', """
527 select
528 dem.urb.postcode,
529 dem.state.code,
530 dem.state.name,
531 dem.country.code,
532 dem.country.name
533 from
534 dem.urb,
535 dem.state,
536 dem.country
537 where
538 dem.urb.name = %s and
539 dem.urb.id_state = dem.state.id and
540 dem.state.country = dem.country.code""", None, town)
541 if not row_list:
542 return (None, None, None, None, None)
543 else:
544 return tuple (row_list[0])
545
546
547
549 print "received post_patient_selection notification"
550 print kwargs['kwds']
551
552
553
554
555
556 if __name__ == "__main__":
557
558 if len(sys.argv) < 2:
559 sys.exit()
560
561 import random
562
564 exists = address_exists (
565 country ='Germany',
566 state ='Sachsen',
567 urb ='Leipzig',
568 suburb ='Sellerhausen',
569 postcode ='04318',
570 street = u'Cunnersdorfer Strasse',
571 number = '11',
572 notes_subunit = '4.Stock rechts'
573 )
574 if exists is None:
575 print "address does not exist"
576 else:
577 print "address exists, primary key:", exists
578
580 address = create_address (
581 country ='DE',
582 state ='SN',
583 urb ='Leipzig',
584 suburb ='Sellerhausen',
585 postcode ='04318',
586 street = u'Cunnersdorfer Strasse',
587 number = '11'
588
589 )
590 print "created existing address"
591 print address
592
593 su = str(random.random())
594
595 address = create_address (
596 country ='DE',
597 state = 'SN',
598 urb ='Leipzig',
599 suburb ='Sellerhausen',
600 postcode ='04318',
601 street = u'Cunnersdorfer Strasse',
602 number = '11',
603
604 subunit = su
605 )
606 print "created new address with subunit", su
607 print address
608 print "deleted address:", delete_address(address)
609
613
615 region = raw_input("Please enter a region: ")
616 print "country for region [%s] is: %s" % (region, get_country_for_region(region = region))
617
618 if sys.argv[1] != 'test':
619 sys.exit()
620
621
622
623
624
625
626 test_get_country_for_region()
627
628 sys.exit()
629
630 gmDispatcher.connect(_post_patient_selection, 'post_patient_selection')
631 while 1:
632 pID = raw_input('a patient: ')
633 if pID == '':
634 break
635 try:
636 print pID
637 myPatient = gmPerson.cIdentity (aPK_obj = pID)
638 except:
639 _log.exception('Unable to set up patient with ID [%s]' % pID)
640 print "patient", pID, "can not be set up"
641 continue
642 print "ID ", myPatient.ID
643 print "name ", myPatient['description']
644 print "name ", myPatient['description_gender']
645 print "title ", myPatient['title']
646 print "dob ", myPatient['dob']
647 print "med age ", myPatient['medical_age']
648 for adr in myPatient.get_addresses():
649 print "address ", adr
650 print "--------------------------------------"
651
652