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


select query


select query

Author
Message
znkin
znkin
Valued Member
Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)

Group: General Forum Members
Points: 64 Visits: 99
I am using SQL 2008 and I need help to write a select query for the following output

I need list of distinct CustId who have ordered both ProdId 1 and 4. Also if the custid has ordered ProdId 0 then that custid should not be selected

table schema and data are given below and as per the data given the select query should display data cust1 and cust5 as both of them have ProdId 1 and 4 and also neither of them have ProdId 0.

create table product_details
(
TempId int identity,
CustId varchar(50),
ProdId char(1),
enteredon datetime
)

insert into product_details values('cust1',1,getdate())
insert into product_details values('cust1',2,getdate())
insert into product_details values('cust1',3,getdate())
insert into product_details values('cust1',4,getdate())
insert into product_details values('cust2',1,getdate())
insert into product_details values('cust2',2,getdate())
insert into product_details values('cust2',3,getdate())
insert into product_details values('cust3',0,getdate())
insert into product_details values('cust3',1,getdate())
insert into product_details values('cust3',2,getdate())
insert into product_details values('cust4',1,getdate())
insert into product_details values('cust4',2,getdate())
insert into product_details values('cust4',3,getdate())
insert into product_details values('cust4',4,getdate())
insert into product_details values('cust4',0,getdate())
insert into product_details values('cust5',1,getdate())
insert into product_details values('cust5',2,getdate())
insert into product_details values('cust5',3,getdate())
insert into product_details values('cust5',4,getdate())


thanks
J Livingston SQL
J Livingston SQL
SSChampion
SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)

Group: General Forum Members
Points: 11653 Visits: 37442
Hi

as a start, suggest you read the article below...it seems to be very clsoe to what you are asking and will explain the method far better than I can.

http://www.sqlservercentral.com/articles/T-SQL/88244/

if you still have issues, please post back.

kind regards

________________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day

Andy Hyslop
Andy Hyslop
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2059 Visits: 3043
Something like this?


SELECT DISTINCT
CustId

FROM

(
SELECT
CustId

FROM
product_details

WHERE
ProdId = 1
AND CustId IN (SELECT DISTINCT CustId FROM product_details WHERE ProdId = 4)

EXCEPT

SELECT CustId
FROM
product_details
WHERE
ProdId = 0

) AS A




Andy

==========================================================================================================================
A computer lets you make more mistakes faster than any invention in human history - with the possible exceptions of handguns and tequila. Mitch Ratcliffe
Sudhakar Vallamsetty
Sudhakar Vallamsetty
SSC-Enthusiastic
SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)

Group: General Forum Members
Points: 129 Visits: 77
Check if the below one helps ur purpose.

select distinct custid
from product_details
where prodid in (1,4) and custid not in (select custid from product_details where prodid=0)

*******Cool
Sudhakar
rhythmk
rhythmk
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1638 Visits: 1099
znkin (9/16/2012)

I am using SQL 2008 and I need help to write a select query for the following output

I need list of distinct CustId who have ordered both ProdId 1 and 4. Also if the custid has ordered ProdId 0 then that custid should not be selected

table schema and data are given below and as per the data given the select query should display data cust1 and cust5 as both of them have ProdId 1 and 4 and also neither of them have ProdId 0.

create table product_details
(
TempId int identity,
CustId varchar(50),
ProdId char(1),
enteredon datetime
)

insert into product_details values('cust1',1,getdate())
insert into product_details values('cust1',2,getdate())
insert into product_details values('cust1',3,getdate())
insert into product_details values('cust1',4,getdate())
insert into product_details values('cust2',1,getdate())
insert into product_details values('cust2',2,getdate())
insert into product_details values('cust2',3,getdate())
insert into product_details values('cust3',0,getdate())
insert into product_details values('cust3',1,getdate())
insert into product_details values('cust3',2,getdate())
insert into product_details values('cust4',1,getdate())
insert into product_details values('cust4',2,getdate())
insert into product_details values('cust4',3,getdate())
insert into product_details values('cust4',4,getdate())
insert into product_details values('cust4',0,getdate())
insert into product_details values('cust5',1,getdate())
insert into product_details values('cust5',2,getdate())
insert into product_details values('cust5',3,getdate())
insert into product_details values('cust5',4,getdate())


thanks


URL provided by Livingston is best suited for your problem.

--rhythmk
------------------------------------------------------------------
To post your question use below link

http://www.sqlservercentral.com/articles/Best+Practices/61537/
:-)
Mark Cowne
Mark Cowne
SSCertifiable
SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)SSCertifiable (6.2K reputation)

Group: General Forum Members
Points: 6172 Visits: 25507
There's lots of ways of doing this, here's another

SELECT CustID
FROM product_details
WHERE ProdId = 1

INTERSECT

SELECT CustID
FROM product_details
WHERE ProdId = 4

EXCEPT

SELECT CustID
FROM product_details
WHERE ProdId = 0;



Also this


WITH Summary AS (
SELECT CustID,
SUM(CASE WHEN ProdId = 0 THEN 1 ELSE 0 END) AS NumProdId0,
SUM(CASE WHEN ProdId = 1 THEN 1 ELSE 0 END) AS NumProdId1,
SUM(CASE WHEN ProdId = 4 THEN 1 ELSE 0 END) AS NumProdId4
FROM product_details
GROUP BY CustID)
SELECT CustID
FROM Summary
WHERE NumProdId0=0 AND NumProdId1>0 AND NumProdId4>0;



____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




Andy Hyslop
Andy Hyslop
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2059 Visits: 3043

select distinct custid
from product_details
where prodid in (1,4) and custid not in (select custid from product_details where prodid=0)


Nope that wont work the IN works like an OR so CustID 2 is returned in the result set..

Andy

==========================================================================================================================
A computer lets you make more mistakes faster than any invention in human history - with the possible exceptions of handguns and tequila. Mitch Ratcliffe
Sudhakar Vallamsetty
Sudhakar Vallamsetty
SSC-Enthusiastic
SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)

Group: General Forum Members
Points: 129 Visits: 77
I have overlooked at the problem statement and gave the wrong query.
Thanks Andy for correcting me.

*******Cool
Sudhakar
SoCal_DBD
SoCal_DBD
SSC Eights!
SSC Eights! (930 reputation)SSC Eights! (930 reputation)SSC Eights! (930 reputation)SSC Eights! (930 reputation)SSC Eights! (930 reputation)SSC Eights! (930 reputation)SSC Eights! (930 reputation)SSC Eights! (930 reputation)

Group: General Forum Members
Points: 930 Visits: 1588
Another option:


SELECT pd.CustID
FROM Product_Details pd
LEFT JOIN (SELECT CustID FROM Product_Details WHERE ProdID = 0) c ON pd.CustID = c.CustID
WHERE pd.ProdID IN (1, 4)
AND c.CustID IS NULL
GROUP BY pd.CustID
HAVING COUNT(*) = 2


ScottPletcher
ScottPletcher
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18712 Visits: 7402

SELECT
CustId
FROM dbo.product_details
GROUP BY
CustId
HAVING
MAX(CASE WHEN ProdId = 0 THEN 1 ELSE 0 END) = 0 AND
MAX(CASE WHEN ProdId = 1 THEN 1 ELSE 0 END) = 1 AND
MAX(CASE WHEN ProdId = 4 THEN 1 ELSE 0 END) = 1
ORDER BY
CustId



SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
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