Skip to content
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.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
-- This index overlaps with pk_luminex_runexclusion
DROP INDEX luminex.idx_luminexrunexclusion_runid;
-- This index overlaps with uq_analyte_lsid
DROP INDEX luminex.ix_luminexdatarow_lsid;
Comment on lines +3 to +4
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

uq_analyte_lsid is on a different table. luminex.analyte vs luminex.datarow. Am I missing something?

Copy link
Contributor Author

@labkey-adam labkey-adam Oct 3, 2025

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes, it's confusing... but if you look at the PostgreSQL luminex-0.000-23.000.sql script, you'll see:

CREATE INDEX IX_LuminexDataRow_LSID ON luminex.Analyte (LSID);

Based on the name and the fact that the SQL Server script has:

CREATE INDEX IX_LuminexDataRow_LSID ON luminex.DataRow (LSID);

...I concluded that the PostgreSQL definition is flat-out wrong. That's why the new incremental script recreates this index (correctly) after the drop statements. Also why there are six index drops on SQL Server and seven on PostgreSQL (that was my first clue that something must be off).

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Oh, interesting. I saw that the scripts were different in this PR but didn't realize it was because the original script was wrong.

Yes, this seems like the correct fixup now. I swear that I saw IX_LuminexDataRow_LSID on datarow when looking directly in the DB, but maybe I was just checking the SQLServer side.

-- This index overlaps with pk_luminex_analytetitration
DROP INDEX luminex.idx_luminexanalytetitration_analyteid;
-- This index overlaps with uq_curvefit
DROP INDEX luminex.idx_luminexcurvefit_analyteidtitrationid;
-- This index overlaps with pk_analytesinglepointcontrol
DROP INDEX luminex.idx_analytesinglepointcontrol_analyteid;
-- This index overlaps with pk_luminexwellexclusionanalyte
DROP INDEX luminex.idx_luminexwellexclusionanalyte_analyteid;
-- This index overlaps with pk_luminexrunexclusionanalyte
DROP INDEX luminex.idx_luminexrunexclusionanalyte_analyteid;

-- Previous index seems to be incorrect... this is the SQL Server version
CREATE INDEX IX_LuminexDataRow_LSID ON luminex.DataRow (LSID);
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
-- This index overlaps with PK_Luminex_RunExclusion
DROP INDEX IDX_LuminexRunExclusion_RunId ON luminex.RunExclusion;
-- This index overlaps with PK_LuminexWellExclusionAnalyte
DROP INDEX IDX_LuminexWellExclusionAnalyte_AnalyteId ON luminex.WellExclusionAnalyte;
-- This index overlaps with PK_Luminex_AnalyteTitration
DROP INDEX IDX_LuminexAnalyteTitration_AnalyteId ON luminex.AnalyteTitration;
-- This index overlaps with PK_AnalyteSinglePointControl
DROP INDEX IDX_AnalyteSinglePointControl_AnalyteId ON luminex.AnalyteSinglePointControl;
-- This index overlaps with UQ_CurveFit
DROP INDEX IDX_LuminexCurveFit_AnalyteIdTitrationId ON luminex.CurveFit;
-- This index overlaps with PK_LuminexRunExclusionAnalyte
DROP INDEX IDX_LuminexRunExclusionAnalyte_AnalyteId ON luminex.RunExclusionAnalyte;
2 changes: 1 addition & 1 deletion luminex/src/org/labkey/luminex/LuminexModule.java
Original file line number Diff line number Diff line change
Expand Up @@ -45,7 +45,7 @@ public String getName()
@Override
public @Nullable Double getSchemaVersion()
{
return 25.000;
return 25.001;
}

