Skip to content

Issue 53446: misconfigured plate assay design, plate validation query optimization #6839

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

Merged
merged 2 commits into from
Jul 14, 2025
Merged
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
55 changes: 33 additions & 22 deletions assay/src/org/labkey/assay/plate/PlateManager.java
Original file line number Diff line number Diff line change
Expand Up @@ -609,29 +609,39 @@ private int getRunCountUsingPlateInResults(@NotNull Container c, @NotNull User u

// get the runIds for each protocol, query against its assay results table
List<SQLFragment> fragments = new ArrayList<>();
Set<FieldKey> requiredFields = Set.of(FieldKey.fromParts("DataId"), FieldKey.fromParts("Plate"));

protocolLoop:
for (ExpProtocol protocol : protocols)
{
AssayProtocolSchema assayProtocolSchema = provider.createProtocolSchema(user, protocol.getContainer(), protocol, null);
TableInfo assayDataTable = assayProtocolSchema.createDataTable(ContainerFilter.getUnsafeEverythingFilter(), false);
if (assayDataTable != null)
{
ColumnInfo dataIdCol = assayDataTable.getColumn("DataId");
if (dataIdCol != null)
// Issue 53446: A misconfigured assay design could be missing required fields.
// This is not expected. Don't let that stop the run counting but do log an error with more context.
for (FieldKey requiredFieldKey : requiredFields)
{
SQLFragment subSelectSql = new SQLFragment("SELECT DISTINCT AD.DataId FROM ")
.append(assayDataTable.getFromSQL("AD", Set.of(FieldKey.fromParts("DataId"), FieldKey.fromParts("Plate"))))
.append(" WHERE AD.Plate = ?")
.add(plate.getRowId());

SQLFragment sql = new SQLFragment("SELECT COUNT(DISTINCT D.RunId) AS RunCount FROM\n")
.append(ExperimentService.get().getTinfoData(), "D")
.append(" INNER JOIN ")
.append(ExperimentService.get().getTinfoExperimentRun(), "R")
.append(" ON D.RunId = R.RowId\n")
.append(" WHERE R.ReplacedByRunId IS NULL AND D.RowId IN (").append(subSelectSql).append(")\n");

fragments.add(sql);
if (assayDataTable.getColumn(requiredFieldKey) == null)
{
LOG.error("Required field \"{}\" not found in plate-based assay results domain for protocol \"{}\" in {}.", requiredFieldKey.getName(), protocol.getName(), protocol.getContainer().getPath());
continue protocolLoop;
}
}

SQLFragment subSelectSql = new SQLFragment("SELECT DISTINCT AD.DataId FROM ")
.append(assayDataTable.getFromSQL("AD", requiredFields))
.append(" WHERE AD.Plate = ?")
.add(plate.getRowId());

SQLFragment sql = new SQLFragment("SELECT COUNT(DISTINCT D.RunId) AS RunCount FROM\n")
.append(ExperimentService.get().getTinfoData(), "D")
.append(" INNER JOIN ")
.append(ExperimentService.get().getTinfoExperimentRun(), "R")
.append(" ON D.RunId = R.RowId\n")
.append(" WHERE R.ReplacedByRunId IS NULL AND D.RowId IN (").append(subSelectSql).append(")\n");

fragments.add(sql);
}
}

Expand Down Expand Up @@ -3387,17 +3397,18 @@ public void validatePrimaryPlateSetUniqueSamples(Set<Integer> wellRowIds, BatchV
TableInfo wellTable = dbSchema.getTableInfoWell();

// Determines the set of primary plate sets that are being touched from the collection of well rowIds
SQLFragment primaryPlateSetsFromWellRowIdsSQL = new SQLFragment("SELECT PS.RowId FROM ").append(wellTable, "W")
// From the set of primary plate sets determine if any sample exists in more than one well within the entire plate set
SQLFragment nonUniqueSamplesPerPrimaryPlateSetSQL = new SQLFragment("WITH PlateSetFilter AS (")
.append("SELECT DISTINCT PS.RowId FROM ").append(wellTable, "W")
.append(" INNER JOIN ").append(plateTable, "P").append(" ON P.RowId = W.PlateId")
.append(" INNER JOIN ").append(plateSetTable, "PS").append(" ON PS.RowId = P.PlateSet")
.append(" WHERE PS.Type = ?").add("primary").append(" AND W.RowId ").appendInClause(wellRowIds, dialect);

// From the set of primary plate sets determine if any sample exists in more than one well within the entire plate set
SQLFragment nonUniqueSamplesPerPrimaryPlateSetSQL = new SQLFragment("SELECT PS.Name AS PlateSetName, W.SampleId FROM ")
.append(wellTable, "W")
.append(" WHERE PS.Type = ?").add("primary").append(" AND W.RowId ").appendInClause(wellRowIds, dialect)
.append(" )")
.append(" SELECT PS.Name AS PlateSetName, W.SampleId FROM ").append(wellTable, "W")
.append(" INNER JOIN ").append(plateTable, "P").append(" ON P.RowId = W.PlateId")
.append(" INNER JOIN ").append(plateSetTable, "PS").append(" ON PS.RowId = P.PlateSet")
.append(" WHERE W.SampleId IS NOT NULL AND PS.RowId IN (").append(primaryPlateSetsFromWellRowIdsSQL).append(")")
.append(" INNER JOIN PlateSetFilter PSF ON PSF.RowId = PS.RowId")
.append(" WHERE W.SampleId IS NOT NULL")
.append(" GROUP BY PS.RowId, W.SampleId, PS.Name HAVING COUNT(W.SampleId) > 1");

var duplicates = new SqlSelector(dbSchema.getSchema(), nonUniqueSamplesPerPrimaryPlateSetSQL).getMapCollection();
Expand Down