Typically, you would leave the query unfiltered and then just filter the report when it opens. So I would recommend that you alter your qryComparisonSheet by adding the pkDisciplineID field to the SELECT clause and removing the (tblDisciplines.SubDiscipline)="TANK") AND from the WHERE clause (see red highlighted areas below)
SELECT tblWorkItems.WorkItemNumber, tblWorkItems.WorkItemTitle, tblWorkRequired.MAKEBUYSUB, tblWorkRequired.HAVETOSUB, tblWorkRequired.fkDisciplineID, tblDisciplines.SubDiscipline, tblSubcontractorQuotes.fkCompanyID, tblSubcontractors.CompanyName, tblSubcontractorQuotes.fkQuoteStatusID, tblQuoteStatus.txtQuoteStatus, tblSubcontractorQuotes.ManHours, tblSubcontractorQuotes.Material, tblSubcontractorQuotes.Total, tblSubcontractorQuotes.SubExceptions, tblSubcontractorQuotes.SubComments, tblSubcontractorQuotes.fkAwardJustificationID, tblAwardJustification.txtAwardJustification, tblWorkRequired.WorkRequired, tblWorkItems.fkPackageTypeID, tblPackageTypes.txtPackageType, tblSubcontractors.fkContractTypeID, tblContractType.txtContractType, tblDisciplines.pkDisciplineID
FROM (tblWorkItemStatus INNER JOIN (tblPackageTypes INNER JOIN (tblAllocationAfterPMO INNER JOIN tblWorkItems ON tblAllocationAfterPMO.pkAllocationID = tblWorkItems.fkAllocationID) ON tblPackageTypes.pkPackageTypeID = tblWorkItems.fkPackageTypeID) ON tblWorkItemStatus.pkWorkItemStatusID = tblWorkItems.fkWorkItemStatusID) INNER JOIN (((tblDisciplines INNER JOIN (tblContractType INNER JOIN tblSubcontractors ON tblContractType.pkContractTypeID = tblSubcontractors.fkContractTypeID) ON tblDisciplines.pkDisciplineID = tblSubcontractors.fkDisciplineID) INNER JOIN tblWorkRequired ON tblDisciplines.pkDisciplineID = tblWorkRequired.fkDisciplineID) INNER JOIN (tblQuoteStatus INNER JOIN (tblAwardJustification INNER JOIN tblSubcontractorQuotes ON tblAwardJustification.pkAwardJustificationID = tblSubcontractorQuotes.fkAwardJustificationID) ON tblQuoteStatus.pkQuoteStatusID = tblSubcontractorQuotes.fkQuoteStatusID) ON (tblWorkRequired.pkWorkReqID = tblSubcontractorQuotes.fkWorkRequiredID) AND (tblSubcontractors.pkCompanyID = tblSubcontractorQuotes.fkCompanyID)) ON tblWorkItems.pkWorkItemNumberID = tblWorkRequired.fkWorkItemNumberID
WHERE (((tblDisciplines.SubDiscipline)="TANK") AND ((tblWorkItemStatus.WorkItemStatus)="ACTIVE"))
ORDER BY tblWorkItems.WorkItemNumber;
I would then create an unbound form and add a combo box based on tblDisciplines. Make the bound field of the combo box pkDisciplineID. Now in either the after update event of the combo box or a button (your choice), you will want to add code to open the report and filter it with the combo box selection. The code would look something like this to open the report in report preview mode:
DoCmd.OpenReport "rptComparisionSheet", acViewPreview, , "pkDisciplineID=" & Me.cboDiscipline, acNormal