@Override
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
-- This index overlaps with pk_proteinquantitation
DROP INDEX ms2.ix_proteinquantitation_proteingroupid;
-- This index overlaps with pk_ms2peptidememberships
DROP INDEX ms2.ix_peptidemembership_proteingroupid;
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
-- This index overlaps with PK_ProteinQuantitation
DROP INDEX IX_ProteinQuantitation_ProteinGroupId ON ms2.ProteinQuantitation;
-- This index overlaps with pk_ms2peptidememberships
DROP INDEX IX_Peptidemembership_ProteingroupId ON ms2.PeptideMemberships;
2 changes: 1 addition & 1 deletion ms2/src/org/labkey/ms2/MS2Module.java
Original file line number Diff line number Diff line change
Expand Up @@ -117,7 +117,7 @@ public String getName()
@Override
public @Nullable Double getSchemaVersion()
{
return 25.000;
return 25.001;
}

@Override
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
-- This index overlaps with ix_annotations_annotident
DROP INDEX prot.ix_annotations_identid;
-- This index overlaps with uq_customannotationset
DROP INDEX prot.ix_customannotationset_container;
-- This index overlaps with ix_gographpath_term1_2_id and IX_GoGraphPath_t1_distance
DROP INDEX prot.ix_gographpath_term1id;
-- This index overlaps with uq_goterm2term_1_2_r
DROP INDEX prot.ix_goterm2term_term1_2_id;
-- This index overlaps with uq_goterm2term_1_2_r
DROP INDEX prot.ix_goterm2term_term1id;
-- This index overlaps with uq_gotermsynonym_termid_termsynonym
DROP INDEX prot.ix_gotermsynonym_termid;

-- Create functions to drop & create all GO indexes. This helps with load performance.
CREATE OR REPLACE FUNCTION prot.create_go_indexes() RETURNS void AS $$
BEGIN
ALTER TABLE prot.goterm ADD CONSTRAINT pk_goterm PRIMARY KEY (id);
CREATE INDEX IX_GoTerm_Name ON prot.GoTerm(name);
CREATE INDEX IX_GoTerm_TermType ON prot.GoTerm(termtype);
CREATE UNIQUE INDEX UQ_GoTerm_Acc ON prot.GoTerm(acc);

ALTER TABLE prot.goterm2term ADD CONSTRAINT pk_goterm2term PRIMARY KEY (id);
CREATE INDEX IX_GoTerm2Term_term2Id ON prot.GoTerm2Term(term2Id);
CREATE INDEX IX_GoTerm2Term_relationshipTypeId ON prot.GoTerm2Term(relationshipTypeId);
CREATE UNIQUE INDEX UQ_GoTerm2Term_1_2_R ON prot.GoTerm2Term(term1Id,term2Id,relationshipTypeId);

ALTER TABLE prot.gographpath ADD CONSTRAINT pk_gographpath PRIMARY KEY (id);
CREATE INDEX IX_GoGraphPath_term2Id ON prot.GoGraphPath(term2Id);
CREATE INDEX IX_GoGraphPath_term1_2_Id ON prot.GoGraphPath(term1Id,term2Id);
CREATE INDEX IX_GoGraphPath_t1_distance ON prot.GoGraphPath(term1Id,distance);

CREATE INDEX IX_GoTermDefinition_dbXrefId ON prot.GoTermDefinition(dbXrefId);
CREATE UNIQUE INDEX UQ_GoTermDefinition_termId ON prot.GoTermDefinition(termId);

CREATE INDEX IX_GoTermSynonym_SynonymTypeId ON prot.GoTermSynonym(synonymTypeId);
CREATE INDEX IX_GoTermSynonym_termSynonym ON prot.GoTermSynonym(termSynonym);
CREATE UNIQUE INDEX UQ_GoTermSynonym_termId_termSynonym ON prot.GoTermSynonym(termId,termSynonym);
END;
$$ LANGUAGE plpgsql;

