From 67a324dc1881dad62ac3a84c08696deab4ffdf6e Mon Sep 17 00:00:00 2001
From: Patrick Meidl <pm2@sanger.ac.uk>
Date: Mon, 8 May 2006 17:00:37 +0000
Subject: [PATCH] schema 39

---
 sql/patch_38_39_a.sql | 16 ++++++++++++++++
 sql/patch_38_39_b.sql | 35 +++++++++++++++++++++++++++++++++++
 sql/patch_38_39_c.sql | 28 ++++++++++++++++++++++++++++
 sql/patch_38_39_d.sql | 13 +++++++++++++
 sql/table.sql         | 19 +++++++++++++++----
 5 files changed, 107 insertions(+), 4 deletions(-)
 create mode 100644 sql/patch_38_39_a.sql
 create mode 100644 sql/patch_38_39_b.sql
 create mode 100644 sql/patch_38_39_c.sql
 create mode 100644 sql/patch_38_39_d.sql

diff --git a/sql/patch_38_39_a.sql b/sql/patch_38_39_a.sql
new file mode 100644
index 0000000000..97e510a639
--- /dev/null
+++ b/sql/patch_38_39_a.sql
@@ -0,0 +1,16 @@
+# patch_38_39_a
+#
+# title: status enum
+#
+# description:
+# this patch adds a new status to the enumeration in gene & transcript
+
+# Add a new status to the enumeration in gene & transcript
+
+ALTER TABLE gene CHANGE COLUMN status status enum('KNOWN','NOVEL','PUTATIVE','PREDICTED','KNOWN_BY_PROJECTION');
+
+ALTER TABLE transcript CHANGE COLUMN status status enum('KNOWN','NOVEL','PUTATIVE','PREDICTED','KNOWN_BY_PROJECTION');
+
+# patch identifier
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_a.sql|status_enum');
+
diff --git a/sql/patch_38_39_b.sql b/sql/patch_38_39_b.sql
new file mode 100644
index 0000000000..9f1768ffaf
--- /dev/null
+++ b/sql/patch_38_39_b.sql
@@ -0,0 +1,35 @@
+# patch_38_39_b
+#
+# title: unique assembly
+#
+# description:
+# this patch adds a unique index to the assembly table to prevent duplicate data
+
+# create a new table with the unique index
+
+CREATE TABLE assembly_new (
+
+  asm_seq_region_id           INT UNSIGNED NOT NULL,
+  cmp_seq_region_id           INT(10) UNSIGNED NOT NULL, 
+  asm_start                   INT(10) NOT NULL,
+  asm_end                     INT(10) NOT NULL,
+  cmp_start                   INT(10) NOT NULL,
+  cmp_end                     INT(10) NOT NULL,
+  ori                         TINYINT  NOT NULL, 
+  
+  KEY (cmp_seq_region_id),
+  KEY (asm_seq_region_id, asm_start),
+  UNIQUE KEY all_idx (asm_seq_region_id, cmp_seq_region_id, asm_start, asm_end, cmp_start, cmp_end, ori)
+
+) COLLATE=latin1_swedish_ci TYPE=MyISAM;
+
+# insert unique values into the new assembly table
+INSERT IGNORE INTO assembly_new SELECT * FROM assembly;
+
+# drop old assembly table and rename new one
+DROP TABLE assembly;
+ALTER TABLE assembly_new RENAME assembly;
+
+# patch identifier
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_b.sql|unique_assembly');
+
diff --git a/sql/patch_38_39_c.sql b/sql/patch_38_39_c.sql
new file mode 100644
index 0000000000..b4118e88b5
--- /dev/null
+++ b/sql/patch_38_39_c.sql
@@ -0,0 +1,28 @@
+# patch_38_39_c
+#
+# title: multi-version objects
+#
+# description:
+# this patch will allow the storage of multiple versions of genes,
+# transcripts and exons in a single database
+
+# add column 'is_current' boolean default 1
+
+ALTER TABLE gene ADD COLUMN is_current BOOLEAN DEFAULT 1;
+ALTER TABLE transcript ADD COLUMN is_current BOOLEAN DEFAULT 1;
+ALTER TABLE exon ADD COLUMN is_current BOOLEAN DEFAULT 1;
+
+# change UNIQUE KEY 'stable_id' to normal KEY in stable_id tables
+
+ALTER TABLE gene_stable_id DROP INDEX stable_id;
+ALTER TABLE gene_stable_id ADD INDEX stable_id_idx (stable_id, version);
+
+ALTER TABLE transcript_stable_id DROP INDEX stable_id;
+ALTER TABLE transcript_stable_id ADD INDEX stable_id_idx (stable_id, version);
+
+ALTER TABLE exon_stable_id DROP INDEX stable_id;
+ALTER TABLE exon_stable_id ADD INDEX stable_id_idx (stable_id, version);
+
+# patch identifier
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_c.sql|multiversion_objects');
+
diff --git a/sql/patch_38_39_d.sql b/sql/patch_38_39_d.sql
new file mode 100644
index 0000000000..22facaf486
--- /dev/null
+++ b/sql/patch_38_39_d.sql
@@ -0,0 +1,13 @@
+# patch_38_39_d
+#
+# title: schema version
+#
+# description:
+# this patch updates the schema version
+
+# update schema version
+UPDATE meta set meta_value = 39 where meta_key = 'schema_version';
+
+# patch identifier
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_d.sql|schema_version');
+
diff --git a/sql/table.sql b/sql/table.sql
index 43488f5ba9..05c535ae53 100755
--- a/sql/table.sql
+++ b/sql/table.sql
@@ -212,6 +212,8 @@ CREATE TABLE exon (
 
   phase                       TINYINT(2) NOT NULL,
   end_phase                   TINYINT(2) NOT NULL,
+
+  is_current                  BOOLEAN DEFAULT 1,
   
   PRIMARY KEY (exon_id),
   KEY seq_region_idx (seq_region_id, seq_region_start)
@@ -233,7 +235,7 @@ CREATE TABLE exon_stable_id (
   modified_date               DATETIME NOT NULL,
 
   PRIMARY KEY (exon_id),
-  UNIQUE (stable_id, version)
+  KEY stable_id_idx (stable_id, version)
 
 ) COLLATE=latin1_swedish_ci TYPE=MyISAM;
 
@@ -411,6 +413,7 @@ CREATE TABLE gene (
   source                      VARCHAR(20) NOT NULL,
   status                      ENUM('KNOWN', 'NOVEL', 'PUTATIVE', 'PREDICTED', 'KNOWN_BY_PROJECTION'),
   description                 TEXT,
+  is_current                  BOOLEAN DEFAULT 1,
 
   PRIMARY KEY (gene_id),
   KEY seq_region_idx (seq_region_id, seq_region_start),
@@ -434,7 +437,7 @@ CREATE TABLE gene_stable_id (
   modified_date               DATETIME NOT NULL,
 
   PRIMARY KEY (gene_id),
-  UNIQUE (stable_id, version)
+  KEY stable_id_idx (stable_id, version)
 
 ) COLLATE=latin1_swedish_ci TYPE=MyISAM;
 
@@ -491,6 +494,7 @@ CREATE TABLE transcript (
   biotype                     VARCHAR(40) NOT NULL,
   status                      ENUM('KNOWN', 'NOVEL', 'PUTATIVE', 'PREDICTED', 'KNOWN_BY_PROJECTION'),
   description                 TEXT,
+  is_current                  BOOLEAN DEFAULT 1,
 
   PRIMARY KEY (transcript_id),
   KEY seq_region_idx (seq_region_id, seq_region_start),
@@ -515,7 +519,7 @@ CREATE TABLE transcript_stable_id (
   modified_date               DATETIME NOT NULL,
   
   PRIMARY KEY (transcript_id),
-  UNIQUE (stable_id, version)
+  KEY stable_id_idx (stable_id, version)
 
 ) COLLATE=latin1_swedish_ci TYPE=MyISAM;
 
@@ -590,7 +594,8 @@ CREATE TABLE assembly (
   ori                         TINYINT  NOT NULL, 
   
   KEY (cmp_seq_region_id),
-  KEY (asm_seq_region_id, asm_start)
+  KEY (asm_seq_region_id, asm_start),
+  UNIQUE KEY all_idx (asm_seq_region_id, cmp_seq_region_id, asm_start, asm_end, cmp_start, cmp_end, ori)
 
 ) COLLATE=latin1_swedish_ci TYPE=MyISAM;
 
@@ -854,6 +859,12 @@ CREATE TABLE meta (
 # Auto add schema version to database
 INSERT INTO meta (meta_key, meta_value) VALUES ("schema_version", "39");
 
+# patches included in this schema file
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_a.sql|status_enum');
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_b.sql|unique_assembly');
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_c.sql|multiversion_objects');
+INSERT INTO meta (meta_key, meta_value) VALUES ('patch', 'patch_38_39_d.sql|schema_version');
+
 
 ################################################################################
 #
-- 
GitLab