Skip to content

Commit b923796

Browse files
authored
Merge pull request #123 from cesmii/FIX/InconsistentDatabaseUsageError
helper utility script to perform data cleanup.
2 parents 40f4bf1 + 901e3b7 commit b923796

File tree

1 file changed

+171
-0
lines changed

1 file changed

+171
-0
lines changed
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,171 @@
1+
--Type definitions - ISA95PropertyDataType
2+
SELECT t.owner_id, u.display_name, u.email_address, t.profile_id, p.namespace, t.name, t.parent_id, t.*
3+
FROM public.profile_type_definition t
4+
JOIN public.user u on u.id = t.owner_id
5+
JOIN public.profile p on p.id = t.profile_id
6+
WHERE (name like 'ISA95PropertyDataType%' OR name like 'ISA95ParameterDataType')
7+
and t.owner_id not in (7, 11, 20, 92, 95, 102, 242, 198, 199, 222)
8+
--and t.owner_id in (222)
9+
;
10+
11+
--Attributes - ISA95PropertyDataType, ISA95ParameterDataType
12+
SELECT t.owner_id, u.display_name, t.profile_id, p.namespace, t.name as typedef_name, a.name, a.data_type_id
13+
, * -- a.*
14+
FROM public.profile_attribute a
15+
JOIN public.data_type d on d.id = a.data_type_id
16+
JOIN public.profile_type_definition t on t.id = a.profile_type_definition_id
17+
JOIN public.profile p on p.id = t.profile_id
18+
JOIN public.user u on u.id = t.owner_id
19+
WHERE
20+
--t.name like 'ISA95MaterialDataType' and
21+
a.name in ('Properties','Subproperties', 'Subparameters')
22+
--and t.owner_id IS NOT null
23+
--and opc_browse_name like '%ISA95-JOBCONTROL%'
24+
--and t.owner_id in (198,199,222,223)
25+
and t.owner_id not in (20, 92, 102, 242, 198, 199)
26+
order by t.owner_id, t.name, a.name
27+
;
28+
29+
--Data type - ISA95PropertyDataType, ISA95ParameterDataType
30+
SELECT t.owner_id, t.profile_id, custom_type_id, t.name, dt.owner_id as dt_owner_id, dt.*
31+
FROM public.data_type dt
32+
JOIN public.profile_type_definition t on t.id = dt.custom_type_id
33+
WHERE dt.name in ('ISA95PropertyDataType', 'ISA95ParameterDataType')
34+
and t.owner_id not in (20)
35+
--and t.owner_id in (11, 199, 222, 223)
36+
--ORDER BY dt.name, t.owner_id, t.profile_id
37+
ORDER BY t.owner_id, t.profile_id, dt.name
38+
;
39+
40+
/*
41+
Steps to correct data. We need to re-assign the profile_type_definition which points to
42+
data type ISA95PropertyDataType, ISA95ParameterDataType
43+
Each user should have its own profile type definition pointing to a unique instance of this data type.
44+
45+
For each owner:
46+
1. Insert 2 record(s) into DataType row - ISA95PropertyDataType, ISA95ParameterDataType
47+
2. Assign custom_type_id to ISA95PropertyDataType, ISA95ParameterDataType for owner
48+
3. Update "Properties" attributes to newly created data_type_id for owner
49+
3a. Update "Subproperties" attributes to newly created data_type_id for owner
50+
3b. Update "Subparameters" attributes to newly created data_type_id for owner
51+
52+
Impacted Users:
53+
1st user (no issue - leave): 7, 11
54+
Corrected: 20 (SC), 242 (PY), 92, 95, 102, 198, 199, 222
55+
Open:
56+
57+
"http://opcfoundation.org/UA/ISA95-JOBCONTROL" -
58+
(4142, 4144)
59+
"http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/" - (5161, 5163)
60+
Check:
61+
"http://opcfoundation.org/UA/TMC/v2/"
62+
63+
*/
64+
--v1 version
65+
INSERT INTO public.data_type(
66+
custom_type_id, code, name, description, display_order, use_min_max, use_eng_unit, is_numeric, is_active)
67+
SELECT t.id, 'http://opcfoundation.org/UA/ISA95-JOBCONTROL.i=3002', 'ISA95PropertyDataType', null, 9998, false, false, false, true
68+
FROM public.profile_type_definition t
69+
WHERE name like 'ISA95PropertyDataType%' and
70+
browse_name like 'http://opcfoundation.org/UA/ISA95-JOBCONTROL;%'
71+
and owner_id = 222
72+
UNION SELECT t.id, 'http://opcfoundation.org/UA/ISA95-JOBCONTROL.i=3003', 'ISA95ParameterDataType', null, 9998, false, false, false, true
73+
FROM public.profile_type_definition t
74+
WHERE name like 'ISA95ParameterDataType%' and
75+
browse_name like 'http://opcfoundation.org/UA/ISA95-JOBCONTROL;%'
76+
and owner_id = 222
77+
;
78+
79+
--v2 version
80+
INSERT INTO public.data_type(
81+
custom_type_id, code, name, description, display_order, use_min_max, use_eng_unit, is_numeric, is_active)
82+
SELECT t.id, 'http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/.i=3002', 'ISA95PropertyDataType', null, 9998, false, false, false, true
83+
FROM public.profile_type_definition t
84+
WHERE name like 'ISA95PropertyDataType%' and
85+
browse_name like 'http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/;%'
86+
and owner_id = 222
87+
UNION SELECT t.id, 'http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/.i=3003', 'ISA95ParameterDataType', null, 9998, false, false, false, true
88+
FROM public.profile_type_definition t
89+
WHERE name like 'ISA95ParameterDataType%' and
90+
browse_name like 'http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/;%'
91+
and owner_id = 222
92+
;
93+
94+
--verify
95+
SELECT *
96+
FROM public.data_type
97+
WHERE name in ('ISA95PropertyDataType', 'ISA95ParameterDataType')
98+
and display_order = 9998
99+
ORDER BY ID desc
100+
--Limit 1
101+
;
102+
103+
--now take newly created data_type and update data_type_id for incorrect owners
104+
--v1 - ISA95ParameterDataType
105+
UPDATE public.profile_attribute
106+
SET data_type_id = (SELECT ID FROM public.data_type
107+
WHERE name like 'ISA95ParameterDataType' and code = 'http://opcfoundation.org/UA/ISA95-JOBCONTROL.i=3003'
108+
ORDER BY ID desc Limit 1)
109+
WHERE
110+
data_type_id IN (4144)
111+
and id in (
112+
SELECT a.ID
113+
FROM public.profile_attribute a
114+
JOIN public.profile_type_definition t on t.id = a.profile_type_definition_id
115+
WHERE
116+
a.name in ('Subparameters')
117+
and owner_id in (222)
118+
)
119+
;
120+
121+
--v2 - ISA95ParameterDataType
122+
UPDATE public.profile_attribute
123+
SET data_type_id = (SELECT ID FROM public.data_type
124+
WHERE name like 'ISA95ParameterDataType' and code = 'http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/.i=3003'
125+
ORDER BY ID desc Limit 1)
126+
WHERE
127+
data_type_id IN (5163)
128+
and id in (
129+
SELECT a.ID
130+
FROM public.profile_attribute a
131+
JOIN public.profile_type_definition t on t.id = a.profile_type_definition_id
132+
WHERE
133+
a.name in ('Subparameters')
134+
and owner_id in (222)
135+
)
136+
;
137+
138+
--v1 - ISA95PropertyDataType
139+
UPDATE public.profile_attribute
140+
SET data_type_id = (SELECT ID FROM public.data_type
141+
WHERE name like 'ISA95PropertyDataType' and code = 'http://opcfoundation.org/UA/ISA95-JOBCONTROL.i=3002'
142+
ORDER BY ID desc Limit 1)
143+
WHERE
144+
data_type_id IN (4142)
145+
and id in (
146+
SELECT a.ID
147+
FROM public.profile_attribute a
148+
JOIN public.profile_type_definition t on t.id = a.profile_type_definition_id
149+
WHERE
150+
a.name in ('Properties', 'Subproperties')
151+
and owner_id in (222)
152+
)
153+
;
154+
155+
--v2 - ISA95PropertyDataType
156+
UPDATE public.profile_attribute
157+
SET data_type_id = (SELECT ID FROM public.data_type
158+
WHERE name like 'ISA95PropertyDataType' and code = 'http://opcfoundation.org/UA/ISA95-JOBCONTROL_V2/.i=3002'
159+
ORDER BY ID desc Limit 1)
160+
WHERE
161+
data_type_id IN (5161)
162+
and id in (
163+
SELECT a.ID
164+
FROM public.profile_attribute a
165+
JOIN public.profile_type_definition t on t.id = a.profile_type_definition_id
166+
WHERE
167+
a.name in ('Properties', 'Subproperties')
168+
and owner_id in (222)
169+
)
170+
;
171+

0 commit comments

Comments
 (0)