Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Help with SQL query


Help with SQL query

Author
Message
mehfuz.khaled
mehfuz.khaled
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 4
Hello all, I am not sure whether this is the right thread to post this or not.

Anyways, I have one table as follows:

table mastertab(
op INT,
msisdn VARCHAR (12),
imei VARCHAR (20)
);

Sample values that I have are as follows:

aa, 0191, 111222333
aa, 0191, 111222444
aa, 0192, 111222333
aa, 0192, 111222444
aa, 0192, 111222555
aa, 0193, 111222333
bb, 0171, 222222333
bb, 0171, 222222444
bb, 0172, 222222444
cc, 0152, 333222444

Now, i want the output to show as (op, imei_count) set where imei_count displays the total number of duplicate imei and groups it by op. Expected output is as follows:

op imei_count
-- ----------
aa 2
bb 1
cc 0

Any help in this regard will highly be appreciated.

Thanks,

Mehfuz
mehfuz.khaled
mehfuz.khaled
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 4
I forgot to mention that it has a composite primary key as follows:
(msisdn, imei)
kapil_kk
kapil_kk
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2387 Visits: 2763
First thing is your table structure is incorrect..
You have specified op as INT but you are inserting character values in that column
aa, 0191, 111222333

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
kapil_kk
kapil_kk
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2387 Visits: 2763
you can try this-

;WITH CTE AS
(
select op,imei, DENSE_RANK() over (order by op,imei) rankno
FROM mastertab
)
select c.op, COUNT(distinct rankno) - 1 cnt
FROM CTE c
GROUP BY c.op



_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
mehfuz.khaled
mehfuz.khaled
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 4
Op is also char. Sorry about that.
kapil_kk
kapil_kk
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2387 Visits: 2763
mehfuz.khaled (7/20/2013)
Op is also char. Sorry about that.

Change the datatype of Op to CHAR and run the query that I posted... Hope it will work for you

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44802 Visits: 39845
kapil_kk (7/20/2013)
you can try this-

;WITH CTE AS
(
select op,imei, DENSE_RANK() over (order by op,imei) rankno
FROM mastertab
)
select c.op, COUNT(distinct rankno) - 1 cnt
FROM CTE c
GROUP BY c.op



Try with this data and see what happens..

drop table mastertab

CREATE table mastertab(
op CHAR(2),
msisdn VARCHAR (12),
imei VARCHAR (20)
);
INSERT INTO mastertab
(op,msisdn,imei)
SELECT 'aa','0191','111222333' UNION ALL
--SELECT 'aa','0191','111222444' UNION ALL
SELECT 'aa','0192','111222333' UNION ALL
--SELECT 'aa','0192','111222444' UNION ALL
SELECT 'aa','0192','111222555' UNION ALL
--SELECT 'aa','0193','111222333' UNION ALL

SELECT 'aa','0193','111222334' UNION ALL --added
SELECT 'aa','0193','111222335' UNION ALL --added
SELECT 'aa','0193','111222336' UNION ALL --added
SELECT 'aa','0193','111222337' UNION ALL --added
SELECT 'aa','0193','111222338' UNION ALL --added


SELECT 'bb','0171','222222333' UNION ALL
SELECT 'bb','0171','222222444' UNION ALL
SELECT 'bb','0172','222222444' UNION ALL
SELECT 'cc','0152','333222444'

;WITH CTE AS
(
select op,imei, DENSE_RANK() over (order by op,imei) rankno
FROM mastertab
)
select c.op, COUNT(distinct rankno) - 1 cnt
FROM CTE c
GROUP BY c.op



--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44802 Visits: 39845
mehfuz.khaled (7/20/2013)
Hello all, I am not sure whether this is the right thread to post this or not.

Anyways, I have one table as follows:

table mastertab(
op INT,
msisdn VARCHAR (12),
imei VARCHAR (20)
);

Sample values that I have are as follows:

aa, 0191, 111222333
aa, 0191, 111222444
aa, 0192, 111222333
aa, 0192, 111222444
aa, 0192, 111222555
aa, 0193, 111222333
bb, 0171, 222222333
bb, 0171, 222222444
bb, 0172, 222222444
cc, 0152, 333222444

Now, i want the output to show as (op, imei_count) set where imei_count displays the total number of duplicate imei and groups it by op. Expected output is as follows:

op imei_count
-- ----------
aa 2
bb 1
cc 0

Any help in this regard will highly be appreciated.

Thanks,

Mehfuz


First, you're new here. You'll get a whole lot more coded, tested answers if you follow the simple advice offered in the first link in my signature line below.

Second, what do you want to be returned if the data is like this?


aa, 0191, 111222333
aa, 0191, 111222444
aa, 0192, 111222333
aa, 0192, 111222444
aa, 0193, 111222555
aa, 0194, 111222555
aa, 0195, 111222556
aa, 0196, 111222556



--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
mehfuz.khaled
mehfuz.khaled
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 4
Thanks Jeff for your response.
For the inputs that you have given, my expected output would be as follow:

Op imei_count
-- -----------
aa 4

Thanks and regards,

Mehfuz
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8923 Visits: 19008
SELECT op, SUM(CASE WHEN dupes > 1 THEN 1 ELSE 0 END) 
FROM (
   SELECT op, imei, dupes = COUNT(*)
   FROM #mastertab
   GROUP BY op, imei
) d
GROUP BY op



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
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