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
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
|
from typing import Any, Tuple, Union
import MySQLdb
def get_trait_csv_sample_data(conn: Any,
trait_name: int, phenotype_id: int) -> str:
"""Fetch a trait and return it as a csv string"""
__query = ("SELECT concat(st.Name, ',', ifnull(pd.value, 'x'), ',', "
"ifnull(ps.error, 'x'), ',', ifnull(ns.count, 'x')) as 'Data' "
",ifnull(ca.Name, 'x') as 'CaseAttr', "
"ifnull(cxref.value, 'x') as 'Value' "
"FROM PublishFreeze pf "
"JOIN PublishXRef px ON px.InbredSetId = pf.InbredSetId "
"JOIN PublishData pd ON pd.Id = px.DataId "
"JOIN Strain st ON pd.StrainId = st.Id "
"LEFT JOIN PublishSE ps ON ps.DataId = pd.Id "
"AND ps.StrainId = pd.StrainId "
"LEFT JOIN NStrain ns ON ns.DataId = pd.Id "
"AND ns.StrainId = pd.StrainId "
"LEFT JOIN CaseAttributeXRefNew cxref ON "
"(cxref.InbredSetId = px.InbredSetId AND "
"cxref.StrainId = st.Id) "
"LEFT JOIN CaseAttribute ca ON ca.Id = cxref.CaseAttributeId "
"WHERE px.Id = %s AND px.PhenotypeId = %s ORDER BY st.Name")
case_attr_columns = set()
csv_data = {}
with conn.cursor() as cursor:
cursor.execute(__query, (trait_name, phenotype_id))
for data in cursor.fetchall():
if data[1] == "x":
csv_data[data[0]] = None
else:
sample, case_attr, value = data[0], data[1], data[2]
if not csv_data.get(sample):
csv_data[sample] = {}
csv_data[sample][case_attr] = None if value == "x" else value
case_attr_columns.add(case_attr)
if not case_attr_columns:
return ("Strain Name,Value,SE,Count\n" +
"\n".join(csv_data.keys()))
else:
columns = sorted(case_attr_columns)
csv = ("Strain Name,Value,SE,Count," +
",".join(columns) + "\n")
for key, value in csv_data.items():
if not value:
csv += (key + (len(case_attr_columns) * ",x") + "\n")
else:
vals = [str(value.get(column, "x")) for column in columns]
csv += (key + "," + ",".join(vals) + "\n")
return csv
return "No Sample Data Found"
def update_sample_data(conn: Any, # pylint: disable=[R0913]
trait_name: str,
strain_name: str,
phenotype_id: int,
value: Union[int, float, str],
error: Union[int, float, str],
count: Union[int, str]):
"""Given the right parameters, update sample-data from the relevant
table."""
strain_id, data_id = "", ""
with conn.cursor() as cursor:
cursor.execute(
("SELECT Strain.Id, PublishData.Id FROM "
"(PublishData, Strain, PublishXRef, PublishFreeze) "
"LEFT JOIN PublishSE ON "
"(PublishSE.DataId = PublishData.Id AND "
"PublishSE.StrainId = PublishData.StrainId) "
"LEFT JOIN NStrain ON "
"(NStrain.DataId = PublishData.Id AND "
"NStrain.StrainId = PublishData.StrainId) "
"WHERE PublishXRef.InbredSetId = "
"PublishFreeze.InbredSetId AND "
"PublishData.Id = PublishXRef.DataId AND "
"PublishXRef.Id = %s AND "
"PublishXRef.PhenotypeId = %s "
"AND PublishData.StrainId = Strain.Id "
"AND Strain.Name = \"%s\"") % (trait_name,
phenotype_id,
str(strain_name)))
strain_id, data_id = cursor.fetchone()
updated_published_data: int = 0
updated_se_data: int = 0
updated_n_strains: int = 0
with conn.cursor() as cursor:
# Update the PublishData table
if value == "x":
cursor.execute(("DELETE FROM PublishData "
"WHERE StrainId = %s AND Id = %s")
% (strain_id, data_id))
updated_published_data = cursor.rowcount
else:
cursor.execute(("UPDATE PublishData SET value = %s "
"WHERE StrainId = %s AND Id = %s"),
(value, strain_id, data_id))
updated_published_data = cursor.rowcount
if not updated_published_data:
cursor.execute(
"SELECT * FROM "
"PublishData WHERE StrainId = "
"%s AND Id = %s" % (strain_id, data_id))
if not cursor.fetchone():
cursor.execute(("INSERT INTO PublishData (Id, StrainId, "
" value) VALUES (%s, %s, %s)") %
(data_id, strain_id, value))
updated_published_data = cursor.rowcount
# Update the PublishSE table
if error == "x":
cursor.execute(("DELETE FROM PublishSE "
"WHERE StrainId = %s AND DataId = %s") %
(strain_id, data_id))
updated_se_data = cursor.rowcount
else:
cursor.execute(("UPDATE PublishSE SET error = %s "
"WHERE StrainId = %s AND DataId = %s"),
(None if error == "x" else error,
strain_id, data_id))
updated_se_data = cursor.rowcount
if not updated_se_data:
cursor.execute(
"SELECT * FROM "
"PublishSE WHERE StrainId = "
"%s AND DataId = %s" % (strain_id, data_id))
if not cursor.fetchone():
cursor.execute(("INSERT INTO PublishSE (StrainId, DataId, "
" error) VALUES (%s, %s, %s)") %
(strain_id, data_id,
None if error == "x" else error))
updated_se_data = cursor.rowcount
# Update the NStrain table
if count == "x":
cursor.execute(("DELETE FROM NStrain "
"WHERE StrainId = %s AND DataId = %s" %
(strain_id, data_id)))
updated_n_strains = cursor.rowcount
else:
cursor.execute(("UPDATE NStrain SET count = %s "
"WHERE StrainId = %s AND DataId = %s"),
(count, strain_id, data_id))
updated_n_strains = cursor.rowcount
if not updated_n_strains:
cursor.execute(
"SELECT * FROM "
"NStrain WHERE StrainId = "
"%s AND DataId = %s" % (strain_id, data_id))
if not cursor.fetchone():
cursor.execute(("INSERT INTO NStrain "
"(StrainId, DataId, count) "
"VALUES (%s, %s, %s)") %
(strain_id, data_id, count))
updated_n_strains = cursor.rowcount
return (updated_published_data,
updated_se_data, updated_n_strains)
def delete_sample_data(conn: Any,
trait_name: str,
strain_name: str,
phenotype_id: int):
"""Given the right parameters, delete sample-data from the relevant
table."""
strain_id, data_id = "", ""
deleted_published_data: int = 0
deleted_se_data: int = 0
deleted_n_strains: int = 0
with conn.cursor() as cursor:
# Delete the PublishData table
try:
cursor.execute(
("SELECT Strain.Id, PublishData.Id FROM "
"(PublishData, Strain, PublishXRef, PublishFreeze) "
"LEFT JOIN PublishSE ON "
"(PublishSE.DataId = PublishData.Id AND "
"PublishSE.StrainId = PublishData.StrainId) "
"LEFT JOIN NStrain ON "
"(NStrain.DataId = PublishData.Id AND "
"NStrain.StrainId = PublishData.StrainId) "
"WHERE PublishXRef.InbredSetId = "
"PublishFreeze.InbredSetId AND "
"PublishData.Id = PublishXRef.DataId AND "
"PublishXRef.Id = %s AND "
"PublishXRef.PhenotypeId = %s "
"AND PublishData.StrainId = Strain.Id "
"AND Strain.Name = \"%s\"") % (trait_name,
phenotype_id,
str(strain_name)))
# Check if it exists if the data was already deleted:
if _result := cursor.fetchone():
strain_id, data_id = _result
# Only run if the strain_id and data_id exist
if strain_id and data_id:
cursor.execute(("DELETE FROM PublishData "
"WHERE StrainId = %s AND Id = %s")
% (strain_id, data_id))
deleted_published_data = cursor.rowcount
# Delete the PublishSE table
cursor.execute(("DELETE FROM PublishSE "
"WHERE StrainId = %s AND DataId = %s") %
(strain_id, data_id))
deleted_se_data = cursor.rowcount
# Delete the NStrain table
cursor.execute(("DELETE FROM NStrain "
"WHERE StrainId = %s AND DataId = %s" %
(strain_id, data_id)))
deleted_n_strains = cursor.rowcount
except Exception as e: #pylint: disable=[C0103, W0612]
conn.rollback()
raise MySQLdb.Error
conn.commit()
cursor.close()
cursor.close()
return (deleted_published_data,
deleted_se_data, deleted_n_strains)
def insert_sample_data(conn: Any, # pylint: disable=[R0913]
trait_name: str,
strain_name: str,
phenotype_id: int,
value: Union[int, float, str],
error: Union[int, float, str],
count: Union[int, str]):
"""Given the right parameters, insert sample-data to the relevant table.
"""
inserted_published_data, inserted_se_data, inserted_n_strains = 0, 0, 0
with conn.cursor() as cursor:
try:
cursor.execute("SELECT DataId FROM PublishXRef WHERE Id = %s AND "
"PhenotypeId = %s", (trait_name, phenotype_id))
data_id = cursor.fetchone()
cursor.execute("SELECT Id FROM Strain WHERE Name = %s",
(strain_name,))
strain_id = cursor.fetchone()
# Return early if an insert already exists!
cursor.execute("SELECT Id FROM PublishData where Id = %s "
"AND StrainId = %s",
(data_id, strain_id))
if cursor.fetchone(): # This strain already exists
return (0, 0, 0)
# Insert the PublishData table
cursor.execute(("INSERT INTO PublishData (Id, StrainId, value)"
"VALUES (%s, %s, %s)"),
(data_id, strain_id, value))
inserted_published_data = cursor.rowcount
# Insert into the PublishSE table if error is specified
if error and error != "x":
cursor.execute(("INSERT INTO PublishSE (StrainId, DataId, "
" error) VALUES (%s, %s, %s)") %
(strain_id, data_id, error))
inserted_se_data = cursor.rowcount
# Insert into the NStrain table
if count and count != "x":
cursor.execute(("INSERT INTO NStrain "
"(StrainId, DataId, count) "
"VALUES (%s, %s, %s)") %
(strain_id, data_id, count))
inserted_n_strains = cursor.rowcount
except Exception: # pylint: disable=[C0103, W0612]
conn.rollback()
raise MySQLdb.Error
return (inserted_published_data,
inserted_se_data, inserted_n_strains)
|