-- Use fn_dropifexists to increase reliability
CREATE OR REPLACE FUNCTION prot.drop_go_indexes() RETURNS void AS $$
BEGIN
PERFORM core.fn_dropifexists('goterm', 'prot', 'Constraint', 'pk_goterm');
PERFORM core.fn_dropifexists('goterm', 'prot', 'Index', 'IX_GoTerm_Name');
PERFORM core.fn_dropifexists('goterm', 'prot', 'Index', 'IX_GoTerm_TermType');
PERFORM core.fn_dropifexists('goterm', 'prot', 'Index', 'UQ_GoTerm_Acc');

PERFORM core.fn_dropifexists('goterm2term', 'prot', 'Constraint', 'pk_goterm2term');
PERFORM core.fn_dropifexists('goterm2term', 'prot', 'Index', 'IX_GoTerm2Term_term2Id');
PERFORM core.fn_dropifexists('goterm2term', 'prot', 'Index', 'IX_GoTerm2Term_relationshipTypeId');
PERFORM core.fn_dropifexists('goterm2term', 'prot', 'Index', 'UQ_GoTerm2Term_1_2_R');

PERFORM core.fn_dropifexists('gographpath', 'prot', 'Constraint', 'pk_gographpath');
PERFORM core.fn_dropifexists('gographpath', 'prot', 'Index', 'IX_GoGraphPath_term2Id');
PERFORM core.fn_dropifexists('gographpath', 'prot', 'Index', 'IX_GoGraphPath_term1_2_Id');
PERFORM core.fn_dropifexists('gographpath', 'prot', 'Index', 'IX_GoGraphPath_t1_distance');

PERFORM core.fn_dropifexists('gotermdefinition', 'prot', 'Index', 'IX_GoTermDefinition_dbXrefId');
PERFORM core.fn_dropifexists('gotermdefinition', 'prot', 'Index', 'UQ_GoTermDefinition_termId');

PERFORM core.fn_dropifexists('gotermsynonym', 'prot', 'Index', 'IX_GoTermSynonym_SynonymTypeId');
PERFORM core.fn_dropifexists('gotermsynonym', 'prot', 'Index', 'IX_GoTermSynonym_termSynonym');
PERFORM core.fn_dropifexists('gotermsynonym', 'prot', 'Index', 'UQ_GoTermSynonym_termId_termSynonym');
END;
$$ LANGUAGE plpgsql;
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
-- This index overlaps with IX_Annotations_AnnotIdent
DROP INDEX IX_Annotations_IdentId ON prot.Annotations;
-- This index overlaps with IX_GoGraphPath_term1_2_Id and IX_GoGraphPath_t1_distance
DROP INDEX IX_GoGraphPath_term1Id ON prot.GoGraphPath;
-- This index overlaps with UQ_CustomAnnotationSet
DROP INDEX IX_CustomAnnotationSet_Container ON prot.CustomAnnotationSet;
-- This index overlaps with UQ_GoTerm2Term_1_2_R
DROP INDEX IX_GoTerm2Term_term1Id ON prot.GoTerm2Term;
-- This index overlaps with UQ_GoTerm2Term_1_2_R
DROP INDEX IX_GoTerm2Term_term1_2_Id ON prot.GoTerm2Term;
-- This index overlaps with UQ_GoTermSynonym_termId_termSynonym
DROP INDEX IX_GoTermSynonym_TermId ON prot.GoTermSynonym;

GO

ALTER PROCEDURE prot.create_go_indexes AS
BEGIN
ALTER TABLE prot.goterm ADD CONSTRAINT pk_goterm PRIMARY KEY (id)
CREATE INDEX IX_GoTerm_Name ON prot.GoTerm(name)
CREATE INDEX IX_GoTerm_TermType ON prot.GoTerm(termtype)
CREATE UNIQUE INDEX UQ_GoTerm_Acc ON prot.GoTerm(acc)

ALTER TABLE prot.goterm2term ADD CONSTRAINT pk_goterm2term PRIMARY KEY (id)
CREATE INDEX IX_GoTerm2Term_term2Id ON prot.GoTerm2Term(term2Id)
CREATE INDEX IX_GoTerm2Term_relationshipTypeId ON prot.GoTerm2Term(relationshipTypeId)
CREATE UNIQUE INDEX UQ_GoTerm2Term_1_2_R ON prot.GoTerm2Term(term1Id,term2Id,relationshipTypeId)

