Skip to content

Web table psql #81

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

Open
wants to merge 121 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
121 commits
Select commit Hold shift + click to select a range
55e982a
add initial web table psql files
steve-fischer-200 May 9, 2025
0038dbd
get MG to conform
steve-fischer-200 May 9, 2025
50e942f
rm spclosure and move genmicseq attributes
jbrestel May 9, 2025
758358e
organism tables... and some protein tables
jbrestel May 9, 2025
9a3a48f
break out indexes into _ix files
steve-fischer-200 May 10, 2025
fcfb725
add macros and fix index files
steve-fischer-200 May 12, 2025
37285ee
wip
jbrestel May 12, 2025
b758e7c
fix quotes and update some tables
steve-fischer-200 May 13, 2025
ce9d81e
fix _ix files
steve-fischer-200 May 13, 2025
577e9fd
wip
jbrestel May 13, 2025
706a561
convert some more MOs
steve-fischer-200 May 13, 2025
8b21396
convert some more MOs
steve-fischer-200 May 13, 2025
f7c173d
filled in some ?
jbrestel May 13, 2025
411faed
Merge branch 'web-table-psql' of github.com:VEuPathDB/ApiCommonModel …
jbrestel May 13, 2025
2f7e259
rename ?? to UK
steve-fischer-200 May 13, 2025
ff0a3fc
filled in some ?
jbrestel May 13, 2025
d48628b
Merge branch 'web-table-psql' of github.com:VEuPathDB/ApiCommonModel …
jbrestel May 13, 2025
d666a39
more updates
steve-fischer-200 May 13, 2025
536410b
touch up transattrs
steve-fischer-200 May 14, 2025
d13012b
wip
jbrestel May 14, 2025
099f1a0
move or remove some psql files
jbrestel May 14, 2025
ec5bf01
wip
jbrestel May 14, 2025
cd9c52d
debug
steve-fischer-200 May 16, 2025
8279375
debug
steve-fischer-200 May 16, 2025
7088823
correct indexes
steve-fischer-200 May 16, 2025
f744115
drop table and clean Ks
steve-fischer-200 May 19, 2025
02d5966
rename webready folders
steve-fischer-200 May 19, 2025
1b021a5
rename webready folders
steve-fischer-200 May 19, 2025
d5798ed
prune tuning manager file
steve-fischer-200 May 20, 2025
4e14421
mv pathwaynodes
steve-fischer-200 May 20, 2025
82ce296
mv pathwaynodes
steve-fischer-200 May 20, 2025
cfcb7e6
adjust PathwayNodes
steve-fischer-200 May 20, 2025
5f6cd2c
fix pathwaynodes
steve-fischer-200 May 20, 2025
8cbe278
clean comparative and global
steve-fischer-200 May 21, 2025
0141db3
fix index schema
steve-fischer-200 May 21, 2025
7bea783
optimize compprops and pathreact
steve-fischer-200 May 22, 2025
74d5718
fix missing :SCHEMA
steve-fischer-200 May 22, 2025
30e5884
fix typos
steve-fischer-200 May 22, 2025
48d2470
fix typo
steve-fischer-200 May 22, 2025
36184a8
fix typo
steve-fischer-200 May 22, 2025
a4dbadb
fix typo
steve-fischer-200 May 22, 2025
4054387
missing taxon.
steve-fischer-200 May 22, 2025
7e684ca
debug
steve-fischer-200 May 22, 2025
a94bc2d
est tables to use is_reference and update notes
jbrestel May 22, 2025
4005884
debug
steve-fischer-200 May 22, 2025
553a3de
Merge branch 'web-table-psql' of github.com:VEuPathDB/ApiCommonModel …
jbrestel May 22, 2025
33b8248
debug
steve-fischer-200 May 22, 2025
9d49eb1
debug
steve-fischer-200 May 22, 2025
97f480c
debug
steve-fischer-200 May 22, 2025
dc1f038
debug
steve-fischer-200 May 22, 2025
f03dad2
debug
steve-fischer-200 May 22, 2025
9cbcbc9
debug
steve-fischer-200 May 22, 2025
affcf6d
debug indexes
steve-fischer-200 May 22, 2025
73a0c35
debug indexes
steve-fischer-200 May 22, 2025
6b97ff9
debug indexes
steve-fischer-200 May 22, 2025
61b40b1
debug
steve-fischer-200 May 22, 2025
6dacc1c
debug
steve-fischer-200 May 22, 2025
3235c0c
debug
steve-fischer-200 May 22, 2025
1b3de8e
debug
steve-fischer-200 May 22, 2025
130a805
debug
steve-fischer-200 May 22, 2025
8a2e733
debug
steve-fischer-200 May 22, 2025
fc1c470
debug
steve-fischer-200 May 22, 2025
26020b1
debug
steve-fischer-200 May 22, 2025
67bbd35
debug
steve-fischer-200 May 22, 2025
23393e5
add comments
steve-fischer-200 May 22, 2025
3372f5f
debug
steve-fischer-200 May 23, 2025
f17c412
debug
steve-fischer-200 May 23, 2025
604dcc5
debug
steve-fischer-200 May 23, 2025
6431a17
debug
steve-fischer-200 May 23, 2025
ede9ee6
debug
steve-fischer-200 May 23, 2025
d9acbfe
debug
steve-fischer-200 May 23, 2025
d10d7ef
debug
steve-fischer-200 May 23, 2025
0843462
debug
steve-fischer-200 May 23, 2025
1ab9d38
debug
steve-fischer-200 May 23, 2025
7f533fe
debug
steve-fischer-200 May 23, 2025
4c14c17
debug
steve-fischer-200 May 23, 2025
5a254fe
debug
steve-fischer-200 May 23, 2025
8480a70
debug
steve-fischer-200 May 23, 2025
7fc4ad7
debug
steve-fischer-200 May 23, 2025
90c0ff8
debug
steve-fischer-200 May 23, 2025
c93978e
debug
steve-fischer-200 May 23, 2025
376f8ba
add TaxonTree
steve-fischer-200 May 27, 2025
c1ca624
fix SQL, as in #8aca696
May 28, 2025
f9fabd4
add group tables
steve-fischer-200 May 28, 2025
399b744
fix taxonomy
steve-fischer-200 May 28, 2025
a8afab3
fix sql as REGEXP_LIKE and REGEXP_COUNT are available in pg
May 12, 2025
2f384f3
uncomment TranscriptGenomicSequence
May 14, 2025
8ac1910
fix dependency for TranscriptGenomicSequence
May 15, 2025
dc408ab
Fix SQL for 3D structure predictions section on gene record page
May 15, 2025
4662e32
Edited SQL to postgres to fix scRNA-Seq section on gene record page
May 16, 2025
d172702
debug
steve-fischer-200 May 28, 2025
783a97d
debug
steve-fischer-200 May 28, 2025
8b3a7bd
debug
steve-fischer-200 May 28, 2025
a60fd41
debug
steve-fischer-200 May 29, 2025
c384689
fix taxonid bug
steve-fischer-200 May 29, 2025
98410cb
debug
steve-fischer-200 Jun 2, 2025
a37bae3
debug
steve-fischer-200 Jun 2, 2025
7276fae
merge from master
steve-fischer-200 Jun 2, 2025
b6e139b
remove ortho .psql
steve-fischer-200 Jun 2, 2025
223b660
need to define taxon tree org specific to handle temp taxon ids
jbrestel Jun 3, 2025
9083af1
remove taxontree
steve-fischer-200 Jun 4, 2025
9124a0d
fix taxonspecies
steve-fischer-200 Jun 4, 2025
590b6b7
add notes
jbrestel Jun 4, 2025
10002ed
New GeneOrthologGroup and TranscriptOrthologGroupTables
rdemko2332 Jun 5, 2025
49e87f6
uncomment TranscriptGenomicSequence
May 14, 2025
8fc8012
New GeneOrthologGroup and TranscriptOrthologGroupTables
rdemko2332 Jun 5, 2025
b20cc2e
Merge remote-tracking branch 'origin/shared_ortho_database' into shar…
rdemko2332 Jun 5, 2025
9d44208
add convert2webready
steve-fischer-200 Jun 5, 2025
56ddd88
Merge branch 'master' into web-table-psql
jbrestel Jun 5, 2025
e655ca5
Merge branch 'web-table-psql' into shared_ortho_database
jbrestel Jun 5, 2025
2ee6f72
add TranscriptProduct
steve-fischer-200 Jun 5, 2025
6e5deac
restore apiTuningManager.xml
steve-fischer-200 Jun 6, 2025
aa89ddb
Resolving syntax error
rdemko2332 Jun 9, 2025
758fa2d
Resolving duplicate row issue
rdemko2332 Jun 9, 2025
4b24d06
Resolving primary key issue
rdemko2332 Jun 9, 2025
d25cdba
Adding distinct full_id to proteinSequenceGroup
rdemko2332 Jun 9, 2025
e20cbdb
Avoid hardcoding webready; use :SCHEMA for better flexibility
sufenhu Jun 16, 2025
6af3a1b
use PG remote schemas
steve-fischer-200 Jun 25, 2025
76eaeb8
Merge branch 'master' into web-table-psql
jbrestel Jun 26, 2025
1788f9a
Merge pull request #82 from VEuPathDB/shared_ortho_database
jbrestel Jul 4, 2025
3d014bc
JB KC Webtables (#86)
jbrestel Jul 17, 2025
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
97 changes: 97 additions & 0 deletions Model/lib/psql/webready/comparative/AlphaFoldGenes.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,97 @@
drop table if exists :SCHEMA.uniprotgenes;

CREATE UNLOGGED TABLE :SCHEMA.uniprotGenes AS
SELECT DISTINCT ed.name
, d.*
, edr.version
, aa.source_id
, pa.gene_source_id
, CASE WHEN (ed.name like '%SWISSPROT%' AND edr.version = 'xrefuniparc') THEN 1
WHEN (ed.name like '%SPTREMBL%' AND edr.version = 'xrefuniparc') THEN 2
WHEN (ed.name like '%SWISSPROT%' AND edr.version = 'xref_sprot_blastp') THEN 4
WHEN (ed.name like '%SPTREMBL%' and edr.version = 'xref_trembl_blastp') THEN 5
ELSE 6 END as rank
, (af.last_residue_index - af.first_residue_index + 1) as hit_length
FROM sres.dbref d
LEFT JOIN apidb.AlphaFold af ON d.primary_identifier = af.uniprot_id
, sres.externaldatabase ed
, sres.externaldatabaserelease edr
, dots.dbrefaafeature db
, dots.aafeature aa
, :SCHEMA.ProteinAttributes pa
WHERE (ed.name = 'Uniprot/SWISSPROT' OR ed.name = 'Uniprot/SPTREMBL')
AND (edr.version = 'xrefuniparc' OR edr.version = 'xref_sprot_blastp' OR edr.version = 'xref_trembl_blastp')
AND edr.external_database_id = ed.external_database_id
AND d.external_database_release_id = edr.external_database_release_id
AND db.db_ref_id = d.db_ref_id
AND aa.aa_feature_id = db.aa_feature_id
AND pa.source_id = aa.source_id
UNION
SELECT DISTINCT ed.name
, d.*
, edr.version
, na.source_id
, ta.gene_source_id
, 3 as rank
, (af.last_residue_index - af.first_residue_index + 1) as hit_length
FROM sres.dbref d
LEFT JOIN apidb.AlphaFold af ON d.primary_identifier = af.uniprot_id
, sres.externaldatabase ed
, sres.externaldatabaserelease edr
, dots.dbrefnafeature db
, dots.nafeature na
, :SCHEMA.TranscriptAttributes ta
WHERE ed.name like '%_dbxref_%niprot_%RSRC'
AND edr.external_database_id = ed.external_database_id
AND d.external_database_release_id = edr.external_database_release_id
AND db.db_ref_id = d.db_ref_id
AND na.na_feature_id = db.na_feature_id
AND (ta.transcript_source_id = na.source_id OR ta.gene_source_id = na.source_id)

;

drop table if exists :SCHEMA.minrank
;
CREATE UNLOGGED TABLE :SCHEMA.minRank AS (
SELECT gene_source_id
, MIN(rank) as min_rank
FROM :SCHEMA.uniprotGenes upg
WHERE hit_length is not null
GROUP BY gene_source_id
)

;

drop table if exists :SCHEMA.alphafoldhits;

CREATE UNLOGGED TABLE :SCHEMA.alphaFoldHits AS (
SELECT DISTINCT gene_source_id
, last_value(primary_identifier) over (PARTITION BY gene_source_id ORDER BY hit_length ASC ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS uniprot_id
FROM (
SELECT upg.*
FROM :SCHEMA.uniprotGenes upg
, :SCHEMA.minRank
WHERE upg.gene_source_id = minRank.gene_source_id
AND upg.rank = minRank.min_rank
) t
)
;

CREATE TABLE :SCHEMA.AlphaFoldGenes AS (
SELECT afh.gene_source_id
, af.uniprot_id
, af.source_id as alphafold_id
, af.alphafold_version
, af.first_residue_index
, af.last_residue_index
FROM apidb.alphafold af
, :SCHEMA.alphaFoldHits afh
WHERE afh.uniprot_id = af.uniprot_id
)

;

drop table if exists :SCHEMA.uniprotgenes;
drop table if exists :SCHEMA.minrank;
drop table if exists :SCHEMA.alphafoldhits;

3 changes: 3 additions & 0 deletions Model/lib/psql/webready/comparative/AlphaFoldGenes_ix.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
CREATE index AlphaFoldGenes_idx ON :SCHEMA.AlphaFoldGenes (gene_source_id, uniprot_id)

;
21 changes: 21 additions & 0 deletions Model/lib/psql/webready/comparative/GroupDomainDescriptions.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
create table :SCHEMA.GroupDomainDescriptions as
SELECT og.group_id AS group_name, ag.descriptions
FROM apidb.OrthologGroup og,
(SELECT group_name,
STRING_AGG(accession ||' (' || num_proteins|| ')', ', ') AS descriptions
FROM (SELECT group_name, accession, num_proteins, rnk
FROM (SELECT group_name, accession, num_proteins,
rank() OVER (PARTITION BY group_name ORDER BY num_proteins DESC) rnk
FROM (SELECT group_name, accession, count(distinct full_id) AS num_proteins
FROM :SCHEMA.ProteinDomainAssignment
GROUP BY group_name,accession
)
)
WHERE rnk <= 3
)
GROUP BY group_name
ORDER BY 1
) ag
WHERE og.group_id = ag.group_name

;
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
CREATE INDEX GroupDomainAttribute_idx ON :SCHEMA.GroupDomainDescriptions (group_name)
;
29 changes: 29 additions & 0 deletions Model/lib/psql/webready/comparative/LoadOrthologTables.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
Truncate table :SCHEMA.GeneOrthologGroup;
Truncate table :SCHEMA.TranscriptOrthologGroup;

insert into :SCHEMA.GeneOrthologGroup (gene_id, group_id, project_id, org_abbrev, modification_date)
SELECT ga.gene_source_id AS gene_id
, ogas.group_id
, ga.project_id
, ga.org_abbrev
, timestamp as modification_date
FROM :SCHEMA.geneattributes ga,
apidb.orthologgroupaasequence ogas
WHERE ga.aa_sequence_id = ogas.aa_sequence_id;



insert into :SCHEMA.TranscriptOrthologGroup (source_id, gene_id, group_id, project_id, org_abbrev, modification_date)
SELECT ta.source_id AS source_id
, ta.gene_source_id as gene_id
, ogas.group_id
, ta.project_id
, ta.org_abbrev
, timestamp as modification_date
FROM :SCHEMA.transcriptattributes ta
, apidb.orthologgroupaasequence ogas
WHERE ta.aa_sequence_id = ogas.aa_sequence_id;




58 changes: 58 additions & 0 deletions Model/lib/psql/webready/comparative/LoadPathwaysGeneTable.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
/* ATTENTION: This script is run using a custom workflow step class */
/* This accommodates the required to retain an empty table on undo */

TRUNCATE TABLE :SCHEMA.PathwaysGeneTable;

DO $$
DECLARE org record:PLPGSQL_DELIM
BEGIN
FOR org IN (SELECT DISTINCT abbrev FROM apidb.organism)
LOOP
INSERT INTO :SCHEMA.PathwaysGeneTable (
SELECT t2.*, current_timestamp AS modification_date FROM (
SELECT DISTINCT
gene_source_id
, pathway_source_id
, pathway_name
, count(reaction_source_id) AS reactions
, enzyme
, expasy_url
, pathway_source
, exact_match
, project_id
, org_abbrev
FROM (
SELECT DISTINCT
tp.gene_source_id
, tp.project_id
, tp.pathway_source_id
, tp.pathway_name
, tp.org_abbrev
, pr.reaction_source_id
, pr.enzyme
, pr.expasy_url
, tp.pathway_source
, CASE MAX(tp.exact_match) WHEN 1 THEN 'Yes' WHEN 0 THEN 'No' END AS exact_match
FROM :SCHEMA.TranscriptPathway tp
, apidbtuning.PathwayAttributes pa
, apidbtuning.PathwayCompounds pc
, apidbtuning.PathwayReactions pr
WHERE tp.pathway_id = pa.pathway_id
AND pc.pathway_id = pa.pathway_id
AND pr.reaction_id = pc.reaction_id
AND pr.ext_db_name = pc.ext_db_name
AND tp.ec_number_pathway = pr.enzyme
AND tp.wildcard_count_gene <= tp.wildcard_count_pathway
AND pr.enzyme != '-.-.-.-'
AND tp.org_abbrev = org.abbrev
GROUP BY tp.gene_source_id, tp.project_id, tp.org_abbrev, tp.pathway_name, tp.pathway_source_id, pr.reaction_source_id, pr.enzyme, pr.expasy_url, tp.pathway_source
) t
GROUP BY gene_source_id, project_id, org_abbrev, pathway_source_id, pathway_name, enzyme, expasy_url, pathway_source, exact_match
) t2
ORDER BY pathway_source, lower(pathway_name)
):PLPGSQL_DELIM
COMMIT:PLPGSQL_DELIM
END LOOP:PLPGSQL_DELIM
END:PLPGSQL_DELIM
$$ LANGUAGE PLPGSQL;

174 changes: 174 additions & 0 deletions Model/lib/psql/webready/comparative/LoadTranscriptPathway.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,174 @@
/* ATTENTION: This script is run using a custom workflow step class */
/* This accommodates the requirement to retain empty TranscriptEC and TranscriptPathway tables on undo */

/* STEP 1: Make sure temp tables have been dropped before starting */

DROP TABLE IF EXISTS :SCHEMA.TranscriptEcUniverse;
DROP TABLE IF EXISTS :SCHEMA.PathwayEcUniverse;
DROP TABLE IF EXISTS :SCHEMA.TranscriptPathwayEcMatch;

-- Just to be safe add these here
TRUNCATE TABLE :SCHEMA.TranscriptPathway;
TRUNCATE TABLE :SCHEMA.TranscriptEC;


/* STEP 2: Load into the TranscriptEC table. This must be done here so that we capture ortho-derived EC numbers*/

/* ATTENTION: this step loads into an empty partitioned table created in the orgSpecific graph */

DO $$
DECLARE org RECORD:PLPGSQL_DELIM
BEGIN
FOR org IN (SELECT DISTINCT taxon_id, abbrev from apidb.organism)
LOOP
INSERT INTO :SCHEMA.TranscriptEc (
SELECT DISTINCT
ta.source_id
, ta.gene_source_id
, ec.enzyme_class_id
, ec.ec_number
, ec.ec_number_1
, ec.ec_number_2
, ec.ec_number_3
, ec.ec_number_4
, regexp_count(ec.ec_number, '-') as wildcard_count
, asec.evidence_code
, ta.project_id
, org.abbrev as org_abbrev
, current_timestamp as modification_date
FROM sres.EnzymeClass ec
, dots.AaSequenceEnzymeClass asec
, :SCHEMA.transcriptattributes ta
WHERE asec.aa_sequence_id = ta.aa_sequence_id
AND asec.enzyme_class_id = ec.enzyme_class_id
AND ta.org_abbrev = org.abbrev
):PLPGSQL_DELIM
COMMIT:PLPGSQL_DELIM
END LOOP:PLPGSQL_DELIM
END:PLPGSQL_DELIM
$$ LANGUAGE PLPGSQL;


/* STEP 3: Extracts the distinct EC numbers from TranscriptEC */
/* This represents the "universe" of EC numbers associated to transcripts */
/* Temp table, will be dropped */

CREATE TABLE :SCHEMA.TranscriptEcUniverse as (
SELECT DISTINCT
enzyme_class_id
, ec_number
, ec_number_1
, ec_number_2
, ec_number_3
, ec_number_4
, wildcard_count
FROM :SCHEMA.TranscriptEc
);

/* STEP 4: Extract the distinct EC number from PathwayEC */
/* This represents the "universe" of EC numbers associated to pathways */
/* Temp table, will be dropped */

CREATE TABLE :SCHEMA.PathwayEcUniverse as (
SELECT DISTINCT
enzyme_class_id
, ec_number
, ec_number_1
, ec_number_2
, ec_number_3
, ec_number_4
, wildcard_count
FROM :SCHEMA.PathwayEc
);


/* STEP 5: Match EC numbers from the transcript universe and EC numbers from the pathway universe */
/* Use the universe tables to avoid redundancy */
/* Temp table, will be dropped */

CREATE TABLE :SCHEMA.TranscriptPathwayEcMatch as (
SELECT DISTINCT
teu.enzyme_class_id AS transcript_enzyme_class_id
, peu.enzyme_class_id AS pathway_enzyme_class_id
, teu.wildcard_count AS wildcard_count_transcript
, peu.wildcard_count AS wildcard_count_pathway
, teu.ec_number AS ec_number_transcript
, peu.ec_number AS ec_number_pathway
FROM :SCHEMA.TranscriptEcUniverse teu
, :SCHEMA.PathwayEc peu

-- this part does ec number expansion using the individual digits to avoid slow like syntax
WHERE (teu.ec_number_1 = peu.ec_number_1 or teu.ec_number_1 is null or peu.ec_number_1 is null)
AND (teu.ec_number_2 = peu.ec_number_2 or teu.ec_number_2 is null or peu.ec_number_2 is null)
AND (teu.ec_number_3 = peu.ec_number_3 or teu.ec_number_3 is null or peu.ec_number_3 is null)
AND (teu.ec_number_4 = peu.ec_number_4 or teu.ec_number_4 is null or peu.ec_number_4 is null)
);


/* STEP 6: Map the matched EC numbers to map back to both pathways and transcripts */
/* ATTENTION: this step loads into an empty partitioned table created in the orgSpecific graph */

/* This is the equivalent of the old TranscriptPathway tuning table */

DO $$
DECLARE org RECORD:PLPGSQL_DELIM
BEGIN
FOR org IN (SELECT DISTINCT taxon_id, abbrev FROM apidb.organism)
LOOP
INSERT INTO :SCHEMA.transcriptpathway (
SELECT DISTINCT

-- gene info
ta.source_id
, ta.gene_source_id

-- pathway info
, pa.source_id AS pathway_source_id
, pa.name AS pathway_name
, pa.pathway_id
, pa.pathway_source
, pec.external_database_release_id

-- info about match
, tpem.ec_number_transcript AS ec_number_gene
, tpem.wildcard_count_transcript AS wildcard_count_gene
, tpem.ec_number_pathway
, tpem.wildcard_count_pathway
, CASE WHEN tpem.ec_number_pathway = tpem.ec_number_transcript
THEN 1
ELSE 0 END AS exact_match
, CASE WHEN tpem.wildcard_count_pathway + tpem.wildcard_count_transcript = 0
THEN 1
ELSE 0 END AS complete_ec

-- for partitioning
, ta.project_id
, org.abbrev AS org_abbrev
, current_timestamp AS modification_date
FROM :SCHEMA.TranscriptPathwayEcMatch tpem
, :SCHEMA.PathwayEc pec
, :SCHEMA.PathwayAttributes pa
, :SCHEMA.TranscriptAttributes ta
, :SCHEMA.TranscriptEc tec
WHERE tpem.ec_number_transcript = tec.ec_number
AND tpem.ec_number_pathway = pec.ec_number
AND pa.pathway_id = pec.pathway_id
AND ta.source_id = tec.source_id
AND tec.org_abbrev = org.abbrev
AND ta.org_abbrev = org.abbrev
-- JB: It is unclear what the intention here was. This will not remove any rows and shouldn't
-- AND (
-- (ta.orthomcl_name IS NULL AND tec.evidence_code != 'OrthoMCLDerived')
-- OR ta.orthomcl_name IS NOT NULL
-- )
):PLPGSQL_DELIM
COMMIT:PLPGSQL_DELIM
END LOOP:PLPGSQL_DELIM
END:PLPGSQL_DELIM
$$ LANGUAGE PLPGSQL;


/* STEP 7: Delete temp tables */
DROP TABLE :SCHEMA.TranscriptEcUniverse;
DROP TABLE :SCHEMA.PathwayEcUniverse;
DROP TABLE :SCHEMA.TranscriptPathwayEcMatch;
Loading