October 22, 2013 at 11:00 am
Hi all I am running a query where I check medical orders on an encounter there can be 1000's of orders and if one of them matches a specific criteria we delete all of them. The common thread hear is a CSN #. I am running a CTE and marking a flag column with a 1 if the criteria is hit and 0 otherwise.
My question is how do I delete this record and the other orders with the same CSN? Can I us a recursive CTE, cross apply? Not sure where to go from here any help appreciated Mahalo, Brew
October 22, 2013 at 11:19 am
It will be helpful having DDL, sample data, an expected result. That way we do not have to guess column names, data types, etc.
Help us to be able to help you!
You can join back the result of the CTE with the original table by the column in common or you can try deleting from the CTE if the conditions to use a CTE as the source are meet.
October 22, 2013 at 11:27 am
HI thx for the info here's the code
;with CteGetMain as (
SELECT DISTINCT PAT.PAT_NAME as PatName,
PAT.PAT_MRN_ID as MRN,
ZBASE.NAME as PatBaseClass,
ZCLASS.NAME as PatSubClass,
HSP.HOSP_ADMSN_TIME as AdmissionDate,
HSP.HOSP_DISCH_TIME as DischargeDate,
DATEDIFF(DAY, HOSP_ADMSN_TIME, HOSP_DISCH_TIME) as VisitLength,
CASE
when
QST.ORD_QUEST_RESP = 'Admit from OB Triage' then 1
else 0
END AS is_AdmitOBTriage,
ORP3.ORDERING_MODE_C as OrderMode,
VHX.EVENT_TYPE_C as EventCode,
DEP.DEPARTMENT_NAME as DeptName,
HSP.PAT_ENC_CSN_ID as CSN,
ORP.PROC_CODE as ProcCode,
EAP.PROC_NAME as ProcName,
MET.ORDER_DTTM as OrderDate,
MET.ORDER_ID as OrderID,
ZTHERA.THERA_CLASS_C as TheraClass,
MED.ORDER_MED_ID as MedOrderID,
MED.DISPLAY_NAME AS MedName,
ATND.PROV_ID as AtndProvID,
SER.PROV_NAME as AtndProv,
ATND.LINE as AtndLine,
SERO.PROV_ID OrderProvID,
SERO.PROV_NAME as OrderProv,
SER.PROV_ID AuthID,
SERA.PROV_NAME as AuthProv,
case
When ORP.ORDER_TYPE_C = 9
or ORP.PROC_CODE in ('DNS3', 'DNS2', 'NUR519', 'NUR519', 'NUR1081', 'NUR1019',
'NUR305', 'NUR981', 'NUR919', 'Diet87' )
Then 'Diet'
When ORP.PROC_CODE in ('ADT1')
Then 'Admit'
When ORP.PROC_CODE in ( 'NUR9','NUR162', 'NUR87', 'NUR158', 'NUR25', 'NUR1029', 'NUR11', 'NUR129',
'NUR130', 'NUR44', 'NUR371', 'NUR511 ','NUR84','PRV9', 'NUR940','NUR25',
'NUR533','NUR714','NUR79', 'NUR820','NUR52')
Then 'Activity'
When ORP.PROC_CODE in ( 'COD1', 'COD2', 'COD3')
Then 'Code'
When ZTHERA.THERA_CLASS_C in (1,2,6)
Then 'Pain'
END as OrderType
FROM V_PAT_ADT_LOCATION_HX VHX
inner join PAT_ENC_HSP HSP
ON VHX.PAT_ENC_CSN = HSP.PAT_ENC_CSN_ID
inner join CLARITY_DEP DEP
ON VHX.ADT_DEPARTMENT_ID = DEP.DEPARTMENT_ID
inner join PATIENT PAT
ON HSP.PAT_ID = PAT.PAT_ID
LEFT OUTER JOIN ORDER_METRICS MET
ON HSP.PAT_ENC_CSN_ID = MET.PAT_ENC_CSN_ID
LEFT OUTER JOIN HSP_ATND_PROV ATND
ON HSP.PAT_ENC_CSN_ID = ATND.PAT_ENC_CSN_ID
LEFT OUTER JOIN ORDER_MED MED
ON MET.PAT_ENC_CSN_ID = MED.PAT_ENC_CSN_ID
LEFT OUTER JOIN ORDER_PROC ORP
ON MET.ORDER_ID = ORP.ORDER_PROC_ID
LEFT OUTER JOIN CLARITY_SER SERO
ON MET.ORDERING_PROV_ID = SERO.PROV_ID
LEFT OUTER JOIN CLARITY_SER SERA
ON MET.AUTH_PROV_ID = SERA.PROV_ID
LEFT OUTER JOIN ORDER_PROC_3 ORP3
ON ORP.ORDER_PROC_ID = ORP3.ORDER_ID
LEFT OUTER JOIN CLARITY_MEDICATION CMED
ON MED.MEDICATION_ID = CMED.MEDICATION_ID
LEFT OUTER JOIN ZC_THERA_CLASS ZTHERA
ON CMED.THERA_CLASS_C = ZTHERA.THERA_CLASS_C
LEFT OUTER JOIN CLARITY_SER SER
ON ATND.PROV_ID = SER.PROV_ID
Left outer join CLARITY_EAP EAP
ON ORP.PROC_ID = EAP.PROC_ID
Left join HSP_ACCOUNT HACCT
on HSP.HSP_ACCOUNT_ID = HACCT.HSP_ACCOUNT_ID
LEFT JOIN ZC_ACCT_BASECLS_HA ZBASE
on HACCT.ACCT_BASECLS_HA_C = ZBASE.ACCT_BASECLS_HA_C
Left join ZC_ACCT_CLASS_HA ZClass
on HACCT.ACCT_CLASS_HA_C = ZClass.ACCT_CLASS_HA_C
Left join ORD_SPEC_QUEST QST
on ORP.ORDER_PROC_ID = QST.ORDER_ID --and QST.ORD_QUEST_ID = '100795' and QST.ORD_QUEST_RESP <> 'ADMIT from OB Triage'
WHERE DEP.DEPARTMENT_NAME not in ('MMC ED ADULT','MMC ED BURN','MMC ED PEDS')
AND VHX.EVENT_TYPE_C in (1,4,7) -- Admission, Transfer out, Outpatient
AND ORP3.ORDERING_MODE_C = 2 -- inpatient order mode
AND HSP.HOSP_ADMSN_TIME >= {ts '2013-08-01 00:00:00'}
AND HSP.HOSP_ADMSN_TIME <{ts '2013-09-01 00:00:00'}
AND ATND.LINE = 1 and HSP.PAT_ENC_CSN_ID = '7847189'
)
/* Now that we have identified the orders we want in OrderType lets remove all the unnecessary orders
marked as null so we create a smaller results set for faster processing */
, CTERemoveNulls as (
select CteGetMain.*
from CteGetMain
where (OrderType is not null))
select * from CTERemoveNulls
October 22, 2013 at 11:33 am
From the description, I would suspect you want an IF EXISTS construct. But really need DDL, sample data and expected results to be sure.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
October 22, 2013 at 3:51 pm
mittensonmaui (10/22/2013)
Hi all I am running a query where I check medical orders on an encounter there can be 1000's of orders and if one of them matches a specific criteria we delete all of them. The common thread hear is a CSN #. I am running a CTE and marking a flag column with a 1 if the criteria is hit and 0 otherwise.My question is how do I delete this record and the other orders with the same CSN? Can I us a recursive CTE, cross apply? Not sure where to go from here any help appreciated Mahalo, Brew
You are looking for something like this (note my comments):
-- let's say we wanted to delete all csn_numbers that have at least one some_value='xxx'
DECLARE @your_table TABLE
(xxx_id int identity primary key,
csn_number int not null,
some_value varchar(20) null)
INSERT INTO @your_table VALUES
(100,'fff'),(100, 'yyy'),(100,'xxx'),(140,'abc'),(150,'xxx'),
(200,'zzz'),(200, 'abc'),(210,'xxx'),(240,'bbb'),(250,'abc');
--Here's what's in there now
SELECT * FROM @your_table;
WITH kill_list AS
(
SELECT * FROM @your_table
WHERE csn_number IN (
SELECT csn_number
FROM @your_table WHERE some_value='xxx' GROUP BY csn_number)
)
DELETE FROM kill_list;
--Here's what's in there now
SELECT * FROM @your_table
The cool thing about this technique is that, in SSMS, you can highlight run your SELECT statement first to see what will be deleted.
-- Itzik Ben-Gan 2001
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply