From 88ae595613dd99317f9f5e8a0a0853ac3e630a87 Mon Sep 17 00:00:00 2001 From: Chris Burr Date: Thu, 19 Feb 2026 14:10:25 +0100 Subject: [PATCH 1/2] fix: Add composite (TQId, Value) indices to TaskQueue multi-value tables The TaskIndex on multi-value tables (tq_TQTo*) previously only covered TQId, requiring a separate lookup for the Value column. Adding Value to the composite index makes it a covering index for all subqueries that filter on both columns, improving query performance significantly. --- src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py b/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py index 96f664ec180..424b11ae603 100755 --- a/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py +++ b/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py @@ -145,7 +145,7 @@ def __initializeDB(self): self.__tablesDesc[tableName] = { "Fields": {"TQId": "INTEGER(11) UNSIGNED NOT NULL", "Value": "VARCHAR(64) NOT NULL"}, "PrimaryKey": ["TQId", "Value"], - "Indexes": {"TaskIndex": ["TQId"], f"{multiField}Index": ["Value"]}, + "Indexes": {"TaskIndex": ["TQId", "Value"], f"{multiField}Index": ["Value"]}, "ForeignKeys": {"TQId": "tq_TaskQueues.TQId"}, } From fe366e0e6c30d18e72120f53bff970b3d8fb194d Mon Sep 17 00:00:00 2001 From: Chris Burr Date: Thu, 19 Feb 2026 14:13:05 +0100 Subject: [PATCH 2/2] fix: Refactor COUNT subqueries to EXISTS in TaskQueueDB Replace COUNT-based subqueries with EXISTS/NOT EXISTS patterns in __generateTQMatchSQL, __generateTagSQLSubCond, and __generateTQFindSQL. EXISTS short-circuits on the first matching row instead of scanning all rows, which combined with the composite (TQId, Value) indices reduces matching query time from ~30ms to ~3ms on production. --- .../DB/TaskQueueDB.py | 47 ++++++++----------- 1 file changed, 19 insertions(+), 28 deletions(-) diff --git a/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py b/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py index 424b11ae603..18282c0a962 100755 --- a/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py +++ b/src/DIRAC/WorkloadManagementSystem/DB/TaskQueueDB.py @@ -508,24 +508,21 @@ def __generateTQFindSQL( for field in multiValueDefFields: tableName = f"`tq_TQTo{field}`" if field in tqDefDict and tqDefDict[field]: - firstQuery = ( - "SELECT COUNT(%s.Value) \ - FROM %s \ - WHERE %s.TQId = `tq_TaskQueues`.TQId" - % (tableName, tableName, tableName) - ) - grouping = f"GROUP BY {tableName}.TQId" valuesList = List.uniqueElements([value.strip() for value in tqDefDict[field] if value.strip()]) numValues = len(valuesList) - secondQuery = "{} AND {}.Value in ({})".format( - firstQuery, - tableName, - ",".join(["%s" % str(value) for value in valuesList]), + valuesStr = ",".join([f"{str(value)}" for value in valuesList]) + # Exact count match: TQ must have exactly numValues entries + sqlCondList.append( + f"( SELECT COUNT({tableName}.Value) FROM {tableName} WHERE {tableName}.TQId = `tq_TaskQueues`.TQId ) = {numValues}" + ) + # All values must be in the TQ + sqlCondList.append( + f"NOT EXISTS ( SELECT 1 FROM {tableName} WHERE {tableName}.TQId = `tq_TaskQueues`.TQId AND {tableName}.Value NOT IN ({valuesStr}) )" ) - sqlCondList.append(f"{numValues} = ({firstQuery} {grouping})") - sqlCondList.append(f"{numValues} = ({secondQuery} {grouping})") else: - sqlCondList.append(f"`tq_TaskQueues`.TQId not in ( SELECT DISTINCT {tableName}.TQId from {tableName} )") + sqlCondList.append( + f"NOT EXISTS ( SELECT 1 FROM {tableName} WHERE {tableName}.TQId = `tq_TaskQueues`.TQId )" + ) # Handle RAM requirements matching hasRAMRequirements = "MinRAM" in tqDefDict or "MaxRAM" in tqDefDict @@ -859,14 +856,11 @@ def __generateTQMatchSQL(self, tqMatchDict, numQueuesToGet=1, negativeCond=None) # that the GridCE matches explicitly so the COUNT can not be 0. In this case we skip this # condition sqlMultiCondList.append( - "( SELECT COUNT(%s.Value) FROM %s WHERE %s.TQId = tq.TQId ) = 0" - % (fullTableN, fullTableN, fullTableN) + f"NOT EXISTS ( SELECT 1 FROM {fullTableN} WHERE {fullTableN}.TQId = tq.TQId )" ) sqlMultiCondList.append( self.__generateSQLSubCond( - "%%s IN ( SELECT %s.Value \ - FROM %s \ - WHERE %s.TQId = tq.TQId )" + "EXISTS ( SELECT 1 FROM %s WHERE %s.TQId = tq.TQId AND %s.Value = %%s )" % (fullTableN, fullTableN, fullTableN), tqMatchDict.get(field), ) @@ -878,9 +872,7 @@ def __generateTQMatchSQL(self, tqMatchDict, numQueuesToGet=1, negativeCond=None) if field in bannedJobMatchFields: fullTableN = f"`tq_TQToBanned{field}s`" csql = self.__generateSQLSubCond( - "%%s not in ( SELECT %s.Value \ - FROM %s \ - WHERE %s.TQId = tq.TQId )" + "NOT EXISTS ( SELECT 1 FROM %s WHERE %s.TQId = tq.TQId AND %s.Value = %%s )" % (fullTableN, fullTableN, fullTableN), tqMatchDict[field], boolOp="OR", @@ -920,7 +912,7 @@ def __generateTQMatchSQL(self, tqMatchDict, numQueuesToGet=1, negativeCond=None) sqlCondList.append( self.__generateSQLSubCond( - f"%%s not in ( SELECT {fullTableN}.Value FROM {fullTableN} WHERE {fullTableN}.TQId = tq.TQId )", + f"NOT EXISTS ( SELECT 1 FROM {fullTableN} WHERE {fullTableN}.TQId = tq.TQId AND {fullTableN}.Value = %%s )", b_fv, boolOp="OR", ) @@ -952,15 +944,14 @@ def __generateTagSQLSubCond(tableName, tagMatchList): """Generate SQL condition where ALL the specified multiValue requirements must be present in the matching resource list """ - sql1 = f"SELECT COUNT({tableName}.Value) FROM {tableName} WHERE {tableName}.TQId=tq.TQId" if not tagMatchList: - sql2 = sql1 + f" AND {tableName}.Value=''" + sql = f"NOT EXISTS ( SELECT 1 FROM {tableName} WHERE {tableName}.TQId=tq.TQId AND {tableName}.Value != '' )" else: if isinstance(tagMatchList, (list, tuple)): - sql2 = sql1 + f" AND {tableName}.Value in ( {','.join([('%s' % v) for v in tagMatchList])} )" + valuesStr = ",".join([f"{v}" for v in tagMatchList]) else: - sql2 = sql1 + f" AND {tableName}.Value={tagMatchList}" - sql = "( " + sql1 + " ) = (" + sql2 + " )" + valuesStr = tagMatchList + sql = f"NOT EXISTS ( SELECT 1 FROM {tableName} WHERE {tableName}.TQId=tq.TQId AND {tableName}.Value NOT IN ( {valuesStr} ) )" return sql @staticmethod