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
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
|
"""Database and utility functions for phenotypes."""
import logging
import tempfile
from pathlib import Path
from functools import reduce
from datetime import datetime
from typing import Optional, Iterable
import MySQLdb as mdb
from MySQLdb.cursors import Cursor, DictCursor
from gn_libs.mysqldb import debug_query
from functional_tools import take
logger = logging.getLogger(__name__)
__PHENO_DATA_TABLES__ = {
"PublishData": {
"table": "PublishData", "valueCol": "value", "DataIdCol": "Id"},
"PublishSE": {
"table": "PublishSE", "valueCol": "error", "DataIdCol": "DataId"},
"NStrain": {
"table": "NStrain", "valueCol": "count", "DataIdCol": "DataId"}
}
def datasets_by_population(
conn: mdb.Connection,
species_id: int,
population_id: int
) -> tuple[dict, ...]:
"""Retrieve all of a population's phenotype studies."""
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(
"SELECT s.SpeciesId, pf.* FROM Species AS s "
"INNER JOIN InbredSet AS iset ON s.Id=iset.SpeciesId "
"INNER JOIN PublishFreeze AS pf ON iset.Id=pf.InbredSetId "
"WHERE s.Id=%s AND iset.Id=%s;",
(species_id, population_id))
return tuple(dict(row) for row in cursor.fetchall())
def dataset_by_id(conn: mdb.Connection,
species_id: int,
population_id: int,
dataset_id: int) -> dict:
"""Fetch dataset details by identifier"""
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(
"SELECT Species.SpeciesId, PublishFreeze.* FROM Species "
"INNER JOIN InbredSet ON Species.Id=InbredSet.SpeciesId "
"INNER JOIN PublishFreeze ON InbredSet.Id=PublishFreeze.InbredSetId "
"WHERE Species.Id=%s AND InbredSet.Id=%s AND PublishFreeze.Id=%s",
(species_id, population_id, dataset_id))
return dict(cursor.fetchone())
def phenotypes_count(conn: mdb.Connection,
population_id: int,
dataset_id: int) -> int:
"""Count the number of phenotypes in the dataset."""
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(
"SELECT COUNT(*) AS total_phenos FROM Phenotype AS pheno "
"INNER JOIN PublishXRef AS pxr ON pheno.Id=pxr.PhenotypeId "
"INNER JOIN PublishFreeze AS pf ON pxr.InbredSetId=pf.InbredSetId "
"WHERE pxr.InbredSetId=%s AND pf.Id=%s",
(population_id, dataset_id))
return int(cursor.fetchone()["total_phenos"])
def phenotype_publication_data(conn, phenotype_id) -> Optional[dict]:
"""Retrieve the publication data for a phenotype if it exists."""
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(
"SELECT DISTINCT pxr.PhenotypeId, pub.* FROM PublishXRef AS pxr "
"INNER JOIN Publication as pub ON pxr.PublicationId=pub.Id "
"WHERE pxr.PhenotypeId=%s",
(phenotype_id,))
res = cursor.fetchone()
if res is None:
return res
return dict(res)
def dataset_phenotypes(conn: mdb.Connection,
population_id: int,
dataset_id: int,
offset: int = 0,
limit: Optional[int] = None) -> tuple[dict, ...]:
"""Fetch the actual phenotypes."""
_query = (
"SELECT pheno.*, pxr.Id AS xref_id, pxr.InbredSetId, ist.InbredSetCode "
"FROM Phenotype AS pheno "
"INNER JOIN PublishXRef AS pxr ON pheno.Id=pxr.PhenotypeId "
"INNER JOIN PublishFreeze AS pf ON pxr.InbredSetId=pf.InbredSetId "
"INNER JOIN InbredSet AS ist ON pf.InbredSetId=ist.Id "
"WHERE pxr.InbredSetId=%s AND pf.Id=%s") + (
f" LIMIT {limit} OFFSET {offset}" if bool(limit) else "")
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(_query, (population_id, dataset_id))
debug_query(cursor, logger)
return tuple(dict(row) for row in cursor.fetchall())
def __phenotype_se__(cursor: Cursor, xref_id, dataids_and_strainids):
"""Fetch standard-error values (if they exist) for a phenotype."""
paramstr = ", ".join(["(%s, %s)"] * len(dataids_and_strainids))
flat = tuple(item for sublist in dataids_and_strainids for item in sublist)
cursor.execute("SELECT * FROM PublishSE WHERE (DataId, StrainId) IN "
f"({paramstr})",
flat)
debug_query(cursor, logger)
_se = {
(row["DataId"], row["StrainId"]): {
"DataId": row["DataId"],
"StrainId": row["StrainId"],
"error": row["error"]
}
for row in cursor.fetchall()
}
cursor.execute("SELECT * FROM NStrain WHERE (DataId, StrainId) IN "
f"({paramstr})",
flat)
debug_query(cursor, logger)
_n = {
(row["DataId"], row["StrainId"]): {
"DataId": row["DataId"],
"StrainId": row["StrainId"],
"count": row["count"]
}
for row in cursor.fetchall()
}
keys = set(tuple(_se.keys()) + tuple(_n.keys()))
return {
key: {"xref_id": xref_id, **_se.get(key,{}), **_n.get(key,{})}
for key in keys
}
def __organise_by_phenotype__(pheno, row):
"""Organise disparate data rows into phenotype 'objects'."""
_pheno = pheno.get(row["Id"])
return {
**pheno,
row["Id"]: {
"Id": row["Id"],
"Pre_publication_description": row["Pre_publication_description"],
"Post_publication_description": row["Post_publication_description"],
"Original_description": row["Original_description"],
"Units": row["Units"],
"Pre_publication_abbreviation": row["Pre_publication_abbreviation"],
"Post_publication_abbreviation": row["Post_publication_abbreviation"],
"xref_id": row["pxr.Id"],
"DataId": row["DataId"],
"data": {
**(_pheno["data"] if bool(_pheno) else {}),
(row["DataId"], row["StrainId"]): {
"DataId": row["DataId"],
"StrainId": row["StrainId"],
"mean": row["mean"],
"Locus": row["Locus"],
"LRS": row["LRS"],
"additive": row["additive"],
"Sequence": row["Sequence"],
"comments": row["comments"],
"value": row["value"],
"StrainName": row["Name"],
"StrainName2": row["Name2"],
"StrainSymbol": row["Symbol"],
"StrainAlias": row["Alias"]
}
}
}
}
def __merge_pheno_data_and_se__(data, sedata) -> dict:
"""Merge phenotype data with the standard errors."""
return {
key: {**value, **sedata.get(key, {})}
for key, value in data.items()
}
def phenotype_by_id(
conn: mdb.Connection,
species_id: int,
population_id: int,
dataset_id: int,
xref_id
) -> Optional[dict]:
"""Fetch a specific phenotype."""
_dataquery = ("SELECT pheno.*, pxr.*, pd.*, str.*, iset.InbredSetCode "
"FROM Phenotype AS pheno "
"INNER JOIN PublishXRef AS pxr ON pheno.Id=pxr.PhenotypeId "
"INNER JOIN PublishData AS pd ON pxr.DataId=pd.Id "
"INNER JOIN Strain AS str ON pd.StrainId=str.Id "
"INNER JOIN StrainXRef AS sxr ON str.Id=sxr.StrainId "
"INNER JOIN PublishFreeze AS pf ON sxr.InbredSetId=pf.InbredSetId "
"INNER JOIN InbredSet AS iset ON pf.InbredSetId=iset.InbredSetId "
"WHERE "
"(str.SpeciesId, pxr.InbredSetId, pf.Id, pxr.Id)=(%s, %s, %s, %s)")
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(_dataquery,
(species_id, population_id, dataset_id, xref_id))
_pheno: dict = reduce(__organise_by_phenotype__, cursor.fetchall(), {})
if bool(_pheno) and len(_pheno.keys()) == 1:
_pheno = tuple(_pheno.values())[0]
return {
**_pheno,
"data": tuple(__merge_pheno_data_and_se__(
_pheno["data"],
__phenotype_se__(
cursor, xref_id, tuple(_pheno["data"].keys()))
).values())
}
if bool(_pheno) and len(_pheno.keys()) > 1:
raise Exception(# pylint: disable=[broad-exception-raised]
"We found more than one phenotype with the same identifier!")
return None
def phenotypes_data(conn: mdb.Connection,
population_id: int,
dataset_id: int,
offset: int = 0,
limit: Optional[int] = None) -> tuple[dict, ...]:
"""Fetch the data for the phenotypes."""
# — Phenotype -> PublishXRef -> PublishData -> Strain -> StrainXRef -> PublishFreeze
_query = ("SELECT pheno.*, pxr.*, pd.*, str.*, iset.InbredSetCode "
"FROM Phenotype AS pheno "
"INNER JOIN PublishXRef AS pxr ON pheno.Id=pxr.PhenotypeId "
"INNER JOIN PublishData AS pd ON pxr.DataId=pd.Id "
"INNER JOIN Strain AS str ON pd.StrainId=str.Id "
"INNER JOIN StrainXRef AS sxr ON str.Id=sxr.StrainId "
"INNER JOIN PublishFreeze AS pf ON sxr.InbredSetId=pf.InbredSetId "
"INNER JOIN InbredSet AS iset ON pf.InbredSetId=iset.InbredSetId "
"WHERE pxr.InbredSetId=%s AND pf.Id=%s") + (
f" LIMIT {limit} OFFSET {offset}" if bool(limit) else "")
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(_query, (population_id, dataset_id))
debug_query(cursor, logger)
return tuple(dict(row) for row in cursor.fetchall())
def save_new_dataset(cursor: Cursor,
population_id: int,
dataset_name: str,
dataset_fullname: str,
dataset_shortname: str) -> dict:
"""Create a new phenotype dataset."""
params = {
"population_id": population_id,
"dataset_name": dataset_name,
"dataset_fullname": dataset_fullname,
"dataset_shortname": dataset_shortname,
"created": datetime.now().date().isoformat(),
"public": 2,
"confidentiality": 0,
"users": None
}
cursor.execute(
"INSERT INTO PublishFreeze(Name, FullName, ShortName, CreateTime, "
"public, InbredSetId, confidentiality, AuthorisedUsers) "
"VALUES(%(dataset_name)s, %(dataset_fullname)s, %(dataset_shortname)s, "
"%(created)s, %(public)s, %(population_id)s, %(confidentiality)s, "
"%(users)s)",
params)
debug_query(cursor, logger)
return {**params, "Id": cursor.lastrowid}
def phenotypes_data_by_ids(
conn: mdb.Connection,
inbred_pheno_xref: dict[str, int]
) -> tuple[dict, ...]:
"""Fetch all phenotype data, filtered by the `inbred_pheno_xref` mapping."""
_paramstr = ",".join(["(%s, %s, %s)"] * len(inbred_pheno_xref))
_query = ("SELECT "
"pub.PubMed_ID, pheno.*, pxr.*, pd.*, str.*, iset.InbredSetCode "
"FROM Publication AS pub "
"RIGHT JOIN PublishXRef AS pxr0 ON pub.Id=pxr0.PublicationId "
"INNER JOIN Phenotype AS pheno ON pxr0.PhenotypeId=pheno.id "
"INNER JOIN PublishXRef AS pxr ON pheno.Id=pxr.PhenotypeId "
"INNER JOIN PublishData AS pd ON pxr.DataId=pd.Id "
"INNER JOIN Strain AS str ON pd.StrainId=str.Id "
"INNER JOIN StrainXRef AS sxr ON str.Id=sxr.StrainId "
"INNER JOIN PublishFreeze AS pf ON sxr.InbredSetId=pf.InbredSetId "
"INNER JOIN InbredSet AS iset ON pf.InbredSetId=iset.InbredSetId "
f"WHERE (pxr.InbredSetId, pheno.Id, pxr.Id) IN ({_paramstr}) "
"ORDER BY pheno.Id")
with conn.cursor(cursorclass=DictCursor) as cursor:
cursor.execute(_query, tuple(item for row in inbred_pheno_xref
for item in (row["population_id"],
row["phenoid"],
row["xref_id"])))
debug_query(cursor, logger)
return tuple(
reduce(__organise_by_phenotype__, cursor.fetchall(), {}).values())
def __pre_process_phenotype_data__(row):
_desc = row.get("description", "")
_pre_pub_desc = row.get("pre_publication_description", _desc)
_orig_desc = row.get("original_description", _desc)
_post_pub_desc = row.get("post_publication_description", _orig_desc)
_pre_pub_abbr = row.get("pre_publication_abbreviation", row["id"])
_post_pub_abbr = row.get("post_publication_abbreviation", _pre_pub_abbr)
return {
"pre_publication_description": _pre_pub_desc,
"post_publication_description": _post_pub_desc,
"original_description": _orig_desc,
"units": row["units"],
"pre_publication_abbreviation": _pre_pub_abbr,
"post_publication_abbreviation": _post_pub_abbr
}
def create_new_phenotypes(conn: mdb.Connection,
population_id: int,
publication_id: int,
phenotypes: Iterable[dict]) -> tuple[dict, ...]:
"""Add entirely new phenotypes to the database. WARNING: Not thread-safe."""
_phenos = tuple()
with conn.cursor(cursorclass=DictCursor) as cursor:
def make_next_id(idcol, table):
cursor.execute(f"SELECT MAX({idcol}) AS last_id FROM {table}")
_last_id = int(cursor.fetchone()["last_id"])
def __next_id__():
_next_id = _last_id + 1
while True:
yield _next_id
_next_id = _next_id + 1
return __next_id__
### Bottleneck: Everything below makes this function not ###
### thread-safe because we have to retrieve the last IDs from ###
### the database and increment those to compute the next IDs. ###
### This is an unfortunate result from the current schema that ###
### has a cross-reference table that requires that a phenotype ###
### be linked to an existing publication, and have data IDs to ###
### link to that phenotype's data. ###
### The fact that the IDs are sequential also compounds the ###
### bottleneck. ###
###
### For extra safety, ensure the following tables are locked ###
### for `WRITE`: ###
### - PublishXRef ###
### - Phenotype ###
### - PublishXRef ###
__next_xref_id = make_next_id("Id", "PublishXRef")()
__next_pheno_id__ = make_next_id("Id", "Phenotype")()
__next_data_id__ = make_next_id("DataId", "PublishXRef")()
def __build_params_and_prepubabbrevs__(acc, row):
processed = __pre_process_phenotype_data__(row)
return (
acc[0] + ({
**processed,
"population_id": population_id,
"publication_id": publication_id,
"phenotype_id": next(__next_pheno_id__),
"xref_id": next(__next_xref_id),
"data_id": next(__next_data_id__)
},),
acc[1] + (processed["pre_publication_abbreviation"],))
while True:
batch = take(phenotypes, 1000)
if len(batch) == 0:
break
params, abbrevs = reduce(__build_params_and_prepubabbrevs__,
batch,
(tuple(), tuple()))
# Check for uniqueness for all "Pre_publication_description" values
abbrevs_paramsstr = ", ".join(["%s"] * len(abbrevs))
_query = ("SELECT PublishXRef.PhenotypeId, Phenotype.* "
"FROM PublishXRef "
"INNER JOIN Phenotype "
"ON PublishXRef.PhenotypeId=Phenotype.Id "
"WHERE PublishXRef.InbredSetId=%s "
"AND Phenotype.Pre_publication_abbreviation IN "
f"({abbrevs_paramsstr})")
cursor.execute(_query,
((population_id,) + abbrevs))
existing = tuple(row["Pre_publication_abbreviation"]
for row in cursor.fetchall())
if len(existing) > 0:
# Narrow this exception, perhaps?
raise Exception(
"Found already existing phenotypes with the following "
"'Pre-publication abbreviations':\n\t"
"\n\t".join(f"* {item}" for item in existing))
cursor.executemany(
(
"INSERT INTO "
"Phenotype("
"Id, "
"Pre_publication_description, "
"Post_publication_description, "
"Original_description, "
"Units, "
"Pre_publication_abbreviation, "
"Post_publication_abbreviation, "
"Authorized_Users"
")"
"VALUES ("
"%(phenotype_id)s, "
"%(pre_publication_description)s, "
"%(post_publication_description)s, "
"%(original_description)s, "
"%(units)s, "
"%(pre_publication_abbreviation)s, "
"%(post_publication_abbreviation)s, "
"'robwilliams'"
")"),
params)
_comments = f"Created at {datetime.now().isoformat()}"
cursor.executemany(
("INSERT INTO PublishXRef("
"Id, "
"InbredSetId, "
"PhenotypeId, "
"PublicationId, "
"DataId, "
"comments"
")"
"VALUES("
"%(xref_id)s, "
"%(population_id)s, "
"%(phenotype_id)s, "
"%(publication_id)s, "
"%(data_id)s, "
f"'{_comments}'"
")"),
params)
_phenos = _phenos + params
return _phenos
def save_phenotypes_data(
conn: mdb.Connection,
table: str,
data: Iterable[dict]
) -> int:
"""Save new phenotypes data into the database."""
_table_details = __PHENO_DATA_TABLES__[table]
with conn.cursor(cursorclass=DictCursor) as cursor:
_count = 0
while True:
batch = take(data, 100000)
if len(batch) == 0:
logger.warning("Got an empty batch. This needs investigation.")
break
logger.debug("Saving batch of %s items.", len(batch))
cursor.executemany(
(f"INSERT INTO {_table_details['table']}"
f"({_table_details['DataIdCol']}, StrainId, {_table_details['valueCol']}) "
"VALUES "
f"(%(data_id)s, %(sample_id)s, %(value)s) "),
tuple(batch))
debug_query(cursor, logger)
_count = _count + len(batch)
logger.debug("Saved a total of %s data rows", _count)
return _count
def quick_save_phenotypes_data(
conn: mdb.Connection,
table: str,
dataitems: Iterable[dict],
tmpdir: Path
) -> int:
"""Save data items to the database, but using """
_table_details = __PHENO_DATA_TABLES__[table]
with (tempfile.NamedTemporaryFile(
prefix=f"{table}_data", mode="wt", dir=tmpdir) as tmpfile,
conn.cursor(cursorclass=DictCursor) as cursor):
_count = 0
logger.debug("Write data rows to text file.")
for row in dataitems:
tmpfile.write(
f'{row["data_id"]}\t{row["sample_id"]}\t{row["value"]}\n')
_count = _count + 1
tmpfile.flush()
logger.debug("Load text file into database (table: %s)",
_table_details["table"])
cursor.execute(
f"LOAD DATA LOCAL INFILE '{tmpfile.name}' "
f"INTO TABLE {_table_details['table']} "
"("
f"{_table_details['DataIdCol']}, "
"StrainId, "
f"{_table_details['valueCol']}"
")")
debug_query(cursor, logger)
return _count
|