-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathdatabase.py
821 lines (708 loc) · 22.9 KB
/
database.py
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
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
import pandas as pd
import sqlite3
from functools import reduce
import json
def create_tables(db_file):
conn = sqlite3.connect(db_file)
conn.execute("""
CREATE TABLE "tblGBRefs" (
"RefID" INTEGER PRIMARY KEY,
"Authors" TEXT,
"FirstAuthorSurname" TEXT,
"Title" TEXT,
"Journal" TEXT,
"PMID" TEXT,
"Year" TEXT,
"ShortName" TEXT
)
""")
conn.execute("""
CREATE TABLE "tblIsolates" (
"Accession" TEXT PRIMARY KEY,
"Country" TEXT,
"RecordYear" INTEGER,
"IsolateYear" INTEGER,
"Host" TEXT,
"Specimen" TEXT,
"IsolateName" TEXT,
"SeqLength" INTEGER,
"IsolateType" TEXT
)
""")
conn.execute("""
CREATE TABLE "tblGBRefLink" (
"RefID" INTEGER,
"Accession" TEXT,
FOREIGN KEY (RefID) REFERENCES tblGBRefs (RefID),
FOREIGN KEY (Accession) REFERENCES tblIsolates (Accession)
)
""")
conn.execute("""
CREATE TABLE "tblSequences" (
"SeqID" INTEGER PRIMARY KEY,
"Accession" TEXT,
"Gene" TEXT,
"CDS_NAME" TEXT,
"AA_seq" TEXT,
"AA_length" INTEGER,
"AA_start" INTEGER,
"AA_stop" INTEGER,
"NA_Seq" TEXT,
"NA_length" INTEGER,
"NA_start" INTEGER,
"NA_stop" INTEGER,
"PcntMatch" REAL,
"HSPLength" INTEGER,
FOREIGN KEY (Accession) REFERENCES tblSequences (Accession)
)
""")
conn.execute("""
CREATE TABLE "tblIndels" (
"SeqID" INTEGER,
"AA_num_ins" INTEGER,
"AA_num_del" INTEGER,
"AA_blast_failed" INTEGER,
"NA_num_ins" INTEGER,
"NA_num_del" INTEGER,
"NA_blast_failed" INTEGER,
"num_N" INTEGER,
"translation_issue" INTEGER,
FOREIGN KEY (SeqID) REFERENCES tblSequences (SeqID)
)
""")
conn.execute("""
CREATE TABLE "tblPublications" (
"PubID" INTEGER PRIMARY KEY,
"Authors" TEXT,
"FirstAuthorSurname" TEXT,
"Title" TEXT,
"Journal" TEXT,
"PMID" TEXT,
"Year" TEXT,
"ShortName" TEXT,
"ref_source" TEXT
)
""")
conn.execute("""
CREATE TABLE "tblPublicationData" (
"PubID" INTEGER,
"Viruses" TEXT,
"NumSeqs" TEXT,
"Host" TEXT,
"SampleYr" TEXT,
"Country" TEXT,
"GenBank" TEXT,
"SeqMethod" TEXT,
"CloneMethod" TEXT,
"IsolateType" TEXT,
"Gene" TEXT,
FOREIGN KEY (PubID) REFERENCES tblPublications (PubID)
)
""")
conn.execute("""
CREATE TABLE "tblGBPubRefLink" (
"PubID" INTEGER,
"RefID" TEXT,
FOREIGN KEY (PubID) REFERENCES tblPublications (PubID),
FOREIGN KEY (RefID) REFERENCES tblGBRefs (RefID)
)
""")
conn.close()
def create_database(virus_obj, references, features, genes, pubmed,
pubmed_genbank):
virus_obj.DB_FILE.unlink(missing_ok=True)
create_tables(virus_obj.DB_FILE)
# GenBank Tables
tblGBRefs = references[[
'RefID',
'Authors',
'FirstAuthorSurname',
'Title',
'Journal',
'PMID',
'Year',
'ShortName',
]]
fill_in_table(virus_obj.DB_FILE, 'tblGBRefs', tblGBRefs)
create_ref_link(virus_obj, references)
features['Specimen'] = features['isolate_source']
features['Virus'] = features['organism']
if 'IsolateType' not in features.columns:
features['IsolateType'] = ""
tblIsolates = features[[
'Accession', 'Country', 'RecordYear', 'IsolateYear', 'Host',
'Specimen', 'IsolateName', 'SeqLength', 'IsolateType'
]]
for i, row in tblIsolates.iterrows():
tblIsolates.at[i, 'Host'] = row['Host'] if row['Host'] else (
'Not applicable' if row['IsolateType'] else 'Not available')
tblIsolates.at[i,
'Specimen'] = row['Specimen'] if row['Specimen'] else (
'Not applicable'
if row['IsolateType'] else 'Not available')
tblIsolates.at[
i, 'IsolateYear'] = row['IsolateYear'] if row['IsolateYear'] else (
'Not applicable' if row['IsolateType'] else 'Not available')
tblIsolates.at[i, 'Country'] = row['Country'] if row['Country'] else (
'Not applicable' if row['IsolateType'] else 'Not available')
fill_in_table(virus_obj.DB_FILE, 'tblIsolates', tblIsolates)
genes['PcntMatch'] = genes['pcnt_id']
tblGBSequences = genes[[
'Accession',
'Gene',
'CDS_NAME',
'AA_seq',
'AA_length',
'AA_start',
'AA_stop',
'NA_seq',
'NA_length',
'NA_start',
'NA_stop',
'PcntMatch',
]]
fill_in_table(virus_obj.DB_FILE, 'tblSequences', tblGBSequences)
tblIndels = genes[(genes['AA_num_ins'] != 0) | (genes['AA_num_del'] != 0) |
(genes['AA_blast_failed'] == 1) |
(genes['NA_num_ins'] != 0) | (genes['NA_num_del'] != 0) |
(genes['NA_blast_failed'] == 1) | (genes['num_N'] != 0) |
(genes['translation_issue'] != 0)]
tblIndels = tblIndels[[
'SeqID', 'AA_num_ins', 'AA_num_del', 'AA_blast_failed', 'NA_num_ins',
'NA_num_del', 'NA_blast_failed', 'num_N', 'translation_issue'
]]
fill_in_table(virus_obj.DB_FILE, 'tblIndels', tblIndels)
# PubMed Tables
tblPublications = pubmed[[
'PubID',
'Authors',
'FirstAuthorSurname',
'Title',
'Journal',
'PMID',
'Year',
'ShortName',
'ref_source'
]]
fill_in_table(virus_obj.DB_FILE, 'tblPublications', tblPublications)
tblPublicationData = pubmed[[
'PubID', 'Viruses', 'NumSeqs', 'Host', 'SampleYr', 'Country',
'GenBank', 'SeqMethod', 'CloneMethod', 'IsolateType', 'Gene'
]]
fill_in_table(virus_obj.DB_FILE, 'tblPublicationData', tblPublicationData)
tblPubRefLink = []
for pubmed, genbank_list, method in pubmed_genbank:
for g in genbank_list:
tblPubRefLink.append((pubmed['PubID'], g['RefID']))
tblPubRefLink = list(set(tblPubRefLink))
tblPubRefLink = [{'PubID': i, 'RefID': j} for i, j in tblPubRefLink]
fill_in_table(virus_obj.DB_FILE, 'tblGBPubRefLink',
pd.DataFrame(tblPubRefLink))
creat_views(virus_obj.DB_FILE)
dump_db_tables(virus_obj.DB_FILE, virus_obj.db_dump_folder)
# get_table_schema_sql(virus_obj.DB_FILE)
def create_ref_link(virus_obj, ref):
ref_link = []
for i, row in ref.iterrows():
accessions = row['accession']
accessions = [i.strip() for i in accessions.split(',') if i.strip()]
for acc in accessions:
ref_link.append({'RefID': row['RefID'], 'Accession': acc})
fill_in_table(virus_obj.DB_FILE, 'tblGBRefLink', pd.DataFrame(ref_link))
def creat_views(db_file):
vGBRefIsolates = """
CREATE VIEW vGBRefIsolates AS
SELECT a.*, c.*
FROM tblGBRefs a, tblGBRefLink b, tblIsolates c
WHERE a.RefID = b.RefID
AND b.Accession = c.Accession;
"""
run_create_view(db_file, vGBRefIsolates)
vNonClinicalIsolate = """
CREATE VIEW vNonClinicalIsolate AS
SELECT
*
FROM
tblIsolates
WHERE
IsolateType IS NOT ""
;
"""
run_create_view(db_file, vNonClinicalIsolate)
vSubmissionPub = """
CREATE VIEW vSubmissionPub AS
SELECT
a.*, c.*
FROM
tblGBRefs a,
tblGBPubRefLink b,
tblPublications c
WHERE
a.RefID = b.RefID
AND b.PubID = c.PubID;
"""
run_create_view(db_file, vSubmissionPub)
vGPMatched = """
CREATE VIEW vGPMatched AS
WITH temp_isolate AS (
SELECT
iso.*,
seq.Gene
FROM
tblIsolates iso,
tblSequences seq
WHERE
iso.Accession = seq.Accession
GROUP BY
iso.Accession, seq.Gene
),
temp_num_isolate AS (
SELECT
a.*,
COUNT(DISTINCT c.ACCESSION) AS num_Isolate,
'https://www.ncbi.nlm.nih.gov/nuccore?cmd=Search&doptcmdl=Summary&term=' || GROUP_CONCAT('"' || c.ACCESSION || '"%5BACCN%5D', "%20OR%20") AS gb_search
FROM
tblGBRefs a,
tblGBRefLink b,
temp_isolate c
WHERE
a.RefID = b.RefID
AND b.Accession = c.Accession
GROUP BY
a.RefID
),
temp_num_gene AS (
SELECT
a.*,
c.Gene,
COUNT(c.Gene) AS num_Gene
FROM
tblGBRefs a,
tblGBRefLink b,
temp_isolate c
WHERE
a.RefID = b.RefID
AND b.Accession = c.Accession
GROUP BY
a.RefID, c.Gene
ORDER BY
c.Gene
),
temp_num_gene_str AS (
SELECT
a.*,
GROUP_CONCAT(a.Gene || ' (' || a.num_Gene || ')', ', ') AS Genes
FROM
temp_num_gene a
GROUP BY
a.RefID
),
temp_GBRef AS (
SELECT
a.*,
b.num_Isolate,
b.gb_search,
c.Genes
FROM
tblGBRefs a
LEFT JOIN temp_num_isolate b ON a.RefID = b.RefID
LEFT JOIN temp_num_gene_str c ON a.RefID = c.RefID
)
SELECT
a.RefID as RefID,
a.ShortName || ". " || a.Title || "; " || a.Authors || "; " || a.Journal || "; ["|| a.Genes || "](" || a.gb_search || ")"
AS SubmissionSet,
c.PubID as PubID,
c.ShortName || ". " || c.Title || "; " || c.Authors || "; " || c.Journal AS Publication,
CASE
WHEN c.ShortName IS NOT NULL THEN c.ShortName
ELSE a.ShortName
END as ShortName
FROM
temp_GBRef a,
tblGBPubRefLink b,
tblPublications c
WHERE
a.RefID = b.RefID
AND b.PubID = c.PubID
AND LOWER(a.Title) NOT LIKE '%patent%'
AND LOWER(a.Title) NOT LIKE '%direct submission%'
AND LOWER(a.Title) NOT LIKE '%construct%'
AND LOWER(a.Journal) NOT LIKE '%patent%'
AND LOWER(a.Journal) NOT LIKE '%direct submission%'
AND LOWER(a.Journal) NOT LIKE '%construct%'
UNION
SELECT
a.RefID as RefID,
a.ShortName || ". " || a.Title || "; " || a.Authors || "; " || a.Journal || "; ["|| a.Genes || "](" || a.gb_search || ")"
AS SubmissionSet,
'' as PubID,
'' AS Publication,
a.ShortName as ShortName
FROM
temp_GBRef a
WHERE
a.RefID NOT IN (SELECT RefID FROM tblGBPubRefLink)
AND LOWER(a.Title) NOT LIKE '%patent%'
AND LOWER(a.Title) NOT LIKE '%direct submission%'
AND LOWER(a.Title) NOT LIKE '%construct%'
AND LOWER(a.Journal) NOT LIKE '%patent%'
AND LOWER(a.Journal) NOT LIKE '%direct submission%'
AND LOWER(a.Journal) NOT LIKE '%construct%'
UNION
SELECT
'' as RefID,
'' AS SubmissionSet,
c.PubID as PubID,
c.ShortName || ". " || c.Title || "; " || c.Authors || "; " || c.Journal AS Publication,
c.ShortName as ShortName
FROM
tblPublications c
WHERE
c.PubID NOT IN (SELECT PubID FROM tblGBPubRefLink)
;
"""
run_create_view(db_file, vGPMatched)
vAccessionPub = """
CREATE VIEW vAccessionPub AS
SELECT
d.*,
a.*
FROM
tblIsolates a,
tblGBRefLink b,
tblGBPubRefLink c,
tblPublications d
WHERE
a.Accession = b.Accession
AND
b.RefID = c.RefID
AND
c.PubID = d.PubID
;
"""
run_create_view(db_file, vAccessionPub)
vAccessionPubData = """
CREATE VIEW vAccessionPubData AS
SELECT
d.*,
a.*
FROM
tblIsolates a,
tblGBRefLink b,
tblGBPubRefLink c,
(SELECT * FROM tblPublications i LEFT JOIN tblPublicationData j ON i.PubID = j.PubID) d
WHERE
a.Accession = b.Accession
AND
b.RefID = c.RefID
AND
c.PubID = d.PubID
;
"""
run_create_view(db_file, vAccessionPubData)
# vNumAccessions = """
# CREATE VIEW vNumAccessions AS
# SELECT
# COUNT(DISTINCT Accession) AS NumAccessions
# FROM
# tblIsolates;
# """
# run_create_view(db_file, vNumAccessions)
# vNumSubmissionSets = """
# CREATE VIEW vNumSubmissionSets AS
# SELECT
# COUNT(DISTINCT RefID) AS NumSubmissionSets
# FROM
# tblGBRefs;
# """
# run_create_view(db_file, vNumSubmissionSets)
vIsolateMissingData = """
CREATE VIEW vIsolateMissingData AS
SELECT
*
FROM tblIsolates
WHERE
IsolateType IS ""
AND
(
Host IN
("Not Applicable", "Not Available", "Not available", "Not applicable")
OR
Country IN
("Not Applicable", "Not Available", "Not available", "Not applicable")
OR
IsolateYear IN
("Not Applicable", "Not Available", "Not available", "Not applicable")
);
"""
# OR
# Specimen IN
# ("Not Applicable", "Not Available", "Not available", "Not applicable")
run_create_view(db_file, vIsolateMissingData)
vSubmissionNotMatch = """
CREATE VIEW vSubmissionNotMatch AS
SELECT
*
FROM
tblGBRefs
WHERE
RefID NOT IN (
SELECT RefID from tblGBPubRefLink
)
"""
run_create_view(db_file, vSubmissionNotMatch)
vPubNotMatch = """
CREATE VIEW vPubNotMatch AS
SELECT
*
FROM
tblGBRefs
WHERE
RefID NOT IN (
SELECT RefID from tblGBPubRefLink
)
"""
run_create_view(db_file, vPubNotMatch)
# vNumMatchedSubmission = """
# CREATE VIEW vNumMatchedSubmission AS
# SELECT
# (SELECT COUNT(DISTINCT RefID) FROM tblGBPubRefLink) as num_submission_set,
# (SELECT COUNT(DISTINCT PubID) FROM tblGBPubRefLink) as num_publication,
# (SELECT COUNT(DISTINCT RefID) FROM tblGBRefs WHERE
# RefID NOT IN (SELECT DISTINCT RefID FROM tblGBPubRefLink)
# ) as num_submission_not_match
# ;
# """
# run_create_view(db_file, vNumMatchedSubmission)
vNumSuppliedIsolateDataByPubMed = """
CREATE VIEW vNumSuppliedIsolateDataByPubMed AS
SELECT
COUNT(
DISTINCT
CASE WHEN tblIsolates.Host LIKE '%*%'
THEN tblGBRefLink.RefID
END) AS submission_host,
COUNT(
DISTINCT
CASE WHEN tblIsolates.Host LIKE '%*%'
THEN tblIsolates.Accession
END) AS isolate_host,
COUNT(
DISTINCT
CASE WHEN tblIsolates.Specimen LIKE '%*%'
THEN tblGBRefLink.RefID
END) AS submission_specimen,
COUNT(
DISTINCT
CASE WHEN tblIsolates.Specimen LIKE '%*%'
THEN tblIsolates.Accession
END) AS isolate_specimen,
COUNT(
DISTINCT
CASE WHEN tblIsolates.Country LIKE '%*%'
THEN tblGBRefLink.RefID
END) AS submission_country,
COUNT(
DISTINCT
CASE WHEN tblIsolates.Country LIKE '%*%'
THEN tblIsolates.Accession
END) AS isolate_country,
COUNT(
DISTINCT CASE WHEN tblIsolates.IsolateYear LIKE '%*%'
THEN tblGBRefLink.RefID
END) AS submission_IsolateYear,
COUNT(
DISTINCT CASE WHEN tblIsolates.IsolateYear LIKE '%*%'
THEN tblIsolates.Accession
END) AS isolate_IsolateYear
FROM
tblGBRefLink
JOIN
tblIsolates ON tblGBRefLink.Accession = tblIsolates.Accession
;
"""
run_create_view(db_file, vNumSuppliedIsolateDataByPubMed)
vIsolateOrig = """
CREATE VIEW vIsolateOrig AS
SELECT
Accession,
CASE
WHEN IsolateYear LIKE '%*' THEN 'Not Available'
ELSE IsolateYear
END AS IsolateYear,
CASE
WHEN Host LIKE '%*' THEN 'Not Available'
ELSE Host
END AS Host,
CASE
WHEN Specimen LIKE '%*' THEN 'Not Available'
ELSE Specimen
END AS Specimen,
CASE
WHEN Country LIKE '%*' THEN 'Not Available'
ELSE Country
END AS Country,
IsolateType
FROM tblIsolates;
"""
run_create_view(db_file, vIsolateOrig)
vIsolateMetadataSummary = """
CREATE VIEW vIsolateMetadataSummary AS
WITH temp_selection AS (
SELECT *
FROM
vIsolateOrig
JOIN tblSequences ON vIsolateOrig.Accession = tblSequences.Accession
JOIN tblGBRefLink ON vIsolateOrig.Accession = tblGBRefLink.Accession
JOIN vGPMatched ON tblGBRefLink.RefID = vGPMatched.RefID
WHERE
IsolateType == ''
)
SELECT DISTINCT
Host,
Country,
IsolateYear,
CASE
WHEN IsolateYear BETWEEN 1900 AND 1990 THEN '<1990'
WHEN IsolateYear BETWEEN 1991 AND 2000 THEN '1991-2000'
WHEN IsolateYear BETWEEN 2001 AND 2010 THEN '2001-2010'
WHEN IsolateYear BETWEEN 2011 AND 2020 THEN '2011-2020'
WHEN IsolateYear BETWEEN 2021 AND 2025 THEN '2021-2025'
ELSE ''
END AS IsolateYr,
Gene,
COUNT(DISTINCT temp_selection.ShortName) AS NumPublications,
GROUP_CONCAT(DISTINCT temp_selection.ShortName) AS Publications,
COUNT(DISTINCT Accession) AS "#" ,
(SELECT COUNT(DISTINCT Accession) from temp_selection) AS Total,
ROUND(
(
COUNT(DISTINCT Accession) * 100.0 /
(SELECT COUNT(DISTINCT Accession) from temp_selection)
), 2
) AS "%"
FROM
temp_selection
GROUP BY
Host,
Country,
IsolateYr,
Gene,
ShortName
ORDER BY
"#" DESC,
Host,
Country,
IsolateYr,
Gene;
"""
run_create_view(db_file, vIsolateMetadataSummary)
vMatchNotByPMID = """
SELECT
gbr.RefID,
GROUP_CONCAT(gbrfl.Accession) AS CombinedAccessions,
gbr.Authors,
gbr.Title,
gbr.Journal,
pub.PubID,
pub.PMID AS RefPMID,
pub.Authors AS RefAuthor,
pub.Title AS RefTitle,
pub.Journal AS RefJournal,
pubd.GenBank AS RefAccession
FROM
tblGBPubRefLink gbprl
JOIN
tblGBRefs gbr ON gbprl.RefID = gbr.RefID
JOIN
tblPublications pub ON gbprl.pubID = pub.pubID
JOIN
tblPublicationData pubd ON gbprl.pubID = pubd.pubID
JOIN
tblGBRefLink gbrfl ON gbrfl.refID = gbr.refID
WHERE
gbr.PMID IS NULL OR gbr.PMID = ''
GROUP BY
gbr.RefID, gbr.PMID, gbr.Authors, gbr.Title, gbr.Journal, pub.Authors, pub.Title, pub.Journal;
"""
run_create_view(db_file, vMatchNotByPMID)
def fill_in_table(db_file, table_name, table):
conn = sqlite3.connect(str(db_file))
table.to_sql(table_name, conn, if_exists='append', index=False)
def run_create_view(db_file, sql):
conn = sqlite3.connect(str(db_file))
cursor = conn.cursor()
cursor.execute(sql)
conn.commit()
conn.close()
def load_table(db_file, table_name):
conn = sqlite3.connect(str(db_file))
return pd.read_sql(f'SELECT * FROM {table_name};', conn)
def load_tables(db_file, table_name_list):
tables = []
for i in table_name_list:
tables.append(load_table(db_file, i))
return tables
def split_table(table_config, dataframe):
tables = []
for table_name, columns in table_config:
table = dataframe[columns]
tables.append((table_name, table))
return tables
def merge_table(tables, key):
return reduce(lambda x, y: pd.merge(x, y, on=key, how='inner'), tables)
def get_table_schema_sql(db_file):
conn = sqlite3.connect(db_file)
cursor = conn.execute(
f"SELECT name FROM sqlite_master WHERE type='table' AND name NOT LIKE 'sqlite_%';"
)
for i in cursor.fetchall():
table_name = i[0]
cursor = conn.execute(
f"SELECT sql FROM sqlite_master WHERE type='table' AND name='{table_name}';"
)
schema = cursor.fetchone()[0]
print(schema)
conn.close()
def dump_db_tables(db_path, db_dump_folder):
tables = [
# 'tblGBRefs',
'vIsolateMissingData',
# 'vSubMissionNotMatch',
'vIsolateMetadataSummary',
# 'vNonClinicalIsolate',
# 'tblPublications',
# 'tblSubmissionPub'
# 'vNumSuppliedIsolateDataByPubMed',
'vGPMatched'
]
for t in tables:
json_file_path = db_dump_folder / f"{t}.json"
dump_table_to_json(json_file_path, db_path, t)
def dump_table_to_json(json_file_path, db_path, table_name):
conn = sqlite3.connect(db_path)
cursor = conn.cursor()
cursor.execute(f"SELECT * FROM {table_name}")
rows = cursor.fetchall()
column_names = [description[0] for description in cursor.description]
data = [dict(zip(column_names, row)) for row in rows]
with open(json_file_path, 'w') as json_file:
json.dump(data, json_file, indent=4)
# print(
# f"Data from view '{table_name}' has been exported to {json_file_path}")
conn.commit()
conn.close()
def dump_view_to_excel(virus_obj, db_path):
conn = sqlite3.connect(db_path)
query = "SELECT * FROM vMatchNotByPMID"
# Execute the query and fetch data into a pandas DataFrame
df = pd.read_sql_query(query, conn)
# Ensure output directory exists
output_dir = f"OutputData/{virus_obj}"
# Save the DataFrame to an Excel file
excel_path = f"{output_dir}/{virus_obj}_matched_except_PMID.xlsx"
df.to_excel(excel_path, index=False)
# Close the database connection
conn.close()
return excel_path