Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 select first of identical column name

Author  Topic 

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-13 : 02:15:23
Hi

I have the following table and data...


CREATE TABLE [dbo].[Card](
[ID] [int] IDENTITY(1,1) NOT NULL,
[TransID] [nvarchar](50) NULL,
[TimeElapsed] [nvarchar](50) NULL,
[FileName] [nvarchar](50) NULL)

INSERT INTO Card (TransID, TimeElapsed, FileName) VALUES ('592300', '7891011', 'File1.jpg')
INSERT INTO Card (TransID, TimeElapsed, FileName) VALUES ('592304', '7891011', 'File2.jpg')
INSERT INTO Card (TransID, TimeElapsed, FileName) VALUES ('592300', '5891011', 'File3.jpg')
INSERT INTO Card (TransID, TimeElapsed, FileName) VALUES ('592300', '6891011', 'File4.jpg')
INSERT INTO Card (TransID, TimeElapsed, FileName) VALUES ('592300', '2891011', 'File5.jpg')




The result I would like to accomplish is this..


ID TransID TimeElapsed FileName
1 592300 7891011 File1.jpg
3 592300 5891011 File3.jpg
4 592300 6891011 File4.jpg
5 592300 2891011 File5.jpg



ID 1 & 2 have the same TimeElapsed value and therefore I would only like to display the ID 1 beacuse that is the one that is inserted first in the database. And the other rows should be there to beacuse they have unique TimeElapsed value. So if 2 or more rows have the same TimeElapsed value the result should only display the first inserted row. Can onyone show how I can do that?

Best Regards

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-13 : 02:30:21
[code]SELECT ID,
TransID,
TimeElapsed,
FileName
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY TimeElapsed ORDER BY ID ASC) AS rn,*
FROM Table
)t
WHERE Rn=1
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-13 : 07:12:26
Worked excellent. Thanks!

I think I need some more help with another approach to the same data. Is it possible to retrieve all rows but mark the ones that isn't displayed as "Active/Not Active" so that the result would be like this....

ID TransID TimeElapsed FileName Active
1 592300 7891011 File1.jpg 1
2 592304 7891011 File2.jpg 0
3 592300 5891011 File3.jpg 1
4 592300 6891011 File4.jpg 1
5 592300 2891011 File5.jpg 1



Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-13 : 07:19:06
[code]SELECT ID,
TransID,
TimeElapsed,
FileName,
CASE WHEN Rn=1 THEN 1 ELSE 0 END AS Active
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY TimeElapsed ORDER BY ID ASC) AS rn,*
FROM Table
)t
[/code]




------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-13 : 08:17:06
Hi

perfect, if the TimeElapsed value is null can that I set it to active=1?
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-13 : 08:22:18
Sure..as below
SELECT ID,	
TransID,
TimeElapsed,
FileName,
CASE WHEN TimeElapsed IS NULL OR Rn=1 THEN 1 ELSE 0 END AS Active
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY TimeElapsed ORDER BY ID ASC) AS rn,*
FROM Table
)t




------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-13 : 09:25:23
Thanks, your code works just fine on my test database, but when I try it on my live database I get Active = 0 on 2 rows that have identical TimeElapsed values, I don't see why though... Do you have any hints?
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-13 : 10:25:36
what are the ID values for them?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-13 : 10:35:37
ID, 6 & 7. They have identical TimeElapsed values and therefore it should mark ID: 6 as 1and ID:7 as 0, but both of them is marked 0...
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-13 : 11:13:37
then there must be another record with same TimeElapsed value

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-13 : 12:38:11
You are right, I used it on a table with a lot of data and used top 100, therefore I didn't see the one with a higher ID. Sorry.
Thank you very much for all help!
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-13 : 12:44:34
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-16 : 08:44:05
Hi

I added a column to the table called "Duplicate", could I use this function to update the "Duplicate" column with the "Active" value. So that the rows that are active is marked as Duplicate = 0, and the the rows that isn't active is marked as Duplicate = 1. I plan to use this as a stored procedure that is run before I make other database activity.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-16 : 12:56:15
you mean this?

UPDATE t
SET t.Duplicate = 0
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY TimeElapsed ORDER BY ID ASC) AS rn,TimeElapsed,Duplicate
FROM Table
)t
WHERE TimeElapsed IS NULL OR Rn=1


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-17 : 02:02:12
Hi

I made one little change (Order By DESC), it do update all the rows that are supposed to be set as 0 but not the ones that are supposed to be set as 1.

Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-17 : 02:14:28
ok.. so its working as expected

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-17 : 02:21:42
Hi

Almost, the ones that should be set to 1 isn't set, they still have NULL values.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-17 : 02:34:21
[code]UPDATE t
SET t.Duplicate = CASE WHEN TimeElapsed IS NULL OR Rn=1 THEN 0 ELSE 1 END
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY TimeElapsed ORDER BY ID ASC) AS rn,TimeElapsed,Duplicate
FROM Table
)t
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-17 : 02:53:17
Thanks, I think there is one more thing, can it be changed so that the check for TimeElapsed field only check if it has a value, so values that are NULL or '' should be marked as duplicate = 0. Sorry for all changes...
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-09-17 : 03:19:35
[code]UPDATE t
SET t.Duplicate = CASE WHEN ISNULL(TimeElapsed,'') ='' OR Rn=1 THEN 0 ELSE 1 END
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY TimeElapsed ORDER BY ID ASC) AS rn,TimeElapsed,Duplicate
FROM Table
)t
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

magmo
Aged Yak Warrior

558 Posts

Posted - 2011-09-17 : 03:24:38
Perfect, Thank you very much I really appreciate it!
Go to Top of Page
    Next Page

- Advertisement -