From dc45f1ec88632749e033c197bf7a06edcc696879 Mon Sep 17 00:00:00 2001
From: Michael Gray <mg13@sanger.ac.uk>
Date: Fri, 11 Oct 2013 14:03:17 +0000
Subject: [PATCH] "INSERT INTO table SET col1=val1, col2=val2" does not work
 for SQLite.

Use "INSERT INTO table (col1, col2) VALUES (val1, val2) instead.
---
 .../Bio/EnsEMBL/DBSQL/CoordSystemAdaptor.pm   |  7 +--
 modules/Bio/EnsEMBL/DBSQL/DBEntryAdaptor.pm   | 56 ++++++++++---------
 modules/Bio/EnsEMBL/DBSQL/GeneAdaptor.pm      | 43 ++++++++------
 .../Bio/EnsEMBL/DBSQL/MiscFeatureAdaptor.pm   | 26 +++++----
 modules/Bio/EnsEMBL/DBSQL/MiscSetAdaptor.pm   | 14 +++--
 modules/Bio/EnsEMBL/DBSQL/OperonAdaptor.pm    | 40 ++++++++-----
 .../EnsEMBL/DBSQL/OperonTranscriptAdaptor.pm  | 43 ++++++++------
 .../EnsEMBL/DBSQL/ProteinFeatureAdaptor.pm    | 16 +++++-
 modules/Bio/EnsEMBL/DBSQL/SliceAdaptor.pm     | 21 +++----
 .../Bio/EnsEMBL/DBSQL/TranscriptAdaptor.pm    | 36 +++++++++++-
 .../Bio/EnsEMBL/DBSQL/TranslationAdaptor.pm   | 27 ++++++---
 11 files changed, 213 insertions(+), 116 deletions(-)

diff --git a/modules/Bio/EnsEMBL/DBSQL/CoordSystemAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/CoordSystemAdaptor.pm
index 1745e9bb98..aeead5a5e6 100644
--- a/modules/Bio/EnsEMBL/DBSQL/CoordSystemAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/CoordSystemAdaptor.pm
@@ -1209,11 +1209,8 @@ sub store {
 
   my $sth =
     $db->dbc->prepare(   'INSERT INTO coord_system '
-                       . 'SET name = ?, '
-                       . 'version = ?, '
-                       . 'attrib = ?,'
-                       . 'rank = ?,'
-                       . 'species_id = ?' );
+                       . '( name, version, attrib, rank, species_id ) '
+                         . 'VALUES ( ?, ?, ?, ?, ? )' );
 
   $sth->bind_param( 1, $name,               SQL_VARCHAR );
   $sth->bind_param( 2, $version,            SQL_VARCHAR );
diff --git a/modules/Bio/EnsEMBL/DBSQL/DBEntryAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/DBEntryAdaptor.pm
index 4cbb7f9bf8..6b281ad16c 100644
--- a/modules/Bio/EnsEMBL/DBSQL/DBEntryAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/DBEntryAdaptor.pm
@@ -725,11 +725,12 @@ sub _store_object_xref_mapping {
     
     my $sth = $self->prepare(qq(
         INSERT IGNORE INTO object_xref
-          SET   xref_id = ?,
-                ensembl_object_type = ?,
-                ensembl_id = ?,
-                linkage_annotation = ?,
-                analysis_id = ? ) 
+              ( xref_id,
+                ensembl_object_type,
+                ensembl_id,
+                linkage_annotation,
+                analysis_id )
+          VALUES ( ?, ?, ?, ?, ? ) )
         );
     $sth->bind_param( 1, $dbEntry->dbID(),              SQL_INTEGER );
     $sth->bind_param( 2, $ensembl_type,                 SQL_VARCHAR );
