October 20, 2014 at 8:52 am
I have a stored procedure in that attempts to perform a WHERE NOT EXISTS check to insert new records. If the table is empty, the procedure will load the table. However, an insert does not occur when a change to one or more source fields occurs against an existing record. The following is my code:
declare
@Created_By nchar(50)
,@Created_Date datetime
,@Updated_By nchar(50)
,@Updated_Date datetime
select @Created_By = system_user
,@Created_Date = getdate()
,@Updated_By = system_user
,@Updated_Date = getdate()
insert fact.Appointment
(
Slot_ID
, Slot_DateTime
, Slot_StartDateTime
, Slot_EndDateTime
, Slot_Duration_min
, Slot_CreateDateTime
, Slot_CreateDate_DateKey
, Healthcare_System_ID
, Healthcare_Service_ID
, Healthcare_Supervising_Service_ID
, Healthcare_Site_ID
, Booked_Appt_ID
, Appt_Notification_Submission_DateKey
, Appt_Notification_Completion_DateKey
, Appt_Notification_Duration
, Appt_Notification_ID
, Patient_ID
, Physician_ID
, Referral_ID
, Specialty
, LanguageRequested
, Created_Date
, Created_By
, Updated_Date
, Updated_By
)
select distinct
Slot.Slot_ID
, Slot.Slot_Start_DateTime as Slot_DateTime --???
, Slot.Slot_Start_DateTime
, Slot.Slot_End_DateTime
, datediff(mi,slot.Slot_Start_DateTime,slot.Slot_End_Datetime) as Slot_Duration_Min
, Slot.Created_Date as Slot_CreateDateTime
, SlotCreateDate.Date_key as Slot_CreateDate_DateKey
, HSite.Healthcare_System_ID
, HSite.Healthcare_Service_ID
, HSite.Healthcare_Service_ID as Healthcare_Supervising_Service_ID
, HSite.Healthcare_Site_ID
, Ref.Booked_Appt_ID
, ApptSubmissionTime.Date_key as Appt_Notification_Submission_DateKey
, ApptCompletionTime.Date_key as Appt_Notification_Completion_DateKey
, datediff(mi,appt.SubmissionTime,appt.CompletionTime) as Appt_Notification_Duration
, Appt.Appt_Notification_ID
, pat.Patient_ID
, 0 as Physician_ID
, ref.Referral_ID
, Hsrv.Specialty
, appt.[Language] as LanguageRequested
,@Created_Date as Created_Date
,@Created_By as Created_By
,@Updated_Date as Updated_Date
,@Updated_By as Updated_By
from dim.Healthcare_System HSys
inner join dim.Healthcare_Service HSrv
on HSys.Healthcare_System_ID = HSrv.HealthCare_System_ID
inner join dim.Healthcare_Site HSite
on HSite.HealthCare_Service_ID = HSrv.Healthcare_Service_ID
and HSite.HealthCare_System_ID = HSrv.HealthCare_System_ID
inner join dim.Referral Ref
on Ref.ReferralSite_ID = HSite.Site_ID
and Ref.ReferralService_ID = HSite.Service_ID
and Ref.ReferralSystem_ID = HSite.System_ID
right join (select distinct Slot_ID, Source_Slot_ID, Slot_Start_DateTime, Slot_End_DateTime, Created_Date from dim.slot)slot
on ref.Source_Slot_ID = slot.Source_Slot_ID
inner join dim.Appointment_Notification appt
on appt.System_ID = HSys.System_ID
inner join dim.Patient pat
on pat.Source_Patient_ID = appt.Source_Patient_ID
inner join dim.SystemUser SysUser
on SysUser.Healthcare_System_ID = HSys.Healthcare_System_ID
left join dim.Calendar SlotCreateDate
on SlotCreateDate.Full_DateTime = cast(Slot.Created_Date as smalldatetime)
left join dim.Calendar ApptSubmissionTime
on ApptSubmissionTime.Full_DateTime = cast(appt.SubmissionTime as smalldatetime)
left join dim.Calendar ApptCompletionTime
on ApptCompletionTime.Full_DateTime = cast(appt.CompletionTime as smalldatetime)
where not exists
(
select
Slot_ID
, Slot_DateTime
, Slot_StartDateTime
, Slot_EndDateTime
, Slot_Duration_min
, Slot_CreateDateTime
, Slot_CreateDate_DateKey
, Healthcare_System_ID
, Healthcare_Service_ID
, Healthcare_Supervising_Service_ID
, Healthcare_Site_ID
, Booked_Appt_ID
, Appt_Notification_Submission_DateKey
, Appt_Notification_Completion_DateKey
, Appt_Notification_Duration
, Appt_Notification_ID
, Patient_ID
, Physician_ID
, Referral_ID
, Specialty
, LanguageRequested
, Created_Date
, Created_By
, Updated_Date
, Updated_By
from fact.Appointment fact
where
(
Slot.Slot_ID = fact.Slot_ID
or
Slot.Slot_Start_DateTime = fact.Slot_DateTime
or
Slot.Slot_Start_DateTime = fact.Slot_StartDateTime
or
Slot.Slot_End_DateTime = fact.Slot_EndDateTime
or
datediff(mi,slot.Slot_Start_DateTime,slot.Slot_End_Datetime) =
fact.Slot_Duration_min
or
Slot.Created_Date = fact.Slot_CreateDateTime
or
SlotCreateDate.Date_key = fact.Slot_CreateDate_DateKey
or
HSite.Healthcare_System_ID = fact.Healthcare_System_ID
or
HSite.Healthcare_Service_ID = fact.Healthcare_Service_ID
or
HSite.Healthcare_Service_ID = fact.Healthcare_Service_ID
or
HSite.Healthcare_Site_ID = fact.Healthcare_Site_ID
or
Ref.Booked_Appt_ID = fact.Booked_Appt_ID
or
ApptSubmissionTime.Date_key =
fact.Appt_Notification_Submission_DateKey
or
ApptCompletionTime.Date_key =
fact.Appt_Notification_Completion_DateKey
or
datediff(mi,appt.SubmissionTime,appt.CompletionTime) = fact.Appt_Notification_Duration
or
Appt.Appt_Notification_ID = fact.Appt_Notification_ID
or
pat.Patient_ID = fact.Patient_ID
or
0 = 0
or
ref.Referral_ID = fact.Referral_ID
or
Hsrv.Specialty = fact.Specialty
or
appt.[Language] = fact.LanguageRequested
)
)
--*********************
I expected that when one of the source values of any field in the second WHERE clause changes, that the procedure would insert a new record. Why is this not happening? One other note: I am not 'allowed' to use MERGE.
Thank you for your help.
CSDunn
October 20, 2014 at 9:01 am
Since all the conditions in the WHERE clause of the NOT EXISTS query are OR'd together it only takes one of the criteria to match in order to get a row that exists. I think you want AND not OR.
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
Viewing 2 posts - 1 through 1 (of 1 total)
You must be logged in to reply to this topic. Login to reply