Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

select query Expand / Collapse
Author
Message
Posted Sunday, September 16, 2012 12:36 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Saturday, September 22, 2012 12:31 AM
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
Post #1359908
Posted Sunday, September 16, 2012 12:51 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 4:16 PM
Points: 1,935, Visits: 19,980
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
Post #1359910
Posted Monday, September 17, 2012 2:51 AM


Say Hey Kid

Say Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey Kid

Group: General Forum Members
Last Login: Monday, November 10, 2014 2:57 AM
Points: 692, Visits: 2,805
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
Post #1360031
Posted Monday, September 17, 2012 3:07 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, October 3, 2013 12:38 AM
Points: 91, 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)



*******
Sudhakar
Post #1360036
Posted Monday, September 17, 2012 3:17 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Friday, November 21, 2014 12:53 AM
Points: 569, Visits: 902
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/
Post #1360042
Posted Monday, September 17, 2012 3:18 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, November 11, 2014 3:53 AM
Points: 1,678, Visits: 19,555
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;



____________________________________________________

How to get the best help on a forum

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

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1360043
Posted Monday, September 17, 2012 3:25 AM


Say Hey Kid

Say Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey Kid

Group: General Forum Members
Last Login: Monday, November 10, 2014 2:57 AM
Points: 692, Visits: 2,805

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
Post #1360047
Posted Monday, September 17, 2012 3:43 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, October 3, 2013 12:38 AM
Points: 91, Visits: 77
I have overlooked at the problem statement and gave the wrong query.
Thanks Andy for correcting me.


*******
Sudhakar
Post #1360056
Posted Monday, September 17, 2012 10:54 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, November 21, 2014 5:34 PM
Points: 181, Visits: 918
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

Post #1360341
Posted Monday, September 17, 2012 1:10 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 10:06 AM
Points: 2,268, Visits: 3,425

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)

Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
Post #1360418
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse