July 28, 2010 at 5:23 am
Hi,
I have a table which contain the data as follows,
ID first * sec GroupID vid
11216 122
32116 122
2318 33
41516 12
51616 1
Here I want to get the minimum of the multiples of the column's(first&sec)
that should be grouped with GroupID.For example the result will be
ID first sec GroupID vid
1 2 2 16 122
2 3 1 8 33
Can any one help me out of this?It is very urgent...
Regards
Varun R
July 28, 2010 at 5:49 am
Hi Varun,
please go through this code. i hope this helps you to get the answers..
SELECT a3.*
FROM (SELECT a.GroupID, MIN(MULTICOLUMN)MULTICOLUMN
FROM (SELECT ID, [FIRST] * SEC MULTICOLUMN, GROUPID FROM SAMPLE_TEST)a
JOIN SAMPLE_TEST b On a.ID = b.ID
GROUP BY a.GroupID
) a1
JOIN (SELECT ID, [FIRST] * SEC MULTICOLUMN, GROUPID FROM SAMPLE_TEST) a2 On a1.GroupID = a2.GroupID AND a1.MULTICOLUMN = a2.MULTICOLUMN
JOIN SAMPLE_TEST a3 On a2.ID = a3.ID
Ini your sample, for the ID value 1 & 3 belongs to same groupID "16" and the multiple for Column first&sec is same. so you would be getting 2 rows for the same groupID 16.
If the query has to be changed bit, let me know i can help you in getting the result.
All the best,
Vijay Vasudevan
July 28, 2010 at 5:56 am
select id,first * sec as dd, sec, groupid, vid from MinMultiplecolumn order by dd
July 28, 2010 at 6:09 am
There are many different ways to write a query to do this, here's a popular one:
DECLARE @SampleData
TABLE (
id INTEGER NOT NULL,
first INTEGER NOT NULL,
sec INTEGER NOT NULL,
group_id INTEGER NOT NULL,
vid INTEGER NOT NULL,
PRIMARY KEY CLUSTERED (id)
);
INSERT @SampleData
VALUES (1, 1, 2, 16, 122),
(3, 2, 1, 16, 122),
(2, 3, 1, 08, 033),
(4, 1, 5, 16, 012),
(5, 1, 6, 16, 001);
SELECT *
FROM (
SELECT *,
row_num =
ROW_NUMBER() OVER (
PARTITION BY S.group_id
ORDER BY S.first * S.sec ASC)
FROM @SampleData S
) S
WHERE S.row_num = 1;
July 28, 2010 at 6:12 am
your idea is good paul.. Thanks dude..
I got a chance to learn new method today!! 🙂
July 28, 2010 at 6:20 am
But my favourite would probably be this:
DECLARE @SampleData
TABLE (
id INTEGER NOT NULL,
first INTEGER NOT NULL,
sec INTEGER NOT NULL,
group_id INTEGER NOT NULL,
vid INTEGER NOT NULL,
computed AS ISNULL(first * sec, 0)
PRIMARY KEY CLUSTERED (id)
);
INSERT @SampleData
VALUES (1, 1, 2, 16, 122),
(3, 2, 1, 16, 122),
(2, 3, 1, 08, 033),
(4, 1, 5, 16, 012),
(5, 1, 6, 16, 001);
SELECT S.id, S.group_id, S.computed
FROM @SampleData S
WHERE S.computed =
(
SELECT MIN(S2.computed)
FROM @SampleData S2
WHERE S2.group_id = S.group_id
);
The computed column in the sample table is required to make this work best, but it does not need to be persisted or indexed, so it only really exists in the metadata.
This is a workaround for a limitation in the query optimiser, which might not be necessary in future versions.
One benefit of the computed column (aside from needing no storage space) is that you can create statistics on it. Or at least you could on a real table - the table variable I used for the demo does not support statistics.
July 28, 2010 at 6:30 am
Dear paulwhite,
Thanks for this wonderful solution...Keep it up..Thanks my dear friends for showing interest in answering my question...(For all)
Regards
varun R
July 28, 2010 at 6:56 am
You're welcome.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply