File: oscar-schema.sql

package info (click to toggle)
gnumed-server 16.17-1
  • links: PTS, VCS
  • area: main
  • in suites: wheezy
  • size: 42,064 kB
  • sloc: sql: 1,190,603; python: 11,850; sh: 1,082; makefile: 19
file content (118 lines) | stat: -rw-r--r-- 2,684 bytes parent folder | download | duplicates (8)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118

\unset ON_ERROR_STOP
drop schema oscar cascade;
\set ON_ERROR_STOP 1

create schema oscar authorization "gm-dbo";

create table oscar.country (
	country varchar(2)
		primary key
);
insert into oscar.country values ('AU');

create table oscar.oscar_to_gnumed_types (
	oscar text,
	gnumed text,
	country varchar(2)
		references oscar.country
);
create unique index idx_oscar_to_gnumed_types on oscar.oscar_to_gnumed_types (oscar, gnumed, country);
insert into oscar.oscar_to_gnumed_types (oscar, gnumed, country) values ('hin', 'Medicare', 'AU');
insert into oscar.oscar_to_gnumed_types (oscar, gnumed, country) values ('chart_no', 'ur_no', 'AU');

create view oscar.demographic as 
select 
	pk_identity as demographic_no , 
	lastnames as last_name, 
	firstnames as first_name , 
	gender as sex, 
	to_char(dob, 'YYYY') as year_of_birth  , 
	to_char(dob, 'MM') as month_of_birth, 
	to_char(dob, 'DD') as date_of_birth  , 
	number || ', '|| street as address,
	urb as city, 
	state as province, 
	postcode as postal,
	phone,
	phone2,
	hin,
	chart_no,
	''::text as roster_status,
	''::text as patient_status,
	''::text as provider_no
from 
	(select *
	from 
		dem.v_basic_person p, 
		dem.v_basic_address a , 
		dem.lnk_person2address lpa 
		where 
			p.pk_identity = lpa.id_identity and
			a.id = lpa.id_address
	) i1   

		left outer join 

	(select 
		url as phone, id_identity  
	from 
		dem.lnk_identity2comm c2a 
	where 
		c2a.id_type = 
			(select id from dem.enum_comm_types ect1 where ect1.description='homephone') 
	) c2 on c2.id_identity = i1.pk_identity 

		left outer join 

	(select 
		url as phone2, id_identity 
	from 
	dem.lnk_identity2comm c2b 
		where 
			c2b.id_type = 
				(select id from dem.enum_comm_types ect where ect.description ='mobile') 
	) c3 on c3.id_identity = i1.pk_identity 

	left outer join 

	(select 
		external_id as hin, id_identity 
	from 
		dem.lnk_identity2ext_id  li1 
	where 
		li1.fk_origin = ( 
			select pk
			from dem.enum_ext_id_types 
			where name = (
				select gnumed
				from oscar.oscar_to_gnumed_types t1 
				where
					t1.oscar = 'hin' and 
					t1.country = (select country from oscar.country limit 1) 
				)
		)
	) li2 on li2.id_identity = i1.pk_identity
	
	left outer join

	(select external_id as chart_no , id_identity
	from 
		dem.lnk_identity2ext_id li3
	where
		li3.fk_origin = ( 
			select pk
			from dem.enum_ext_id_types
			where
				name = (
					select gnumed
					from oscar.oscar_to_gnumed_types t1
					where
						t1.oscar = 'chart_no' and t1.country = (select country from oscar.country limit 1)
				)
		)
	) li3 on li3.id_identity = i1.pk_identity

;

grant select on oscar.demographic to group "gm-doctors";