@@ -747,16 +748,17 @@ sub _store_object_xref_mapping {
         if ( $dbEntry->isa('Bio::EnsEMBL::IdentityXref') ) {
         $sth = $self->prepare( "
              INSERT ignore INTO identity_xref
-             SET object_xref_id = ?,
-             xref_identity = ?,
-             ensembl_identity = ?,
-             xref_start = ?,
-             xref_end   = ?,
-             ensembl_start = ?,
-             ensembl_end = ?,
-             cigar_line = ?,
-             score = ?,
-             evalue = ?" );
+           ( object_xref_id,
+             xref_identity,
+             ensembl_identity,
+             xref_start,
+             xref_end  ,
+             ensembl_start,
+             ensembl_end,
+             cigar_line,
+             score,
+             evalue )
+           VALUES ( ?, ?, ?, ?, ?, ?, ?, ?, ?, ? )" );
         $sth->bind_param( 1, $object_xref_id,            SQL_INTEGER );
         $sth->bind_param( 2, $dbEntry->xref_identity,    SQL_INTEGER );
         $sth->bind_param( 3, $dbEntry->ensembl_identity, SQL_INTEGER );
@@ -771,9 +773,10 @@ sub _store_object_xref_mapping {
       } elsif ( $dbEntry->isa('Bio::EnsEMBL::OntologyXref') ) {
         $sth = $self->prepare( "
              INSERT ignore INTO ontology_xref
-                SET object_xref_id = ?,
-                    source_xref_id = ?,
-                    linkage_type = ? " );
+                  ( object_xref_id,
+                    source_xref_id,
+                    linkage_type    )
+               VALUES ( ?, ?, ? )" );
         foreach my $info ( @{ $dbEntry->get_all_linkage_info() } ) {
             my ( $linkage_type, $sourceXref ) = @{$info};
             my $sourceXid = undef;
@@ -964,13 +967,14 @@ sub _store_or_fetch_xref {
     
     my $sth = $self->prepare( "
        INSERT IGNORE INTO xref
-       SET dbprimary_acc = ?,
-           display_label = ?,
-           version = ?,
-           description = ?,
-           external_db_id = ?,
-           info_type = ?,
-           info_text = ?");
+         ( dbprimary_acc,
+           display_label,
+           version,
+           description,
+           external_db_id,
+           info_type,
+           info_text )
+         VALUES ( ?, ?, ?, ?, ?, ?, ? ) ");
     $sth->bind_param(1, $dbEntry->primary_id,SQL_VARCHAR);
     $sth->bind_param(2, $dbEntry->display_id,SQL_VARCHAR);
     $sth->bind_param(3, ($dbEntry->version || q{0}),SQL_VARCHAR);
@@ -993,7 +997,7 @@ sub _store_or_fetch_xref {
     
         my $synonym_store_sth = $self->prepare(
             "INSERT ignore INTO external_synonym
-             SET xref_id = ?, synonym = ?");
+             ( xref_id, synonym ) VALUES ( ?, ? ) ");
     
         my $synonyms = $dbEntry->get_all_synonyms();
         foreach my $syn ( @$synonyms ) {
diff --git a/modules/Bio/EnsEMBL/DBSQL/GeneAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/GeneAdaptor.pm
index b88b900e63..fc94af81c7 100644
--- a/modules/Bio/EnsEMBL/DBSQL/GeneAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/GeneAdaptor.pm
@@ -1201,28 +1201,39 @@ sub store {
 
   ($gene, $seq_region_id) = $self->_pre_store($gene);
 
-  my $store_gene_sql = qq(
-        INSERT INTO gene
-           SET biotype = ?,
-               analysis_id = ?,
-               seq_region_id = ?,
-               seq_region_start = ?,
-               seq_region_end = ?,
-               seq_region_strand = ?,
-               description = ?,
-               source = ?,
-               status = ?,
-               is_current = ?,
-               canonical_transcript_id = ?
+  my @columns = qw(
+               biotype
+               analysis_id
+               seq_region_id
+               seq_region_start
+               seq_region_end
+               seq_region_strand
+               description
+               source
+               status
+               is_current
+               canonical_transcript_id
   );
 
+  my @canned_columns;
+  my @canned_values;
+
   if (defined($gene->stable_id)) {
-	my $created  = $self->db->dbc->from_seconds_to_date($gene->created_date());
-	my $modified = $self->db->dbc->from_seconds_to_date($gene->modified_date());
-	$store_gene_sql .= ", stable_id = ?, version = ?, created_date = " . $created . " , modified_date = " . $modified;
+      push @columns, 'stable_id', 'version';
+
+      my $created  = $self->db->dbc->from_seconds_to_date($gene->created_date());
+      my $modified = $self->db->dbc->from_seconds_to_date($gene->modified_date());
 
+      push @canned_columns, 'created_date', 'modified_date';
+      push @canned_values,  $created,       $modified;
   }
 
+  my $columns = join(', ', @columns, @canned_columns);
+  my $values  = join(', ', ('?') x @columns, @canned_values);
+  my $store_gene_sql = qq(
+        INSERT INTO gene ( $columns ) VALUES ( $values )
+  );
+
   # column status is used from schema version 34 onwards (before it was
   # confidence)
 
diff --git a/modules/Bio/EnsEMBL/DBSQL/MiscFeatureAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/MiscFeatureAdaptor.pm
index bd3fa764f8..bddb7861d7 100644
--- a/modules/Bio/EnsEMBL/DBSQL/MiscFeatureAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/MiscFeatureAdaptor.pm
@@ -673,17 +673,21 @@ sub store {
 
   my $db = $self->db();
 
-  my $feature_sth = $self->prepare
-    ("INSERT INTO misc_feature SET " .
-     " seq_region_id    = ?, " .
-     " seq_region_start = ?, " .
-     " seq_region_end   = ?, " .
-     " seq_region_strand = ?");
-
-  my $feature_set_sth = $self->prepare
-    ("INSERT IGNORE misc_feature_misc_set SET " .
-     " misc_feature_id = ?, " .
-     " misc_set_id = ?");
+  my $feature_sth = $self->prepare(
+    q{INSERT INTO misc_feature (
+        seq_region_id,
+        seq_region_start,
+        seq_region_end,
+        seq_region_strand
+      ) VALUES (?, ?, ?, ?)
+    });
+
+  my $feature_set_sth = $self->prepare(
+    qq{INSERT IGNORE INTO misc_feature_misc_set (
+         misc_feature_id,
+         misc_set_id
+       ) VALUES (?, ?)
+      });
 
   my $msa = $db->get_MiscSetAdaptor();
   my $aa  = $db->get_AttributeAdaptor();
diff --git a/modules/Bio/EnsEMBL/DBSQL/MiscSetAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/MiscSetAdaptor.pm
index dfc0b0e041..58fddae42d 100644
--- a/modules/Bio/EnsEMBL/DBSQL/MiscSetAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/MiscSetAdaptor.pm
@@ -224,12 +224,14 @@ sub store {
   # otherwise 2 processes could try to insert at the same time and one
   # would fail
 
-  my $sth = $self->prepare
-    ("INSERT IGNORE INTO misc_set " .
-     "SET code = ?, " .
-     "    name = ?, " .
-     "    description = ?, " .
-     "    max_length  = ?");
+  my $sth = $self->prepare(
+    qq{INSERT IGNORE INTO misc_set (
+         code,
+         name,
+         description,
+         max_length
+      ) VALUES (?, ?, ?, ?)
+    });
 
   my $db = $self->db();
 
diff --git a/modules/Bio/EnsEMBL/DBSQL/OperonAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/OperonAdaptor.pm
index b8edcdb482..ccccf55f64 100644
--- a/modules/Bio/EnsEMBL/DBSQL/OperonAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/OperonAdaptor.pm
@@ -490,21 +490,31 @@ sub store {
 
 	( $operon, $seq_region_id ) = $self->_pre_store($operon);
 
-	my $store_operon_sql = qq(
-        INSERT INTO operon
-           SET seq_region_id = ?,
-               seq_region_start = ?,
-               seq_region_end = ?,
-               seq_region_strand = ?,
-               display_label = ?,
-               analysis_id = ?
-  );
-	
+	my @columns = qw(
+               seq_region_id
+               seq_region_start
+               seq_region_end
+               seq_region_strand
+               display_label
+               analysis_id
+        );
+
+        my ($created, $modified);
 	if ( defined($operon->stable_id()) ) {
-	    my $created = $self->db->dbc->from_seconds_to_date($operon->created_date());
-	    my $modified = $self->db->dbc->from_seconds_to_date($operon->modified_date());
-	    $store_operon_sql .= ", stable_id = ?, version = ?, created_date = " . $created . ",modified_date = " . $modified;
+	    $created = $self->db->dbc->from_seconds_to_date($operon->created_date());
+	    $modified = $self->db->dbc->from_seconds_to_date($operon->modified_date());
+            push @columns, qw(
+              stable_id
+              version
+              created_date
+              modified_date
+            );
 	}
+        my $i_columns = join(', ', @columns);
+        my $i_values  = join(', ', ('?') x @columns);
+        my $store_operon_sql = qq(
+          INSERT INTO operon ( ${i_columns} ) VALUES ( $i_values )
+        );
 
         # column status is used from schema version 34 onwards (before it was
 	# confidence)
@@ -520,7 +530,9 @@ sub store {
 	if ( defined($operon->stable_id()) ) {
 	    $sth->bind_param( 7, $operon->stable_id(), SQL_VARCHAR );
 	    my $version = ($operon->version()) ? $operon->version() : 1;
-	    $sth->bind_param( 8, $version, SQL_INTEGER ); 
+	    $sth->bind_param( 8, $version,             SQL_INTEGER );
+	    $sth->bind_param( 9, $created,             SQL_DATETIME );
+	    $sth->bind_param(10, $modified,            SQL_DATETIME );
 	}
 
 	$sth->execute();
diff --git a/modules/Bio/EnsEMBL/DBSQL/OperonTranscriptAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/OperonTranscriptAdaptor.pm
index af7f06677f..b6cecf03f7 100644
--- a/modules/Bio/EnsEMBL/DBSQL/OperonTranscriptAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/OperonTranscriptAdaptor.pm
@@ -544,23 +544,32 @@ sub store {
 	} else {
 		$analysis_id = $db->get_AnalysisAdaptor->store($analysis);
 	}
-	my $store_operon_transcript_sql = qq(
-        INSERT INTO operon_transcript
-           SET seq_region_id = ?,
-               seq_region_start = ?,
-               seq_region_end = ?,
-               seq_region_strand = ?,
-               display_label = ?,
-               operon_id = ?,
-               analysis_id =?
-  );
-
+	my @columns = qw(
+               seq_region_id
+               seq_region_start
+               seq_region_end
+               seq_region_strand
+               display_label
+               operon_id
+               analysis_id
+        );
+
+        my ($created, $modified);
 	if ( defined($operon_transcript->stable_id()) ) {
-	    my $created = $self->db->dbc->from_seconds_to_date($operon_transcript->created_date());
-	    my $modified = $self->db->dbc->from_seconds_to_date($operon_transcript->modified_date());
-	    $store_operon_transcript_sql .= ", stable_id = ?, version = ?, created_date = " . $created . ",modified_date = " . $modified;
+	    $created = $self->db->dbc->from_seconds_to_date($operon_transcript->created_date());
+	    $modified = $self->db->dbc->from_seconds_to_date($operon_transcript->modified_date());
+            push @columns, qw(
+              stable_id
+              version
+              created_date
+              modified_date
+            );
 	}
-	
+        my $i_columns = join(', ', @columns);
+        my $i_values  = join(', ', ('?') x @columns);
+        my $store_operon_transcript_sql = qq(
+          INSERT INTO operon_transcript ( ${i_columns} ) VALUES ( $i_values )
+        );
 
 	# column status is used from schema version 34 onwards (before it was
 	# confidence)
@@ -577,7 +586,9 @@ sub store {
 	if ( defined($operon_transcript->stable_id()) ) {
 	    $sth->bind_param( 8, $operon_transcript->stable_id(), SQL_VARCHAR );
 	    my $version = ($operon_transcript->version()) ? $operon_transcript->version() : 1;
-	    $sth->bind_param( 9, $version, SQL_INTEGER ); 
+	    $sth->bind_param( 9, $version,  SQL_INTEGER );
+	    $sth->bind_param(10, $created,  SQL_DATETIME );
+	    $sth->bind_param(11, $modified, SQL_DATETIME );
 	}
 
 	$sth->execute();
diff --git a/modules/Bio/EnsEMBL/DBSQL/ProteinFeatureAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/ProteinFeatureAdaptor.pm
index 5e9269b1a3..df64c6e104 100755
--- a/modules/Bio/EnsEMBL/DBSQL/ProteinFeatureAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/ProteinFeatureAdaptor.pm
@@ -220,7 +220,21 @@ sub store {
 	$db->get_AnalysisAdaptor->store($analysis);
   }
 
-  my $sth = $self->prepare("INSERT INTO protein_feature " . "        SET translation_id  = ?, " . "            seq_start       = ?, " . "            seq_end         = ?, " . "            analysis_id     = ?, " . "            hit_start       = ?, " . "            hit_end         = ?, " . "            hit_name        = ?, " . "            hit_description = ?, " . "            score           = ?, " . "            perc_ident      = ?, " . "            evalue          = ?");
+  my $sth = $self->prepare(q{
+    INSERT INTO protein_feature
+                ( translation_id,
+                  seq_start,
+                  seq_end,
+                  analysis_id,
+                  hit_start,
+                  hit_end,
+                  hit_name,
+                  hit_description,
+                  score,
+                  perc_ident,
+                  evalue     )
+         VALUES ( ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ? )
+  });
 
   $sth->bind_param(1,  $translation_id,        SQL_INTEGER);
   $sth->bind_param(2,  $feature->start,        SQL_INTEGER);
diff --git a/modules/Bio/EnsEMBL/DBSQL/SliceAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/SliceAdaptor.pm
index ca4c883c1a..45a3e9a3d2 100644
--- a/modules/Bio/EnsEMBL/DBSQL/SliceAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/SliceAdaptor.pm
@@ -2018,9 +2018,9 @@ sub store {
   #store the seq_region
 
   my $sth = $db->dbc->prepare("INSERT INTO seq_region " .
-                         "SET    name = ?, " .
-                         "       length = ?, " .
-                         "       coord_system_id = ?" );
+                              "            ( name, length, coord_system_id ) " .
+                              "     VALUES ( ?, ?, ? )"
+      );
 
   $sth->bind_param(1,$sr_name,SQL_VARCHAR);
   $sth->bind_param(2,$sr_len,SQL_INTEGER);
@@ -2332,13 +2332,14 @@ sub store_assembly{
   #
   my $sth = $self->db->dbc->prepare
       ("INSERT INTO assembly " .
-       "SET     asm_seq_region_id = ?, " .
-       "        cmp_seq_region_id = ?, " .
-       "        asm_start = ?, " .
-       "        asm_end   = ?, " .
-       "        cmp_start = ?, " .
-       "        cmp_end   = ?, " .
-       "        ori       = ?" );
+       "      ( asm_seq_region_id, " .
+       "        cmp_seq_region_id, " .
+       "        asm_start, " .
+       "        asm_end  , " .
+       "        cmp_start, " .
+       "        cmp_end  , " .
+       "        ori       )" .
+       "VALUES ( ?, ?, ?, ?, ?, ?, ? )");
 
   my $asm_seq_region_id = $self->get_seq_region_id( $asm_slice );
   my $cmp_seq_region_id = $self->get_seq_region_id( $cmp_slice );
diff --git a/modules/Bio/EnsEMBL/DBSQL/TranscriptAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/TranscriptAdaptor.pm
index 2882756054..2d7e889399 100644
--- a/modules/Bio/EnsEMBL/DBSQL/TranscriptAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/TranscriptAdaptor.pm
@@ -973,18 +973,48 @@ sub store {
   #
   # Store transcript
   #
-  my $store_transcript_sql = 
-    sprintf "INSERT INTO transcript SET gene_id = ?, analysis_id = ?, seq_region_id = ?, seq_region_start = ?, seq_region_end = ?, seq_region_strand = ?,%s biotype = ?, status = ?, description = ?, is_current = ?, canonical_translation_id = ?", ($self->schema_version > 74)?" source = ?,":'';
 
+#  my $store_transcript_sql = 
+#    sprintf "INSERT INTO transcript SET gene_id = ?, analysis_id = ?, seq_region_id = ?, seq_region_start = ?, seq_region_end = ?, seq_region_strand = ?,%s biotype = ?, status = ?, description = ?, is_current = ?, canonical_translation_id = ?", ($self->schema_version > 74)?" source = ?,":'';
+
+  my @columns = qw(
+            gene_id
+            analysis_id
+            seq_region_id
+            seq_region_start
+            seq_region_end
+            seq_region_strand
+  );
+
+  push @columns, 'source' if ($self->schema_version > 74);
+
+  push @columns, qw(
+            biotype
+            status
+            description
+            is_current
+            canonical_translation_id
+  );
+
+  my @canned_columns;
+  my @canned_values;
 
   if ( defined( $transcript->stable_id() ) ) {
+      push @columns, 'stable_id', 'version';
 
       my $created = $self->db->dbc->from_seconds_to_date($transcript->created_date());
       my $modified = $self->db->dbc->from_seconds_to_date($transcript->modified_date());
-      $store_transcript_sql .= ", stable_id = ?, version = ?, created_date = " . $created . " , modified_date = " . $modified;
 
+      push @canned_columns, 'created_date', 'modified_date';
+      push @canned_values,  $created,       $modified;
   }
 
+  my $columns = join(', ', @columns, @canned_columns);
+  my $values  = join(', ', ('?') x @columns, @canned_values);
+  my $store_transcript_sql = qq(
+        INSERT INTO transcript ( $columns ) VALUES ( $values )
+  );
+
   my $tst = $self->prepare($store_transcript_sql);
   my $i = 0;
   $tst->bind_param( ++$i,  $gene_dbID,                 SQL_INTEGER );
diff --git a/modules/Bio/EnsEMBL/DBSQL/TranslationAdaptor.pm b/modules/Bio/EnsEMBL/DBSQL/TranslationAdaptor.pm
index 661e69e767..cf063d4786 100644
--- a/modules/Bio/EnsEMBL/DBSQL/TranslationAdaptor.pm
+++ b/modules/Bio/EnsEMBL/DBSQL/TranslationAdaptor.pm
@@ -477,22 +477,33 @@ sub store {
     throw("end_Exon must have a dbID for Translation to be stored.");
   }
 
-  my $store_translation_sql = qq(
-         INSERT INTO translation 
-             SET seq_start = ?, 
-                 start_exon_id = ?,
-                 seq_end = ?, 
-                 end_exon_id = ?, 
-                 transcript_id = ?
+  my @columns = qw(
+                 seq_start
+                 start_exon_id
+                 seq_end
+                 end_exon_id
+                 transcript_id
   );
 
+  my @canned_columns;
+  my @canned_values;
+
   if (defined($translation->stable_id)) {
+      push @columns, 'stable_id', 'version';
+
       my $created = $self->db->dbc->from_seconds_to_date($translation->created_date());
       my $modified = $self->db->dbc->from_seconds_to_date($translation->modified_date());
-      $store_translation_sql .= ", stable_id = ?, version = ?, created_date = " . $created . " , modified_date = " . $modified;
 
+      push @canned_columns, 'created_date', 'modified_date';
+      push @canned_values,  $created,       $modified;
   }
 
+  my $columns = join(', ', @columns, @canned_columns);
+  my $values  = join(', ', ('?') x @columns, @canned_values);
+  my $store_translation_sql = qq(
+        INSERT INTO translation ( $columns ) VALUES ( $values )
+  );
+
   my $sth = $self->prepare($store_translation_sql);
   $sth->bind_param(1,$translation->start,SQL_INTEGER);
   $sth->bind_param(2,$translation->start_Exon->dbID,SQL_INTEGER);
-- 
GitLab