-- Stored procedure used on the /Company/Applications page IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[Web_SearchApplications2]') AND type in (N'P', N'PC')) BEGIN DROP PROCEDURE dbo.[Web_SearchApplications2] END SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[Web_SearchApplications2] -- Username of the CompanyPerson who's doing the search @UserName varchar(256), -- If we want only users who uploaded a profile picture @HasPortrait bit = NULL, -- If we want only users who are explicitely searching for an offer @IsSearchingAppr bit = NULL, -- If we want only users with whom the company has unread messages @IsMessageUnread bit = NULL, -- If we want only users with whom the company has unanswered messages @IsMessageUnanswered bit = NULL, -- If we want to hide anonymous Applicants @HideAnonymousApplicant bit = NULL, -- Filter for company locations @CompanyLocationsFilter varchar(MAX) = NULL, -- Combined string of CompanyLocationProfessionIds, like '49601|49602|49600|49599|49592|49598' -- Filter for ApprenticeshipTypes @ApprenticeshipTypesFilter varchar(MAX) = NULL, -- Combined string of ProfessionIds, like '1|2' -- Filter for company professions @MessageProfessionsFilter varchar(MAX) = NULL, -- Combined string of ProfessionIds, like '101080|102519' -- Filter for ABCD ratings, using the professions chosen @RatingProfessionsFilter varchar(MAX) = NULL, -- Combined string of ProfessionIds, like '101080|102519' -- Filter for ABCD ratings, using the rating itself @RatingFilter varchar(MAX) = NULL, -- Combined string of ApplicantProfessionRatingTypeId, like '1|2' -- Filters for Responsible Persons -- If true, we also want results where there is no RP defined -- If false, we don't want results where there is no RP @SearchResponsiblePersonIsNotDefine bit = 0, -- If set, we'll get the results where these specific CompanyPersons are RP @ApprenticeshipResponsiblePersonsFilter varchar(MAX) = NULL, -- Combined string of CompanyPersonIds, like '41099|41103|41100' -- Filter to limit the results to selected companies @CoCompaniesFilter varchar(MAX) = NULL, -- Combined string of CompanyProfileIds, like '181|1201' -- Filter for statuses @WorkflowStatesFilter varchar(MAX) = NULL, -- Combined string of CompanyApplicantStateAvailableIds, like '382|383' -- Filter for content of possible comments @CompanySetApplicantComment varchar(MAX) = NULL, -- Filters for Applicant's personal info -- Filter for first or last name of the Applicant @ApplicantNamesFilter varchar(MAX) = NULL, -- Filter for exact birth date of the Applicant @ApplicantBirthDate datetime = NULL, -- Filter for Applicant's language @SchoolLangFilter varchar(MAX) = NULL, -- Message filters -- Filter after and before dates for when the first message was sent between a Company and an Applicant, -- i.e. when an Application was created. @FirstMessageStartDate datetime = NULL, @FirstMessageEndDate datetime = NULL, -- Apprenticeship date filters -- Filter after and before dates for when the Apprenticeship is set to begin @ApprenticeshipStartDate datetime = NULL, @ApprenticeshipEndDate datetime = NULL, -- Filters for inactive / deleted data -- If we want to include Applications related to deleted Apprenticeships, company locations or professions @IncludeDeletedApprenticeship bit = 0, -- If we want to include Applicants not visible on gateway @IncludeInactiveApplicantsFilter bit = 0, -- If we want to include inactive Applications @IncludeInactiveApplications bit = 0, -- If we want to include Applicants created by the company @IncludeApplicantsCreatedByCompanyFilter bit = 0, -- Language to use for the translations, for example the profession names @Language varchar(2) = 'de', -- Sorting @SortColumn varchar(50) = NULL, @SortAsc bit = 1, -- Paging @CurrentPage int = 1, @PageSize int = 20, -- Company person roles allowed to see applicants @CompanyPersonRolesAllowedToSeeApplicants varchar(MAX) = NULL -- Combined string roles like '10|20' AS BEGIN LINENO 108 -- To give correct line number in error messages SET NOCOUNT ON; IF @UserName = '' OR NOT EXISTS(SELECT CompanyProfileId FROM CompanyPerson WHERE UserName = @UserName) RAISERROR(N'Parameter "@UserName" must not be empty, and must be a valid CompanyPerson username!', 4, 1); -- Internal variables DECLARE @true bit, @false bit, @FirstRow int, @companySetId int, @companyProfileId int, @companyPersonId int, @companyPersonRole int; SET @true = 1; SET @false = 0; SET @FirstRow = (@PageSize * (@CurrentPage - 1)) + 1; -- Get the CompanyPerson, CompanyProfile and CompanySet info via the logged in CompanyPerson SELECT @companyPersonId = t.Id, @companyPersonRole = t.Role, @companyProfileId = t.CompanyProfileId FROM (SELECT Id, Role, CompanyProfileId FROM CompanyPerson WHERE UserName = @UserName) t; SET @companySetId = (SELECT CompanySetId FROM CompanyProfile WHERE Id = @companyProfileId); -- See if the company has the CanShareDossiers specific permission DECLARE @SharingEnabled bit; SET @SharingEnabled = COALESCE((SELECT csp.CanShareDossiers FROM CompanySpecificPermissions csp WHERE csp.CompanyProfileId = @companyProfileId), 0) ---------------------------------------------------------------------- ------ 1. CENTRAL TABLE WITH AS MANY FILTERS AS POSSIBLE -------- ---------------------------------------------------------------------- -- This temp table is used as a first filter. We use the CompanyApplicantRelationsState table -- to get all interactions between the CompanySet and the Applicants. DECLARE @tmpCompanyApplicantRelationState TABLE ( CompanyProfileId INT, ApplicantProfileId INT, LastEditDossierDate DATETIME, DossierId INT, -- Optional, not always available ApplicationId INT, ApplicationCreateDate DATETIME, ApprenticeshipId INT, CompanyLocationProfessionId INT, CompanyLocationProfileId INT, CompanyPersonId INT NOT NULL DEFAULT 0, ApplicantProfessionProfileId INT, ProfessionId INT, CompanyApplicantStateAvailableId INT, IsActiveApplication BIT, -- Type of relation HasComment BIT, HasRating BIT, HasResponsiblePersonForAnyApplication BIT, -- For the CSV SocialSecurityNumber NVARCHAR(30)); INSERT INTO @tmpCompanyApplicantRelationState SELECT DISTINCT cars.CompanyProfileId, cars.ApplicantProfileId, cars.LastEditDossierDate, cars.DossierId, ap.Id AS ApplicationId, ap.CreatedDate AS ApplicationCreateDate, apr.Id AS ApprenticeshipId, clpro.Id AS CompanyLocationProfessionId, clocprof.Id AS CompanyLocationProfileId, ISNULL(csar.CompanyPersonId, 0) AS CompanyPersonId, -- TODO: is ISNULL still necessary? ap.ApplicantProfessionProfileId, clpro.ProfessionId, cas.CompanyApplicantStateAvailableId, ap.IsActive AS IsActiveApplication, cars.HasComment, cars.HasRating, cars.HasResponsiblePersonForAnyApplication, csaplntr.SocialSecurityNumber FROM CompanyApplicantRelationsState cars WITH(NOLOCK) INNER JOIN CompanyProfile cp WITH(NOLOCK) ON (cp.Id = cars.CompanyProfileId AND cp.CompanySetId = @companySetId) INNER JOIN CompanyPerson cpers WITH(NOLOCK) ON cpers.CompanyProfileId = cp.Id INNER JOIN ApplicantProfile apro WITH(NOLOCK) ON cars.ApplicantProfileId = apro.Id -- Here we try get some Application-related info, to apply some filters -- We use outer joins in case there is no Application (just a rating for example) LEFT OUTER JOIN DossierApplication da WITH(NOLOCK) ON cars.DossierId = da.DossierId LEFT OUTER JOIN Application ap WITH(NOLOCK) ON ap.Id = da.ApplicationId LEFT OUTER JOIN Apprenticeship apr WITH(NOLOCK) ON ap.ApprenticeshipId = apr.Id LEFT OUTER JOIN CompanyLocationProfession clpro WITH(NOLOCK) ON clpro.Id = apr.CompanyLocationProfessionId LEFT OUTER JOIN CompanyLocationProfile clocprof WITH(NOLOCK) ON clocprof.Id = apr.CompanyLocationProfileId LEFT OUTER JOIN CompanyApplicantState cas WITH(NOLOCK) ON cas.ApplicationId = ap.Id -- ABCD Ratings LEFT OUTER JOIN ApplicantProfessionRating aprofrate WITH (NOLOCK) ON (cars.ApplicantProfileId = aprofrate.ApplicantProfileId AND aprofrate.CompanyPersonId = cpers.Id) -- Comments LEFT OUTER JOIN CompanySetApplicantComment csacomm ON (csacomm.ApplicantProfileId = cars.ApplicantProfileId AND csacomm.CompanySetId = cp.CompanySetId) -- Responsible Person LEFT OUTER JOIN CompanySetApplicationRelation csar WITH(NOLOCK) ON csar.ApplicationId = ap.Id -- Messages LEFT OUTER JOIN Message msg WITH(NOLOCK) ON msg.ApplicationId = ap.Id -- To get the social security number LEFT OUTER JOIN CompanySetApplicantRelation csaplntr WITH(NOLOCK) ON (csaplntr.ApplicantProfileId = cars.ApplicantProfileId AND csaplntr.CompanySetId = @companySetId) -- FILTERS WHERE cars.IsActive = 1 AND ap.IsDeletedByCompany = 0 -- Inactive data AND (@IncludeInactiveApplications = 1 OR (ap.Id IS NULL OR ap.IsActive = 1)) AND (@IncludeDeletedApprenticeship = 1 OR (apr.Id IS NULL OR (apr.IsDeleted = 0 AND clocprof.IsDeleted = 0 AND clpro.IsDeleted = 0))) AND (@IncludeInactiveApplicantsFilter = 1 OR apro.IsVisibleOnGateway = 1) -- Apprenticeship Type AND (@ApprenticeshipTypesFilter IS NULL OR apr.ApprenticeshipType IN (SELECT * FROM dbo.CreateInFilter(@ApprenticeshipTypesFilter,'|'))) -- Profession AND (@MessageProfessionsFilter IS NULL OR clpro.ProfessionId IN (SELECT * FROM dbo.CreateInFilter(@MessageProfessionsFilter,'|'))) -- ABCD ratings AND ( (@RatingProfessionsFilter IS NULL AND @RatingFilter IS NULL) OR ( (@RatingProfessionsFilter IS NULL OR EXISTS ( SELECT 1 FROM ApplicantProfessionRating apr WHERE apr.DossierId = cars.DossierId AND apr.ProfessionId = clpro.ProfessionId AND apr.ProfessionId IN (SELECT value FROM dbo.CreateInFilter(@RatingProfessionsFilter,'|')) )) AND (@RatingFilter IS NULL OR EXISTS ( SELECT 1 FROM ApplicantProfessionRating apr WHERE apr.DossierId = cars.DossierId AND apr.ProfessionId = clpro.ProfessionId AND apr.ApplicantProfessionRatingTypeId IN (SELECT value FROM dbo.CreateInFilter(@RatingFilter,'|')) ) ) ) ) -- Comments AND (@CompanySetApplicantComment IS NULL OR EXISTS ( SELECT * FROM CompanySetApplicantComment csacomm WHERE csacomm.ApplicantProfileId = cars.ApplicantProfileId AND csacomm.CompanySetId = @companySetId AND csacomm.Comment LIKE '%' + @CompanySetApplicantComment + '%')) -- Responsible Person AND ( -- No RP filter is selected, we show all results (TODO: this is not possible in UI anymore, and it could be useful, typically with CompanySets) ( @ApprenticeshipResponsiblePersonsFilter IS NULL AND @SearchResponsiblePersonIsNotDefine = 0 ) -- Show results that have a RP selected OR csar.CompanyPersonId IN (SELECT * FROM dbo.CreateInFilter(@ApprenticeshipResponsiblePersonsFilter,'|')) -- shared dossiers if the RP is the current user OR (EXISTS (SELECT * FROM DossierViewPermission dvp WHERE (dvp.TargetCompanyPersonId IN (SELECT TOP 1 * FROM dbo.CreateInFilter(@ApprenticeshipResponsiblePersonsFilter,'|') f WHERE f.value = @companyPersonId ) AND dvp.DossierId IN (SELECT d.Id FROM Dossier d WHERE d.ApplicantProfileId = cars.ApplicantProfileId AND d.CompanySetId = @companySetId) AND dvp.Type = 3 -- Specific permission AND ( -- Dossier-level permission dvp.ApplicationId IS NULL -- Application-level permission for this specific application OR dvp.ApplicationId = ap.Id ) )) ) -- Show results that don't have a RP OR (@SearchResponsiblePersonIsNotDefine = 1 AND csar.CompanyPersonId IS NULL) ) -- Messages AND (msg.Id IS NULL OR msg.MessageStatusTypeId IN (1,2,3,5,9)) --(ApplicantApplied, CompanyCvAsked, ApplicantCvAskAccepted, ApplicantDeclined, GenericMessage) TODO: document why we only get these AND (@FirstMessageStartDate IS NULL OR (CONVERT(DATE, ap.CreatedDate) >= @FirstMessageStartDate)) AND (@FirstMessageEndDate IS NULL OR (CONVERT(DATE, ap.CreatedDate) <= @FirstMessageEndDate)) -- Apprenticeship start date AND (@ApprenticeshipStartDate IS NULL OR (CONVERT(DATE, apr.StartDate) >= @ApprenticeshipStartDate)) AND (@ApprenticeshipEndDate IS NULL OR (CONVERT(DATE, apr.StartDate) <= @ApprenticeshipEndDate)) -- If the Applicant is searching for any type of offer AND (@IsSearchingAppr IS NULL OR (@IsSearchingAppr = 1 AND (apro.IsSearchingApprenticeship = 1 OR apro.IsSearchingInternship = 1 OR apro.IsSearchingTrialApprenticeship = 1 OR apro.IsSearchingProfessionalOffer = 1 OR apro.IsSearchingStudyOffer = 1 OR apro.IsSearchingStage = 1 OR apro.IsSearchingJob = 1))) -- Applicant's personal info AND (@ApplicantBirthDate IS NULL OR apro.BornDate = @ApplicantBirthDate) AND (@ApplicantNamesFilter IS NULL OR ( ((dbo.InLike(apro.FirstName, @ApplicantNamesFilter) = 1) OR (dbo.InLike(apro.LastName, @ApplicantNamesFilter) = 1)) AND EXISTS(SELECT * FROM CompanyApplicantRelationsState c_aRel -- To make sure the Dossier is released INNER JOIN CompanyProfile cpBoughtDossier ON cpBoughtDossier.Id = c_aRel.CompanyProfileId WHERE c_aRel.DossierReleased = 1 AND c_aRel.ApplicantProfileId = apro.Id AND cpBoughtDossier.CompanySetId = @companySetId )) ) -- Company info AND cars.CompanyProfileId IN (SELECT Id FROM CompanyProfile WHERE CompanySetId = @companySetId) -- Useful to reduce the amount of SQL operations AND (@CoCompaniesFilter IS NULL OR cars.CompanyProfileId IN (SELECT * FROM dbo.CreateInFilter(@CoCompaniesFilter,'|'))) -- Location AND (clocprof.Id IS NULL OR clocprof.Id IN (SELECT Id FROM CompanyLocationProfile WHERE CompanyProfileId IN (SELECT Id FROM CompanyProfile WHERE CompanySetId = @companySetId))) -- TODO: do we need SELECT Id FROM... ? AND (@CompanyLocationsFilter IS NULL OR clocprof.Id IN (SELECT * FROM dbo.CreateInFilter(@CompanyLocationsFilter,'|'))) -- Applicant's language AND (@SchoolLangFilter IS NULL OR (apro.[Language] IN (SELECT * FROM dbo.CreateInFilter(@SchoolLangFilter,'|')))) -- Statuses AND (@WorkflowStatesFilter IS NULL OR cas.CompanyApplicantStateAvailableId IN (SELECT * FROM dbo.CreateInFilter(@WorkflowStatesFilter,'|')) OR (cas.CompanyApplicantStateAvailableId IS NULL AND 0 IN (SELECT * FROM dbo.CreateInFilter(@WorkflowStatesFilter,'|'))) -- TODO: is this needed? ) OPTION (RECOMPILE) ---------------------------------------------------------------------- ------ 2. GROUP RESULTS AND FILTER MESSAGE STATES -------- ---------------------------------------------------------------------- -- Group data (to remove duplicates) and apply unread/unanswered messages filter CREATE TABLE #tmpResults2 ( Id int identity(1,1), -- TODO: do we need that? ApplicantProfileId int, ApplicantProfessionProfileId int, CompanyLocationProfileId int, CompanyPersonId int, ApprenticeshipId int, ApplicationId int, ApplicationCreateDate DATETIME, CompanyApplicantAvailableStateId int, DossierPayed BIT, -- New (compared to #tmpResults2) AverageCompanySetCompanyRatings float, -- New (compared to #tmpResults2) SocialSecurityNumber varchar(30), UnreadMsgCount int, UnansweredMsgCount int, LastEditDossierDate DATETIME, IsActiveApplication bit, LastSentMessageDate DATETIME, LastReceivedMessageDate DATETIME ); CREATE CLUSTERED INDEX IDX_tmpResults2_ID ON #tmpResults2 (Id) CREATE INDEX IDX_tmpResults2_Profile ON #tmpResults2 (Id, ApplicantProfileId, ApprenticeshipId) --TODO: do we need it? CREATE INDEX IDX_tmpResults2_ApplicationId ON #tmpResults2 (ApplicationId) INSERT #tmpResults2 ( ApplicantProfileId , ApplicantProfessionProfileId , CompanyLocationProfileId , CompanyPersonId , ApprenticeshipId , ApplicationId , ApplicationCreateDate , CompanyApplicantAvailableStateId , DossierPayed, AverageCompanySetCompanyRatings, SocialSecurityNumber, LastEditDossierDate, IsActiveApplication ) SELECT DISTINCT r.ApplicantProfileId, ApplicantProfessionProfileId, r.CompanyLocationProfileId, r.CompanyPersonId, ApprenticeshipId, r.ApplicationId, ApplicationCreateDate, CompanyApplicantStateAvailableId, --caas.Id AS CompanyApplicantAvailableStateId, CASE WHEN EXISTS(SELECT * FROM CompanyApplicantRelationsState c_aRel INNER JOIN CompanyProfile cpBoughtDossier ON cpBoughtDossier.Id = c_aRel.CompanyProfileId WHERE c_aRel.DossierReleased = 1 AND c_aRel.ApplicantProfileId=r.ApplicantProfileId AND cpBoughtDossier.CompanySetId = @companySetId) THEN @true ELSE @false END, (SELECT TOP 1 ISNULL(apprating.CompanySetRatingAverage, 0) FROM ApplicantProfileRatings apprating WHERE apprating.ApplicantProfileId = r.ApplicantProfileId AND apprating.CompanySetId = @companySetId), r.SocialSecurityNumber, MAX(r.LastEditDossierDate), -- To avoid duplicate results if an Applicant's RP has been chosen in a different company than the Application's one r.IsActiveApplication FROM @tmpCompanyApplicantRelationState r GROUP BY r.ApplicantProfileId, ApplicantProfessionProfileId, r.CompanyLocationProfileId, r.CompanyPersonId, ApprenticeshipId, r.ApplicationId, ApplicationCreateDate, r.SocialSecurityNumber, r.CompanyApplicantStateAvailableId, r.IsActiveApplication OPTION (RECOMPILE) UPDATE t SET UnreadMsgCount = MessageUnread, UnansweredMsgCount = MessageUnanswered FROM ( SELECT UnreadMsgCount, UnansweredMsgCount, (CASE WHEN (EXISTS (SELECT Id FROM [Message] WHERE IsRead = @false AND Id = msg.Id)) THEN 1 ELSE NULL END) AS MessageUnread, (CASE WHEN (EXISTS (SELECT Id FROM [Message] WHERE IsReplied = @false AND MessageStatusTypeId <> 5 AND Id = msg.Id)) THEN 1 ELSE NULL END) AS MessageUnanswered FROM #tmpResults2 t JOIN Apprenticeship app ON t.ApprenticeshipId = app.Id JOIN [Message] msg ON msg.ApplicationId IN ( SELECT a.Id FROM [Application] a WHERE a.ApprenticeshipId = t.ApprenticeshipId AND a.ApplicantProfessionProfileId = t.ApplicantProfessionProfileId AND (@IncludeInactiveApplications = 1 OR a.IsActive = @true) ) AND msg.SentByCompanyPersonId IS NULL AND msg.IsDeletedByCompany = @false ) AS t WHERE (@IsMessageUnread IS NULL OR MessageUnread IS NOT NULL) AND (@IsMessageUnanswered IS NULL OR MessageUnanswered IS NOT NULL) IF @IsMessageUnread IS NOT NULL BEGIN DELETE FROM #tmpResults2 WHERE UnreadMsgCount IS NULL END IF @IsMessageUnanswered IS NOT NULL BEGIN DELETE FROM #tmpResults2 WHERE UnansweredMsgCount IS NULL END ;WITH DistinctApps AS ( SELECT DISTINCT ApplicationId FROM #tmpResults2 WHERE ApplicationId IS NOT NULL ), LatestMsgDates AS ( SELECT m.ApplicationId, MAX(CASE WHEN m.SentByCompanyPersonId IS NOT NULL THEN m.SentDateTime END) AS LastSentMessageDate, MAX(CASE WHEN m.SentByCompanyPersonId IS NULL THEN m.SentDateTime END) AS LastReceivedMessageDate FROM [Message] m WITH(NOLOCK) JOIN DistinctApps da ON da.ApplicationId = m.ApplicationId GROUP BY m.ApplicationId ) UPDATE t SET t.LastSentMessageDate = l.LastSentMessageDate, t.LastReceivedMessageDate = l.LastReceivedMessageDate FROM #tmpResults2 t LEFT JOIN LatestMsgDates l ON l.ApplicationId = t.ApplicationId ---------------------------------------------------------------------- ------ 3. SELECT RESULT, APPLY PAGING & ORDERING --------- ---------------------------------------------------------------------- --GET THE RESULT-- ;WITH paged AS ( SELECT d.Id AS DossierID, res.ApplicantProfileId, res.ApprenticeshipId, @false AS Checked, apro.Id, res.DossierPayed, apro.IsVisibleOnGateway, apro.PlaceName AS ApplicantCity, apro.IsMale, apro.LastName, apro.FirstName, apro.Email, apro.Phone, apro.PortraitImageUrl, apro.BornDate, apro.PlaceName AS ApplicantProfilePlaceName, apro.Street AS ApplicantProfileStreet, apro.MotherTongue, apro.PlaceOfOrigin, apro.WorkPermit, apr.StartDate AS ApprenticeshipStartDate, apr.ApplyPeriodType, apr.ApplyPeriodStartDate, apr.CompanyLocationProfileId, res.ApplicationCreateDate, COALESCE(cpn.FirstName,'') AS CompanyPersonFirstName, COALESCE(cpn.LastName,'') AS CompanyPersonLastName, COALESCE(cpn.FirstName + ' ' +cpn.LastName,'') AS CompanyPersonName, 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, res.ApplicationId AS ApplicationId, clprof.PlaceName AS CompanyLocationProfilePlaceName, clprof.Street AS CompanyLocationProfileStreet, clprof.Plz AS CompanyLocationProfilePlz, apr.ApprenticeshipType, res.ApplicantProfessionProfileId, caas.ShortCode + ': ' + caas.Name AS WorkflowState, 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, COALESCE(res.UnreadMsgCount, 0) AS UnreadMsgCount, COALESCE(res.UnansweredMsgCount, 0) AS UnansweredMsgCount, @false AS IsCreatedByCompany, apro.Language AS ApplicantProfileLanguage, apro.Plz AS ApplicantProfilePlz, res.LastEditDossierDate, apro.HealthInsuranceNumber AS HealthInsuranceNumber, apro.FirstNationalityId AS NationalityId, apro.CountryId AS CountryId, apro.Mobile AS Mobile, res.IsActiveApplication, clpro.ExternalReferenceId, apro.CompletionPercentage AS CompletionPercentage, (SELECT ColorCode FROM CompanyApplicantAvailableStateColor WHERE Id = caas.ColorId) AS ColorCode, res.LastSentMessageDate, res.LastReceivedMessageDate, clprof.CompanyAppendix AS CompanyLocationProfileAppendix FROM #tmpResults2 res LEFT JOIN Dossier d ON d.ApplicantProfileId = res.ApplicantProfileId AND d.CompanySetId = @companySetId LEFT JOIN ApplicantProfile apro ON apro.Id = res.ApplicantProfileId LEFT JOIN Apprenticeship apr ON apr.Id = res.ApprenticeshipId LEFT JOIN CompanyPerson cpnapp ON cpnapp.Id = apr.CompanyPersonId LEFT JOIN CompanyPerson cpn ON cpn.Id = res.CompanyPersonId 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 WHERE -- Anonymous Applicants ((@HideAnonymousApplicant IS NULL OR @HideAnonymousApplicant = 0) OR (@HideAnonymousApplicant=1 AND res.DossierPayed = @true )) AND (@SharingEnabled = @false -- Own Dossiers. OR (res.CompanyPersonId = @companyPersonId) -- All Admins. OR EXISTS (SELECT * FROM DossierViewPermission dvp WHERE (@companyPersonRole IN (SELECT * FROM dbo.CreateInFilter(@CompanyPersonRolesAllowedToSeeApplicants,'|'))) -- 20 "Administration role", 10 "Recruiting role" AND dvp.DossierId IN (SELECT d.Id FROM Dossier d WHERE d.ApplicantProfileId = res.ApplicantProfileId AND d.CompanySetId = @companySetId) AND dvp.Type = 0 -- CompanySet wide permission (Dossier). -- Shared to specific CP ) OR EXISTS (SELECT * FROM DossierViewPermission dvp WHERE (dvp.TargetCompanyPersonId = @companyPersonId AND dvp.DossierId IN (SELECT d.Id FROM Dossier d WHERE d.ApplicantProfileId = res.ApplicantProfileId AND d.CompanySetId = @companySetId) AND dvp.Type = 3 -- Specific CP AND (dvp.ApplicationId IS NULL OR dvp.ApplicationId = res.ApplicationId ) ) ) ) -- Portrait -- We need the filter here, because we also don't want to show anonymous pictures (see GAT-4224) AND (@HasPortrait IS NULL OR (@HasPortrait = 1 AND apro.PortraitImageUrl IS NOT NULL AND res.DossierPayed = 1)) -------------------------------------------------------------------------------- -- Add the ApplicantProfilesCreatedByCompany to the result set UNION -------------------------------------------------------------------------------- SELECT D.Id AS DossierID, ISNULL(apcc.ApplicantProfileId, 0) AS ApplicantProfileId, --(because the C# code doesn't expect a NULL) -- res.ApplicantProfileId, app.Id AS ApprenticeshipId, -- res.ApprenticeshipId @false AS Checked, apcc.Id, @true AS DossierPayed, -- (never anonymous, since it was inserted by the company), --res.DossierPayed, @true AS IsVisibleOnGateway, -- (always true, since it has to be visible by the company) --apro.IsVisibleOnGateway apcc.PlaceName AS ApplicantCity, -- apro.PlaceName AS ApplicantCity, apcc.IsMale, apcc.LastName, apcc.FirstName, apcc.Email, apcc.Phone, -- apro.Phone, apcc.PortraitImageUrl, -- apro.PortraitImageUrl, apcc.BornDate, -- apro.BornDate, apcc.PlaceName AS ApplicantProfilePlaceName, -- apro.PlaceName as ApplicantProfilePlaceName, apcc.Street AS ApplicantProfileStreet, -- apro.Street as ApplicantProfileStreet, '' as MotherTongue, '' as PlaceOfOrigin, NULL as WorkPermit, app.StartDate AS ApprenticeshipStartDate, -- apr.StartDate AS ApprenticeshipStartDate, app.ApplyPeriodType, app.ApplyPeriodStartDate, app.CompanyLocationProfileId, -- apr.CompanyLocationProfileId, apcc.DateCreated AS ApplicationCreateDate, -- Similar enough to Application.CreateDate -- res.ApplicationCreateDate, cpers.FirstName AS CompanyPersonFirstName, -- COALESCE(cpn.FirstName,'') AS CompanyPersonFirstName, cpers.LastName AS CompanyPersonLastName, -- COALESCE(cpn.LastName,'') AS CompanyPersonLastName, cpers.FirstName + ' ' + cpers.LastName AS CompanyPersonName, --cpn.FirstName + ' '+cpn.LastName as CompanyPersonName, cpers.Salutation AS Salutation, cp.Id AS CompanyProfileId, -- COALESCE(cpn.CompanyProfileId, cpnapp.CompanyProfileId) AS CompanyProfileId, cpers.Email AS CompanyPersonEmail, -- cpn.Email as CompanyPersonEmail, (SELECT TOP 1 proT.Name FROM ProfessionTranslation prot WHERE prot.Language = @Language AND prot.ProfessionId = cprof.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 = cprof.ProfessionId) AS RatingTypeResult, 0 AS CommentsCount, NULL AS LastComment, NULL AS CommentTemplateId, NULL AS ApplicationId, cloc.PlaceName AS CompanyLocationProfilePlaceName, -- clprof.PlaceName AS CompanyLocationProfilePlaceName, cloc.Street AS CompanyLocationProfileStreet, -- clprof.Street as CompanyLocationProfileStreet, cloc.Plz AS CompanyLocationProfilePlz, -- clprof.Plz as CompanyLocationProfilePlz, app.ApprenticeshipType, -- apr.ApprenticeshipType, NULL, -- res.ApplicantProfessionProfileId, NULL AS WorkflowState, -- caas.ShortCode + ': ' + caas.Name AS WorkflowState, NULL AS WorkflowStateDescription, NULL AS CompanySetRatingAverage, -- res.AverageCompanySetCompanyRatings as CompanySetRatingAverage, NULL AS SocialSecurityNumber, -- res.SocialSecurityNumber @false AS DocChangeNotificationEnabled, @false AS IsHeadquarterCompanyLocationProfile, 0 AS UnreadMsgCount, 0 AS UnansweredMsgCount, @true AS IsCreatedByCompany, apcc.Language ApplicantProfileLanguage, apcc.Plz ApplicantProfilePlz, apcc.DateModified AS LastEditDossierDate, NULL AS HealthInsuranceNumber, NULL AS NationalityId, apcc.CountryId AS CountryId, apcc.Mobile AS Mobile, @true AS IsActiveApplication, cprof.ExternalReferenceId, 5 AS CompletionPercentage, -- We set CompletionPercentage to 5% for applicant created by company person NULL AS ColorCode, NULL AS LastSentMessageDate, NULL AS LastReceivedMessageDate, cloc.CompanyAppendix AS CompanyLocationProfileAppendix FROM ApplicantProfileCreatedByCompany apcc LEFT JOIN Dossier d ON d.ApplicantProfileId = apcc.ApplicantProfileId AND d.ApplicantProfileCreatedByCompanyId = apcc.Id AND d.CompanySetId = @companySetId JOIN ApplicantProfileCreatedByCompanyApprenticeship apcc_app ON apcc_app.ApplicantProfileCreatedByCompany_Id = apcc.Id JOIN Apprenticeship app ON apcc_app.Apprenticeship_Id = app.Id JOIN CompanyLocationProfile cloc ON app.CompanyLocationProfileId = cloc.Id JOIN CompanyLocationProfession cprof ON app.CompanyLocationProfessionId = cprof.Id JOIN CompanyPerson cpers ON app.CompanyPersonId = cpers.Id JOIN CompanyProfile cp ON cpers.CompanyProfileId = cp.Id WHERE cp.CompanySetId = @companySetId AND (@ApplicantNamesFilter IS NULL OR ( (dbo.InLike(apcc.FirstName, @ApplicantNamesFilter) = 1) OR (dbo.InLike(apcc.LastName, @ApplicantNamesFilter) = 1)) ) AND (@ApplicantBirthDate IS NULL OR apcc.BornDate = @ApplicantBirthDate) AND ( @ApprenticeshipResponsiblePersonsFilter IS NULL OR app.CompanyPersonId IN (SELECT * FROM dbo.CreateInFilter(@ApprenticeshipResponsiblePersonsFilter,'|')) -- Shared dossiers if the RP is the current user OR (EXISTS (SELECT * FROM DossierViewPermission dvp WHERE (dvp.TargetCompanyPersonId IN (SELECT TOP 1 * FROM dbo.CreateInFilter(@ApprenticeshipResponsiblePersonsFilter,'|') f WHERE f.value = @companyPersonId ) AND dvp.DossierId IN (SELECT d.Id FROM Dossier d WHERE d.ApplicantProfileId = apcc.ApplicantProfileId AND d.CompanySetId = @companySetId) AND dvp.Type = 3 -- Specific permission AND dvp.ApplicationId IS NULL -- Only dossier-level permissions for ApplicantProfileCreatedByCompany )) ) ) AND ( @CompanyLocationsFilter IS NULL OR app.CompanyLocationProfileId IN (SELECT * FROM dbo.CreateInFilter(@CompanyLocationsFilter,'|')) ) AND ( @ApprenticeshipTypesFilter IS NULL OR app.ApprenticeshipType IN (SELECT * FROM dbo.CreateInFilter(@ApprenticeshipTypesFilter,'|')) ) -- AND ( -- TODO: why is this commented? -- @MessageProfessionsFilter IS NULL -- OR cprof.ProfessionId IN (SELECT * FROM dbo.CreateInFilter(@MessageProfessionsFilter,'|')) -- ) -- Date Filter -- For the Application start and end dates, we use the profile creation dates, it's similar enough AND ( @FirstMessageStartDate IS NULL OR (CONVERT(DATE, apcc.DateCreated) >= @FirstMessageStartDate) ) AND ( @FirstMessageEndDate IS NULL OR (CONVERT(DATE, apcc.DateCreated) <= @FirstMessageEndDate) ) AND ( @ApprenticeshipStartDate IS NULL OR (CONVERT(DATE, app.StartDate) >= @ApprenticeshipStartDate) ) AND ( @ApprenticeshipEndDate IS NULL OR (CONVERT(DATE, app.StartDate) <= @ApprenticeshipEndDate) ) AND ( (@CoCompaniesFilter IS NULL AND apcc.CompanyProfileId IN (SELECT Id FROM CompanyProfile WHERE CompanySetId = @companySetId)) OR apcc.CompanyProfileId IN (SELECT * FROM dbo.CreateInFilter(@CoCompaniesFilter,'|')) ) -- The filters below can't apply to ApplicantProfileCreatedByCompany, -- so they have to be null (unused) to return resultset AND (@RatingProfessionsFilter IS NULL AND @RatingFilter IS NULL) AND (@SchoolLangFilter IS NULL) AND (@WorkflowStatesFilter IS NULL) -- Because we can't have unread or unanswered messages for ApplicantProfilesCreatedByCompany AND (@IsMessageUnread IS NULL) AND (@IsMessageUnanswered IS NULL) AND (@IncludeApplicantsCreatedByCompanyFilter != 0) ), ordered as ( SELECT ROW_NUMBER() OVER (ORDER BY CASE WHEN @SortColumn = 'ApplicantName' THEN DossierPayed END DESC, CASE WHEN @SortColumn = 'ApplicantName' AND @SortAsc = 1 THEN LastName END ASC, CASE WHEN @SortColumn = 'ApplicantName' AND @SortAsc = 0 THEN LastName END DESC, CASE WHEN @SortColumn = 'ApplicantName' AND @SortAsc = 1 THEN FirstName END ASC, CASE WHEN @SortColumn = 'ApplicantName' AND @SortAsc = 0 THEN FirstName END DESC, CASE WHEN @SortColumn = 'ApplicantCity' AND @SortAsc = 1 THEN ApplicantCity END ASC, CASE WHEN @SortColumn = 'ApplicantCity' AND @SortAsc = 0 THEN ApplicantCity END DESC, CASE WHEN @SortColumn = 'Profession' AND @SortAsc = 1 THEN Profession END ASC, CASE WHEN @SortColumn = 'Profession' AND @SortAsc = 0 THEN Profession END DESC, CASE WHEN @SortColumn = 'CompanyLocationProfilePlaceName' AND @SortAsc = 1 THEN CompanyLocationProfilePlaceName END ASC, CASE WHEN @SortColumn = 'CompanyLocationProfilePlaceName' AND @SortAsc = 0 THEN CompanyLocationProfilePlaceName END DESC, CASE WHEN @SortColumn = 'CompanyPersonName' AND @SortAsc = 1 THEN CompanyPersonLastName END ASC, CASE WHEN @SortColumn = 'CompanyPersonName' AND @SortAsc = 0 THEN CompanyPersonLastName END DESC, CASE WHEN @SortColumn = 'CompanyPersonName' AND @SortAsc = 1 THEN CompanyPersonFirstName END ASC, CASE WHEN @SortColumn = 'CompanyPersonName' AND @SortAsc = 0 THEN CompanyPersonFirstName END DESC, CASE WHEN @SortColumn = 'WorkflowState' AND @SortAsc = 1 THEN [WorkflowState] END ASC, CASE WHEN @SortColumn = 'WorkflowState' AND @SortAsc = 0 THEN [WorkflowState] END DESC, CASE WHEN @SortColumn = 'CompanySetRatingAverage' AND @SortAsc = 1 THEN RatingTypeResult END ASC, CASE WHEN @SortColumn = 'CompanySetRatingAverage' AND @SortAsc = 0 THEN RatingTypeResult END DESC, CASE WHEN @SortColumn = 'CompanySetRatingAverage' AND @SortAsc = 1 THEN [CompanySetRatingAverage] END ASC, CASE WHEN @SortColumn = 'CompanySetRatingAverage' AND @SortAsc = 0 THEN [CompanySetRatingAverage] END DESC, CASE WHEN @SortColumn = 'ApplicationCreateDate' AND @SortAsc = 1 THEN [ApplicationCreateDate] END ASC, CASE WHEN @SortColumn = 'ApplicationCreateDate' AND @SortAsc = 0 THEN [ApplicationCreateDate] END DESC, CASE WHEN @SortColumn = 'LastEditDossierDate' AND @SortAsc = 1 THEN [LastEditDossierDate] END ASC, CASE WHEN @SortColumn = 'LastEditDossierDate' AND @SortAsc = 0 THEN [LastEditDossierDate] END DESC, CASE WHEN @SortColumn = 'LastReceivedMessageDate' AND @SortAsc = 1 THEN LastReceivedMessageDate END ASC, CASE WHEN @SortColumn = 'LastReceivedMessageDate' AND @SortAsc = 0 THEN LastReceivedMessageDate END DESC, CASE WHEN @SortColumn = 'LastSentMessageDate' AND @SortAsc = 1 THEN LastSentMessageDate END ASC, CASE WHEN @SortColumn = 'LastSentMessageDate' AND @SortAsc = 0 THEN LastSentMessageDate END DESC, Id ) AS RowNumber, * FROM paged ) SELECT ( SELECT COUNT(*) FROM paged res2 WHERE ((@HideAnonymousApplicant IS NULL OR @HideAnonymousApplicant=0) OR (@HideAnonymousApplicant=1 AND res2.DossierPayed=@true )) ) AS TotalItems, cpro.Name AS CompanyName, cpro.Id AS CompanyProfileId, ordered.* FROM ordered LEFT JOIN CompanyProfile cpro ON cpro.Id = ordered.CompanyProfileId WHERE (ordered.RowNumber >= @FirstRow) AND (ordered.RowNumber < (@FirstRow + @PageSize)) ORDER BY ordered.RowNumber END