SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Stuck on Query to Conditionally Exclude Data


Stuck on Query to Conditionally Exclude Data

Author
Message
jkalmar 43328
jkalmar 43328
SSC-Enthusiastic
SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)

Group: General Forum Members
Points: 123 Visits: 51
Eirikur, with this test data the expected result set would be:

C1473045850  T1954  3730  ''
C1473045850 T1954 3731 ''
C1473045850 T1954 3732 ''
C1473045850 T1954 3733 ''



(not sure how to indicate the blanks so I used empty quotes, hope that's OK).
mickyT
mickyT
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2774 Visits: 3318
What would you expect for the following data?
INSERT INTO PRE_LOAD
(KitID, BatteryID, TestID, LBSTAT)
SELECT 'C1473045850','T1878','3730','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3731','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3732','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3733','NOT DONE' UNION ALL
SELECT 'C1473045850','T1954','3730','' UNION ALL
SELECT 'C1473045850','T1954','3731',''


Sean Lange
Sean Lange
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60891 Visits: 17954
jkalmar 43328 (8/25/2014)
Eirikur, with this test data the expected result set would be:

C1473045850  T1954  3730  ''
C1473045850 T1954 3731 ''
C1473045850 T1954 3732 ''
C1473045850 T1954 3733 ''



(not sure how to indicate the blanks so I used empty quotes, hope that's OK).


Seems that what I posted should work for you then?

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39569 Visits: 19440
jkalmar 43328 (8/25/2014)
Eirikur, with this test data the expected result set would be:

C1473045850  T1954  3730  ''
C1473045850 T1954 3731 ''
C1473045850 T1954 3732 ''
C1473045850 T1954 3733 ''



(not sure how to indicate the blanks so I used empty quotes, hope that's OK).


Good stuff, think I might be missing something though as the following query will produce this results but feels kind of "too simple" given the original requirements
Cool

SELECT
*
FROM dbo.PRE_LOAD PL
WHERE PL.LBSTAT <> 'NOT DONE'



Sean Lange already posted a solution that produces the same results, is that what you need?
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40902 Visits: 19815
Here's an extended set of sample data and the solutions posted. I guess Micky's got the correct formula.

CREATE TABLE PRE_LOAD(
KitID varchar(20) NULL,
BatteryID varchar(20) NULL,
TestID varchar(20) NULL,
LBSTAT varchar(8) NULL
)

INSERT INTO PRE_LOAD
(KitID, BatteryID, TestID, LBSTAT)
SELECT 'C1473999999','T5555','3730','NOT DONE' UNION ALL
SELECT 'C1473999999','T5555','3731','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3730','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3731','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3732','NOT DONE' UNION ALL
SELECT 'C1473045850','T1878','3733','NOT DONE' UNION ALL
SELECT 'C1473045850','T1954','3730','' UNION ALL
SELECT 'C1473045850','T1954','3731','' UNION ALL
SELECT 'C1473045850','T1954','3732','' UNION ALL
SELECT 'C1473045850','T1954','3733','' UNION ALL
SELECT 'C1111111111','T1234','3737','' UNION ALL
SELECT 'C1111111111','T1234','3737','' UNION ALL
SELECT 'C1111111111','T4444','3738',''

select *
from PRE_LOAD
where BatteryID not in
(
select BatteryID
from PRE_LOAD
where LBSTAT = 'NOT DONE'
)

select *
from PRE_LOAD ex
where EXISTS
(
select 1
from PRE_LOAD i
where LBSTAT <> 'NOT DONE'
AND ex.kitID = i.KitID
)

SELECT p.KitID,
p.BatteryID,
p.TestID,
p.LBSTAT
FROM PRE_LOAD p
CROSS APPLY (
SELECT COUNT(*) chk
FROM PRE_LOAD c
WHERE p.KitID = c.KitID AND
p.TestID = c.TestID AND
c.LBSTAT <> 'NOT DONE'
) x
WHERE LBSTAT <> 'NOT DONE' OR
x.chk = 0
GO
DROP TABLE PRE_LOAD




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
jkalmar 43328
jkalmar 43328
SSC-Enthusiastic
SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)

Group: General Forum Members
Points: 123 Visits: 51
Actually Luis, yours gives the closest to the needed result on the actual data. With some tuning I think it's going to work for me. Thanks to everyone for their help!
mickyT
mickyT
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2774 Visits: 3318
Can you post up your solution when you have it tuned thanks.
jkalmar 43328
jkalmar 43328
SSC-Enthusiastic
SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)SSC-Enthusiastic (123 reputation)

Group: General Forum Members
Points: 123 Visits: 51
The solution is going to look very different because they changed the requirements on me a bit. Here's the final code:

WITH ctePLC (cKitID, cStdBatteryName)
AS
(
SELECT KitID, StdBatteryName
FROM (
SELECT KitId
,StdBatteryName
,COUNT(DISTINCT StdBatteryId) AS bCount
FROM PRE_LOAD
GROUP BY KitId, StdBatteryName
) AS t2
WHERE t2.bCount > 1
)
,
ctePLD (dKitID, dStdBatteryName)
AS
(
SELECT DISTINCT t1.KitID, t1.StdBatteryName FROM PRE_LOAD AS t1
INNER JOIN ctePLC
ON t1.KitID = ctePLC.cKitID
AND t1.StdBatteryName = ctePLC.cStdBatteryName
AND t1.TestStatus = 'D'
)
,
ctePLN (nKitID, nStdBatteryName)
AS
(
SELECT DISTINCT t1.KitID, t1.StdBatteryName FROM PRE_LOAD AS t1
INNER JOIN ctePLC
ON t1.KitID = ctePLC.cKitID
AND t1.StdBatteryName = ctePLC.cStdBatteryName
AND t1.TestStatus = 'N'
)
,
ctePLX (xKitID, xStdBatteryName)
AS
(
SELECT DISTINCT t1.KitID, t1.StdBatteryName FROM PRE_LOAD AS t1
INNER JOIN ctePLC
ON t1.KitID = ctePLC.cKitID
AND t1.StdBatteryName = ctePLC.cStdBatteryName
AND t1.TestStatus = 'X'
)

SELECT *
FROM PRE_LOAD AS t1
INNER JOIN ctePLC AS c
ON t1.KitID = c.cKitID
AND t1.StdBatteryName = c.cStdBatteryName
LEFT JOIN ctePLD AS d
ON c.cKitID = d.dKitID
AND c.cStdBatteryName = d.dStdBatteryName
LEFT JOIN ctePLN AS n
ON c.cKitID = n.nKitID
AND c.cStdBatteryName = n.nStdBatteryName
LEFT JOIN ctePLX AS x
ON c.cKitID = x.xKitID
AND c.cStdBatteryName = x.xStdBatteryName
WHERE
t1.TestStatus = 'N'
AND (
EXISTS (
SELECT t1.KitID, t1.StdBatteryName
FROM PRE_LOAD AS t1
WHERE t1.KitID = d.dKitID
AND t1.StdBatteryName = d.dStdBatteryName
)
OR
EXISTS (
SELECT t1.KitID, t1.StdBatteryName
FROM PRE_LOAD AS t1
WHERE t1.KitID = x.xKitID
AND t1.StdBatteryName = x.xStdBatteryName
)
)
OR
t1.TestStatus = 'X'
AND (
EXISTS (
SELECT t1.KitID, t1.StdBatteryName
FROM PRE_LOAD AS t1
WHERE t1.KitID = d.dKitID
AND t1.StdBatteryName = d.dStdBatteryName
)
AND
NOT EXISTS (
SELECT t1.KitID, t1.StdBatteryName
FROM PRE_LOAD AS t1
WHERE t1.KitID = n.nKitID
AND t1.StdBatteryName = n.nStdBatteryName
)
)
ORDER BY t1.KitID, t1.stdbatteryname,t1.stdbatteryid,t1.TestStatus



It selects all batteries under the same KitID where the TestStatus is 'N' and there exists a battery with the same name under that same KitID with a TestStatus of 'D' or 'X', and all batteries under the same KitID where the TestStatus is 'X' and there exists a battery with the same name under that same KitID with a TestStatus of 'D' but NO battery with the same name with a TestStatus of 'N'.

The ultimate goal is to delete all 'N' if there's a 'D' or an 'X' and all 'X' if there's a 'D' but no 'N'. I'm having trouble getting my DELETE statement to work, but I'll post that as a new thread.

Again, thanks to all!
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search