September 3, 2015 at 8:54 am
I need the sql statement that meets the following
I need a list of memberids who meet the following criteria
Select memberid, measureid from numerator
1. There should be atleast 1 record where the measureid = 501
2. There should be atleast 1 record where the measureid = 502
3. There should be atleast 1 record where the measureid = 503
September 3, 2015 at 9:12 am
mw112009 (9/3/2015)
I need the sql statement that meets the followingI need a list of memberids who meet the following criteria
Select memberid, measureid from numerator
1. There should be atleast 1 record where the measureid = 501
2. There should be atleast 1 record where the measureid = 502
3. There should be atleast 1 record where the measureid = 503
SELECT somecolumns
FROM sometable
WHERE something equals something else (or doesn't)
If you provide a little sample data, someone will fill in the gaps.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
September 3, 2015 at 9:29 am
It could be with something like this:
CREATE TABLE numerator(
memberid int,
measureid int
);
INSERT INTO numerator
VALUES
(1,501),
(1,502),
(1,503),
(2,501),
(2,502),
(3,501),
(3,501),
(3,501),
(3,501),
(4,501),
(4,502),
(4,503),
(4,504),
(4,505);
SELECT memberid,
measureid
FROM numerator
WHERE memberid IN (
SELECT memberid
FROM numerator
GROUP BY memberid
HAVING COUNT( DISTINCT CASE WHEN measureid IN( 501, 502, 503) THEN measureid END)= 3);
GO
DROP TABLE numerator;
September 8, 2015 at 8:25 am
Luis Cazares (9/3/2015)
It could be with something like this:
CREATE TABLE numerator(
memberid int,
measureid int
);
INSERT INTO numerator
VALUES
(1,501),
(1,502),
(1,503),
(2,501),
(2,502),
(3,501),
(3,501),
(3,501),
(3,501),
(4,501),
(4,502),
(4,503),
(4,504),
(4,505);
SELECT memberid,
measureid
FROM numerator
WHERE memberid IN (
SELECT memberid
FROM numerator
GROUP BY memberid
HAVING COUNT( DISTINCT CASE WHEN measureid IN( 501, 502, 503) THEN measureid END)= 3);
GO
DROP TABLE numerator;
Based solely on the original post, only the GROUP BY portion of your query is actually needed:
CREATE TABLE #numerator(
memberid int,
measureid int
);
INSERT INTO #numerator
VALUES (1,501),
(1,502),
(1,503),
(2,501),
(2,502),
(3,501),
(3,501),
(3,501),
(3,501),
(4,501),
(4,502),
(4,503),
(4,504),
(4,505);
SELECT memberid
FROM #numerator
GROUP BY memberid
HAVING COUNT(DISTINCT CASE WHEN measureid IN(501, 502, 503) THEN measureid END)= 3--);
GO
DROP TABLE #numerator;
GO
Steve (aka sgmunson) π π π
Rent Servers for Income (picks and shovels strategy)
September 8, 2015 at 8:46 am
sgmunson (9/8/2015)
Based solely on the original post, only the GROUP BY portion of your query is actually needed:
It depends on the expected output. My code will return all the rows while yours will only return the 2 memberid.
September 8, 2015 at 4:09 pm
Luis Cazares (9/8/2015)
sgmunson (9/8/2015)
Based solely on the original post, only the GROUP BY portion of your query is actually needed:
It depends on the expected output. My code will return all the rows while yours will only return the 2 memberid.
Ummm... that was the stated objective in the original post...
Steve (aka sgmunson) π π π
Rent Servers for Income (picks and shovels strategy)
September 8, 2015 at 4:13 pm
cool
good job.
i am happy with the reply
September 9, 2015 at 7:58 am
sgmunson (9/8/2015)
Luis Cazares (9/8/2015)
sgmunson (9/8/2015)
Based solely on the original post, only the GROUP BY portion of your query is actually needed:
It depends on the expected output. My code will return all the rows while yours will only return the 2 memberid.
Ummm... that was the stated objective in the original post...
:ermm: Somehow I missed that part. π
September 12, 2015 at 9:54 pm
mw112009 (9/8/2015)
coolgood job.
i am happy with the reply
Now... what did you learn?
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply