Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: Change mysql database to postgres database #510

Merged
merged 2 commits into from
Feb 19, 2019
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
3 changes: 3 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -22,3 +22,6 @@ scripts/importer/downloaded_files
postgres-data
# local personal things
personal
# travis test remnants
master-schema.sql
settings.json.tmp
5 changes: 5 additions & 0 deletions .travis.yml
Original file line number Diff line number Diff line change
Expand Up @@ -10,3 +10,8 @@ install:
- pip install coverage coveralls
script:
- test/travis_script.sh
addons:
postgresql: "10"
apt:
packages:
- postgresql-client-10
2 changes: 1 addition & 1 deletion backend/test.py
Original file line number Diff line number Diff line change
Expand Up @@ -101,7 +101,7 @@ def tearDown(self):
try:
u = db.User.select(db.User).where(db.User.email==self.USER).get()
try:
u.access.get().delete_instance()
u.dataset_access.get().delete_instance()
except peewee.PeeweeException:
pass
try:
Expand Down
16 changes: 11 additions & 5 deletions settings_sample.json
Original file line number Diff line number Diff line change
Expand Up @@ -5,11 +5,17 @@
"googleSecret" : "a secret from google",
"redirectUri" : "https://google oauth redirect uri",

"postgresHost": "postgres host",
"postgresPort": 5432,
"postgresUser": "postgres",
"postgresPass": "",
"postgresName": "",
"mysqlHost" : "127.0.0.1",
"mysqlPasswd" : "password",
"mysqlSchema" : "swefreq",
"mysqlUser" : "swefreq",
"mysqlPort" : 3306,

"postgresHost" : "postgres host",
"postgresPort" : 5432,
"postgresUser" : "postgres",
"postgresPass" : "",
"postgresName" : "",

"mongoHost" : "mongodb host",
"mongoPassword" : "password",
Expand Down
47 changes: 0 additions & 47 deletions sql/beacon_schema.sql

This file was deleted.

68 changes: 51 additions & 17 deletions sql/data_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@
-- (reference-data, variants, and coverage) the goes into the Swefreq system. --
-- --
--------------------------------------------------------------------------------
CREATE SCHEMA IF NOT EXISTS data;

--------------------------------------------------------------------------------
-- dbSNP tables.
Expand All @@ -22,20 +23,20 @@ CREATE TABLE IF NOT EXISTS data.dbsnp_versions (
CREATE TABLE IF NOT EXISTS data.dbsnp (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
version_id integer REFERENCES data.dbsnp_versions,
rsid bigint UNIQUE,
rsid bigint,
chrom varchar(10),
pos integer
pos integer,
UNIQUE(version_id, rsid)
);

CREATE INDEX IF NOT EXISTS rsid_index ON data.dbsnp USING hash (rsid);

--------------------------------------------------------------------------------
-- Reference Set tables
--

CREATE TABLE IF NOT EXISTS data.reference_sets (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
dbsnp_version integer REFERENCES data.dbsnp_versions,
reference_build varchar UNIQUE, -- should be ^(GRCh[0-9]+([.]p[0-9]+)?)$
reference_name varchar,
ensembl_version varchar,
gencode_version varchar,
Expand All @@ -49,14 +50,19 @@ CREATE TABLE IF NOT EXISTS data.genes (
gene_id varchar(15),
gene_name varchar,
full_name varchar,
other_names varchar[],
canonical_transcript varchar(15),
chrom varchar(10),
start_pos integer,
end_pos integer,
strand varchar
);

CREATE TABLE IF NOT EXISTS data.gene_other_names (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
gene integer REFERENCES data.genes,
name varchar
);

CREATE TABLE IF NOT EXISTS data.transcripts (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
transcript_id varchar(15),
Expand Down Expand Up @@ -111,6 +117,7 @@ CREATE TABLE IF NOT EXISTS data.datasets (
full_name varchar(100) NOT NULL,
browser_uri varchar(200) DEFAULT NULL,
beacon_uri varchar(200) DEFAULT NULL,
beacon_description text DEFAULT NULL,
avg_seq_depth real DEFAULT NULL,
seq_type varchar(50) DEFAULT NULL,
seq_tech varchar(50) DEFAULT NULL,
Expand Down Expand Up @@ -143,7 +150,9 @@ CREATE TABLE IF NOT EXISTS data.dataset_versions (
available_from timestamp DEFAULT current_timestamp,
ref_doi varchar(100) DEFAULT NULL,
data_contact_name varchar(100) DEFAULT NULL,
data_contact_link varchar(100) DEFAULT NULL
data_contact_link varchar(100) DEFAULT NULL,
num_variants integer DEFAULT NULL,
coverage_levels integer[] DEFAULT NULL
);

CREATE TABLE IF NOT EXISTS data.dataset_files (
Expand All @@ -161,14 +170,13 @@ CREATE TABLE IF NOT EXISTS data.dataset_files (
CREATE TABLE IF NOT EXISTS data.variants (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
dataset_version integer REFERENCES data.dataset_versions,
variant_type varchar, -- variants go here `"enum": ["DEL", "INS", "DUP", "INV", "CNV", "SNP", "DUP:TANDEM", "DEL:ME", "INS:ME"]`
rsid integer,
chrom varchar(10),
pos integer,
ref varchar,
alt varchar,
site_quality real,
genes varchar[],
transcripts varchar[],
orig_alt_alleles varchar[],
hom_count integer,
allele_freq real,
Expand All @@ -180,22 +188,26 @@ CREATE TABLE IF NOT EXISTS data.variants (
vep_annotations jsonb
);

CREATE TABLE IF NOT EXISTS data.variant_genes (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
variant integer REFERENCES data.variants,
gene integer REFERENCES data.genes
);

CREATE TABLE IF NOT EXISTS data.variant_transcripts (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
variant integer REFERENCES data.variants,
transcript integer REFERENCES data.transcripts
);

CREATE TABLE IF NOT EXISTS data.coverage (
id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
dataset_version integer REFERENCES data.dataset_versions,
chrom varchar(10),
pos integer,
mean real,
median real,
cov1 real,
cov5 real,
cov10 real,
cov15 real,
cov20 real,
cov25 real,
cov30 real,
cov50 real,
cov100 real
coverage real[]
);

CREATE TABLE IF NOT EXISTS data.metrics (
Expand All @@ -205,3 +217,25 @@ CREATE TABLE IF NOT EXISTS data.metrics (
mids integer[],
hist integer
);

--------------------------------------------------------------------------------
-- Data views
--

CREATE OR REPLACE VIEW data.dataset_version_current AS
SELECT * FROM data.dataset_versions
WHERE (dataset, id)
IN (SELECT dataset, MAX(id) FROM data.dataset_versions
WHERE available_from < now()
GROUP BY dataset);

--------------------------------------------------------------------------------
-- Indexes
--

CREATE INDEX variant_pos ON data.variants (pos);
CREATE INDEX dbsnp_chrom_pos ON data.dbsnp (chrom, pos);
CREATE INDEX coverage_pos_chrom ON data.coverage (chrom, pos);
CREATE INDEX variants_rsid ON data.variants (rsid);
CREATE INDEX variants_chrom_pos ON data.variants (chrom, pos);
CREATE INDEX transcripts_transcript_id ON data.transcripts (transcript_id);
108 changes: 0 additions & 108 deletions sql/schema.dot

This file was deleted.

Binary file removed sql/schema.dot.png
Binary file not shown.