GW Web_SearchApplications2 fix

This commit is contained in:
Dobromir Popov
2025-08-20 22:15:12 +03:00
parent 3993248a76
commit 61d0f986b1

View File

@@ -472,6 +472,130 @@ BEGIN
FROM #tmpResults2 t
LEFT JOIN LatestMsgDates l ON l.ApplicationId = t.ApplicationId
-- Dossier set for current results
CREATE TABLE #tmpDossiers (
DossierId INT PRIMARY KEY
)
INSERT INTO #tmpDossiers (DossierId)
SELECT DISTINCT d.Id
FROM #tmpResults2 r
JOIN Dossier d ON d.ApplicantProfileId = r.ApplicantProfileId AND d.CompanySetId = @companySetId
-- Aggregate comments per dossier and compute latest comment fields
CREATE TABLE #tmpDossierCommentAgg (
DossierId INT PRIMARY KEY,
CommentsCount INT NOT NULL,
LastComment NVARCHAR(MAX) NULL,
LastCommentTemplateId INT NULL
)
;WITH LastC AS (
SELECT c.DossierId,
c.Comment,
c.CompanySetApplicantCommentTemplateId,
ROW_NUMBER() OVER (PARTITION BY c.DossierId ORDER BY c.LastChangeDate DESC) AS rn
FROM CompanySetApplicantComment c WITH(NOLOCK)
WHERE c.DossierId IN (SELECT DossierId FROM #tmpDossiers)
)
INSERT INTO #tmpDossierCommentAgg (DossierId, CommentsCount, LastComment, LastCommentTemplateId)
SELECT d.DossierId,
ISNULL(cnt.Cnt, 0) AS CommentsCount,
lc.Comment AS LastComment,
lc.CompanySetApplicantCommentTemplateId AS LastCommentTemplateId
FROM #tmpDossiers d
LEFT JOIN (
SELECT DossierId, COUNT(*) AS Cnt
FROM CompanySetApplicantComment WITH(NOLOCK)
WHERE DossierId IN (SELECT DossierId FROM #tmpDossiers)
GROUP BY DossierId
) cnt ON cnt.DossierId = d.DossierId
LEFT JOIN LastC lc ON lc.DossierId = d.DossierId AND lc.rn = 1
-- Keys for rating lookup per dossier and profession
CREATE TABLE #tmpRatingKeys (
DossierId INT NOT NULL,
ProfessionId INT NOT NULL,
PRIMARY KEY (DossierId, ProfessionId)
)
INSERT INTO #tmpRatingKeys (DossierId, ProfessionId)
SELECT DISTINCT d.Id AS DossierId,
clpro.ProfessionId
FROM #tmpResults2 r
JOIN Apprenticeship apr ON apr.Id = r.ApprenticeshipId
JOIN CompanyLocationProfession clpro ON clpro.Id = apr.CompanyLocationProfessionId
JOIN Dossier d ON d.ApplicantProfileId = r.ApplicantProfileId AND d.CompanySetId = @companySetId
CREATE TABLE #tmpRating (
DossierId INT NOT NULL,
ProfessionId INT NOT NULL,
RatingTypeResult NVARCHAR(50) NULL,
PRIMARY KEY (DossierId, ProfessionId)
)
INSERT INTO #tmpRating (DossierId, ProfessionId, RatingTypeResult)
SELECT k.DossierId,
k.ProfessionId,
MIN(aprt.ShortCode) AS RatingTypeResult
FROM ApplicantProfessionRating apr
JOIN ApplicantProfessionRatingType aprt ON aprt.Id = apr.ApplicantProfessionRatingTypeId
JOIN #tmpRatingKeys k ON k.DossierId = apr.DossierId AND k.ProfessionId = apr.ProfessionId
GROUP BY k.DossierId, k.ProfessionId
-- Precompute effective CompanyPerson for doc-change flag and related ApplicationIds
CREATE TABLE #tmpEffCompanyPerson (
ApprenticeshipId INT NOT NULL,
ApplicantProfessionProfileId INT NULL,
EffectiveCompanyPersonId INT NULL,
PRIMARY KEY (ApprenticeshipId, ApplicantProfessionProfileId)
)
INSERT INTO #tmpEffCompanyPerson (ApprenticeshipId, ApplicantProfessionProfileId, EffectiveCompanyPersonId)
SELECT DISTINCT t.ApprenticeshipId,
t.ApplicantProfessionProfileId,
COALESCE(t.CompanyPersonId, app.CompanyPersonId) AS EffectiveCompanyPersonId
FROM #tmpResults2 t
LEFT JOIN Apprenticeship app ON app.Id = t.ApprenticeshipId
WHERE t.ApprenticeshipId IS NOT NULL
CREATE TABLE #tmpResAppIds (
ApprenticeshipId INT NOT NULL,
ApplicantProfessionProfileId INT NULL,
EffectiveCompanyPersonId INT NULL,
ApplicationId INT NOT NULL,
PRIMARY KEY (ApprenticeshipId, ApplicantProfessionProfileId, EffectiveCompanyPersonId, ApplicationId)
)
INSERT INTO #tmpResAppIds (ApprenticeshipId, ApplicantProfessionProfileId, EffectiveCompanyPersonId, ApplicationId)
SELECT rk.ApprenticeshipId,
rk.ApplicantProfessionProfileId,
rk.EffectiveCompanyPersonId,
a.Id AS ApplicationId
FROM [Application] a
JOIN #tmpEffCompanyPerson rk
ON rk.ApprenticeshipId = a.ApprenticeshipId
AND ISNULL(rk.ApplicantProfessionProfileId, -1) = ISNULL(a.ApplicantProfessionProfileId, -1)
WHERE (@IncludeInactiveApplications = 1 OR a.IsActive = 1)
CREATE TABLE #tmpDocNotifEnabled (
ApprenticeshipId INT NOT NULL,
ApplicantProfessionProfileId INT NULL,
EffectiveCompanyPersonId INT NULL,
DocEnabled BIT NOT NULL,
PRIMARY KEY (ApprenticeshipId, ApplicantProfessionProfileId, EffectiveCompanyPersonId)
)
INSERT INTO #tmpDocNotifEnabled (ApprenticeshipId, ApplicantProfessionProfileId, EffectiveCompanyPersonId, DocEnabled)
SELECT ra.ApprenticeshipId,
ra.ApplicantProfessionProfileId,
ra.EffectiveCompanyPersonId,
CAST(1 AS BIT) AS DocEnabled
FROM CompanySetApplicationRelation csar WITH(NOLOCK)
JOIN #tmpResAppIds ra ON ra.ApplicationId = csar.ApplicationId
WHERE csar.EmailNotificationWhenDocumentsChange = 1 AND csar.CompanyPersonId = ra.EffectiveCompanyPersonId
GROUP BY ra.ApprenticeshipId, ra.ApplicantProfessionProfileId, ra.EffectiveCompanyPersonId
----------------------------------------------------------------------
------ 3. SELECT RESULT, APPLY PAGING & ORDERING ---------
----------------------------------------------------------------------
@@ -510,18 +634,11 @@ BEGIN
cpn.Salutation AS Salutation,
COALESCE(cpn.CompanyProfileId, cpnapp.CompanyProfileId) AS CompanyProfileId,
cpn.Email AS CompanyPersonEmail,
(SELECT TOP 1 proT.Name
FROM ProfessionTranslation proT
WHERE prot.Language = @Language
AND prot.ProfessionId = clpro.ProfessionId
) AS Profession,
(SELECT TOP 1 aprt.ShortCode
FROM ApplicantProfessionRatingType aprt
JOIN ApplicantProfessionRating apr ON apr.ApplicantProfessionRatingTypeId = aprt.Id
WHERE apr.DossierId = d.Id AND apr.ProfessionId = clpro.ProfessionId) AS RatingTypeResult,
(SELECT COUNT(Id) FROM CompanySetApplicantComment WHERE DossierId = d.Id) AS CommentsCount,
(SELECT TOP 1 Comment FROM CompanySetApplicantComment WHERE DossierId = d.Id ORDER BY LastChangeDate DESC) AS LastComment,
(SELECT TOP 1 CompanySetApplicantCommentTemplateId FROM CompanySetApplicantComment WHERE DossierId = d.Id ORDER BY LastChangeDate DESC) AS CommentTemplateId,
pt.Name AS Profession,
rt.RatingTypeResult,
dc.CommentsCount,
dc.LastComment,
dc.LastCommentTemplateId AS CommentTemplateId,
res.ApplicationId AS ApplicationId,
clprof.PlaceName AS CompanyLocationProfilePlaceName,
clprof.Street AS CompanyLocationProfileStreet,
@@ -532,21 +649,8 @@ BEGIN
caas.[Description] AS WorkflowStateDescription,
res.AverageCompanySetCompanyRatings AS CompanySetRatingAverage,
res.SocialSecurityNumber,
CASE WHEN EXISTS (
SELECT * FROM CompanySetApplicationRelation csar
WHERE csar.EmailNotificationWhenDocumentsChange = @true
AND csar.ApplicationId IN
(SELECT Id
FROM [Application] a
WHERE a.ApprenticeshipId = res.ApprenticeshipId
AND (@IncludeInactiveApplications = 1 OR a.IsActive = @true)
AND a.ApplicantProfessionProfileId = res.ApplicantProfessionProfileId) -- GAT-3420 must find record for particular ApplicantProfessionProfileId from res table, not only for ApplicationId
AND csar.CompanyPersonId = COALESCE(res.CompanyPersonId, (SELECT a.CompanyPersonId FROM Apprenticeship a WHERE a.Id = res.ApprenticeshipId))
) THEN @true ELSE @false END AS DocChangeNotificationEnabled,
CASE WHEN clprof.Id = (SELECT HeadquarterCompanyLocationProfileId
FROM CompanyProfile c
WHERE c.Id = clprof.CompanyProfileId)
THEN @true ELSE @false END AS IsHeadquarterCompanyLocationProfile,
CASE WHEN dne.DocEnabled = 1 THEN @true ELSE @false END AS DocChangeNotificationEnabled,
CASE WHEN clprof.Id = cp.HeadquarterCompanyLocationProfileId THEN @true ELSE @false END AS IsHeadquarterCompanyLocationProfile,
COALESCE(res.UnreadMsgCount, 0) AS UnreadMsgCount,
COALESCE(res.UnansweredMsgCount, 0) AS UnansweredMsgCount,
@false AS IsCreatedByCompany,
@@ -560,8 +664,7 @@ BEGIN
res.IsActiveApplication,
clpro.ExternalReferenceId,
apro.CompletionPercentage AS CompletionPercentage,
(SELECT ColorCode FROM CompanyApplicantAvailableStateColor
WHERE Id = caas.ColorId) AS ColorCode,
caasc.ColorCode AS ColorCode,
res.LastSentMessageDate,
res.LastReceivedMessageDate,
clprof.CompanyAppendix AS CompanyLocationProfileAppendix
@@ -574,6 +677,13 @@ BEGIN
LEFT JOIN CompanyLocationProfession clpro ON clpro.Id = apr.CompanyLocationProfessionId
LEFT JOIN CompanyLocationProfile clprof ON clprof.Id = apr.CompanyLocationProfileId
LEFT JOIN CompanyApplicantAvailableState caas ON caas.Id = res.CompanyApplicantAvailableStateId
LEFT JOIN CompanyProfile cp ON cp.Id = clprof.CompanyProfileId
LEFT JOIN ProfessionTranslation pt ON pt.ProfessionId = clpro.ProfessionId AND pt.Language = @Language
LEFT JOIN #tmpDossierCommentAgg dc ON dc.DossierId = d.Id
LEFT JOIN #tmpRating rt ON rt.DossierId = d.Id AND rt.ProfessionId = clpro.ProfessionId
LEFT JOIN #tmpEffCompanyPerson ecp ON ecp.ApprenticeshipId = res.ApprenticeshipId AND ISNULL(ecp.ApplicantProfessionProfileId, -1) = ISNULL(res.ApplicantProfessionProfileId, -1)
LEFT JOIN #tmpDocNotifEnabled dne ON dne.ApprenticeshipId = res.ApprenticeshipId AND ISNULL(dne.ApplicantProfessionProfileId, -1) = ISNULL(res.ApplicantProfessionProfileId, -1) AND dne.EffectiveCompanyPersonId = ecp.EffectiveCompanyPersonId
LEFT JOIN CompanyApplicantAvailableStateColor caasc ON caasc.Id = caas.ColorId
WHERE
-- Anonymous Applicants
((@HideAnonymousApplicant IS NULL OR @HideAnonymousApplicant = 0)