October 25, 2013 at 12:46 pm
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
October 25, 2013 at 1:28 pm
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 25, 2013 at 2:05 pm
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
October 25, 2013 at 3:03 pm
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 26, 2013 at 3:44 am
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 on googles mail service
October 26, 2013 at 4:00 pm
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!).
October 26, 2013 at 5:35 pm
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
Change is inevitable... Change for the better is not.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply