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


Count of Unique Row Combinations


Count of Unique Row Combinations

Author
Message
tajrin
tajrin
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 70
Hi,

I have the following table:

ID | Val
1 | A
1 | B
1 | C
2 | C
2 | B
2 | A
3 | A
3 | B
3 | X
4 | A
4 | Z
4 | Y
5 | A
5 | B
5 | C

My problem is, how do I write a query to get the count of unique combinations, in this case 3 x ABC, 1 x ABX and 1 x AZY?

SQL fiddle trial so far:

http://sqlfiddle.com/#!3/1accd/9


tnx in advance
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16636 Visits: 17024
You were so close...at least as I understand your requirements.


Select COUNT(*) / LEN(x.Vals) TCRuns, x.Vals
FROM
(
SELECT t1.ID as RunID, msv1.Val as Vals
From trial t1
CROSS APPLY
(SELECT
(SELECT t2.Val --+ '|'
FROM trial t2
WHERE t1.ID = t2.ID
ORDER BY t2.Val
FOR XML PATH(''), TYPE).value('.', 'varchar(max)')
) msv1 (Val)
) x
Group by x.Vals




_______________________________________________________________

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 Moden's 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)
tajrin
tajrin
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 70
tnx for the reply, some more questions please:

1...Is it possible to get 3 as a final result....ie the total number of different combinations?
2...why did you comment out the pipe separator (|)?
3...Is it possible to achieve the same result without using FOR XML path, because this is kind of slow.

tnx
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16636 Visits: 17024
tajrin (10/25/2013)
tnx for the reply, some more questions please:

1...Is it possible to get 3 as a final result....ie the total number of different combinations?


Sure no problem. Just roll your code into a cte and then it is pretty simple


;with Combinations as
(
Select COUNT(*) / LEN(x.Vals) TCRuns, x.Vals
FROM
(
SELECT t1.ID as RunID, msv1.Val as Vals
From trial t1
CROSS APPLY
(SELECT
(SELECT t2.Val --+ '|'
FROM trial t2
WHERE t1.ID = t2.ID
ORDER BY t2.Val
FOR XML PATH(''), TYPE).value('.', 'varchar(max)')
) msv1 (Val)
) x
Group by x.Vals
)
, TotalCount as
(
select COUNT(*) as TotalCount from Combinations
)
select *
from Combinations
cross join TotalCount




2...why did you comment out the pipe separator (|)?


It made it far easier to see the results without the extra noise of a | in middle. There was no logical reason to remove it. If you want/need it just put it back in.


3...Is it possible to achieve the same result without using FOR XML path, because this is kind of slow.


It is certainly possible to do this other ways but I don't know that there is a faster way.

_______________________________________________________________

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 Moden's 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)
TheSQLGuru
TheSQLGuru
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 6002 Visits: 8314
tajrin (10/25/2013)
tnx for the reply, some more questions please:

1...Is it possible to get 3 as a final result....ie the total number of different combinations?
2...why did you comment out the pipe separator (|)?
3...Is it possible to achieve the same result without using FOR XML path, because this is kind of slow.

tnx


See here for 1 SIGNIFICANT improvement to the XML version, and lots of other helpful information too: http://www.sqlservercentral.com/Forums/Topic1046233-1273-1.aspx

Note that the xml stuff blows up if certain characters are in your data - another reason to perhaps avoid it. But the 2-order-of-magnitude perf improvement found in the link is a big deal obviously. I dislike XML also for both the data issue and the memory grant required.

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
hunchback
hunchback
SSC-Enthusiastic
SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)

Group: General Forum Members
Points: 117 Visits: 639
If the number of elements per ID is always 3 then you can pivot, group by yhe pivoted columns and count the distinct IDs.


SET NOCOUNT ON;
USE tempdb;
GO
CREATE TABLE trial
(
ID int,
Val varchar(2),
PRIMARY KEY (ID, Val)
);

INSERT INTO trial
(ID, Val)
VALUES
(1, 'A'),
(1, 'B'),
(1, 'C'),
(2, 'C'),
(2, 'B'),
(2, 'A'),
(3, 'A'),
(3, 'B'),
(3, 'X'),
(4, 'A'),
(4, 'Z'),
(4, 'Y'),
(5, 'A'),
(5, 'B'),
(5, 'C');
GO
WITH C1 AS (
SELECT
ID,
MIN(CASE WHEN rn = 1 THEN Val END) AS Val1,
MIN(CASE WHEN rn = 2 THEN Val END) AS Val2,
MIN(CASE WHEN rn = 3 THEN Val END) AS Val3
FROM
(
SELECT
ID,
Val,
ROW_NUMBER() OVER(PARTITION BY ID ORDER BY Val) AS rn
FROM
trial
) AS T
GROUP BY
ID
)
SELECT
Val1,
Val2,
Val3,
COUNT(DISTINCT ID) AS cnt,
COUNT(*) OVER() AS DistinctGroups
FROM
C1
GROUP BY
Val1,
Val2,
Val3
ORDER BY
Val1,
Val2,
Val3;
GO
DROP TABLE trial;
GO




If the number of elements is variable then things get complicated and having a string aggregation could be handy or may be go for dynamic pivoting (ouch!).



Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45307 Visits: 39934
TheSQLGuru (10/26/2013)
See here for 1 SIGNIFICANT improvement to the XML version, and lots of other helpful information too: http://www.sqlservercentral.com/Forums/Topic1046233-1273-1.aspx


It's a funny thing about that "improvement". While the Actual Execution plan looks totally awesome compared to the orginal, it's not any better than the original from what I've seen in the testing I've done. In fact, both can be pretty well beat up by using a CAST to VARCHAR(MAX) instead of using any reference node references at all.

I had reason to revisit that discussion and I'm not sure how they came up with such a difference in times on that post. I'm still checking to make sure I didn't screw something up in my testing.

--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 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
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