ALTER TABLE prot.gographpath ADD CONSTRAINT pk_gographpath PRIMARY KEY (id)
CREATE INDEX IX_GoGraphPath_term2Id ON prot.GoGraphPath(term2Id)
CREATE INDEX IX_GoGraphPath_term1_2_Id ON prot.GoGraphPath(term1Id,term2Id)
CREATE INDEX IX_GoGraphPath_t1_distance ON prot.GoGraphPath(term1Id,distance)

CREATE INDEX IX_GoTermDefinition_dbXrefId ON prot.GoTermDefinition(dbXrefId)
CREATE UNIQUE INDEX UQ_GoTermDefinition_termId ON prot.GoTermDefinition(termId)

CREATE INDEX IX_GoTermSynonym_SynonymTypeId ON prot.GoTermSynonym(synonymTypeId)
CREATE INDEX IX_GoTermSynonym_termSynonym ON prot.GoTermSynonym(termSynonym)
CREATE UNIQUE INDEX UQ_GoTermSynonym_termId_termSynonym ON prot.GoTermSynonym(termId,termSynonym);
END

GO

ALTER PROCEDURE prot.drop_go_indexes AS
BEGIN
EXEC core.fn_dropifexists 'goterm', 'prot', 'Constraint', 'PK_GoTerm'
EXEC core.fn_dropifexists 'goterm', 'prot', 'Index', 'IX_GoTerm_Name'
EXEC core.fn_dropifexists 'goterm', 'prot', 'Index', 'IX_GoTerm_TermType'
EXEC core.fn_dropifexists 'goterm', 'prot', 'Index', 'UQ_GoTerm_Acc'

EXEC core.fn_dropifexists 'goterm2term', 'prot', 'Constraint', 'PK_GoTerm2Term'
EXEC core.fn_dropifexists 'goterm2term', 'prot', 'Index', 'IX_GoTerm2Term_term2Id'
EXEC core.fn_dropifexists 'goterm2term', 'prot', 'Index', 'IX_GoTerm2Term_relationshipTypeId'
EXEC core.fn_dropifexists 'goterm2term', 'prot', 'Index', 'UQ_GoTerm2Term_1_2_R'

EXEC core.fn_dropifexists 'gographpath', 'prot', 'Constraint', 'PK_GoGraphPath'
EXEC core.fn_dropifexists 'gographpath', 'prot', 'Index', 'IX_GoGraphPath_term2Id'
EXEC core.fn_dropifexists 'gographpath', 'prot', 'Index', 'IX_GoGraphPath_term1_2_Id'
EXEC core.fn_dropifexists 'gographpath', 'prot', 'Index', 'IX_GoGraphPath_t1_distance'

EXEC core.fn_dropifexists 'gotermdefinition', 'prot', 'Index', 'IX_GoTermDefinition_dbXrefId'
EXEC core.fn_dropifexists 'gotermdefinition', 'prot', 'Index', 'UQ_GoTermDefinition_termId'

EXEC core.fn_dropifexists 'gotermsynonym', 'prot', 'Index', 'IX_GoTermSynonym_SynonymTypeId'
EXEC core.fn_dropifexists 'gotermsynonym', 'prot', 'Index', 'IX_GoTermSynonym_termSynonym'
EXEC core.fn_dropifexists 'gotermsynonym', 'prot', 'Index', 'UQ_GoTermSynonym_termId_termSynonym';
END

GO
2 changes: 1 addition & 1 deletion protein/src/org/labkey/protein/ProteinModule.java
Original file line number Diff line number Diff line change
Expand Up @@ -68,7 +68,7 @@ public String getName()
@Override
public @Nullable Double getSchemaVersion()
{
return 25.002;
return 25.003;
}

@Override
Expand Down