Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Matching Column Data in Rows Expand / Collapse
Author
Message
Posted Wednesday, October 23, 2013 2:26 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, August 20, 2014 3:24 PM
Points: 266, Visits: 692
Something I thought would be so simple has me scratching my head. How do we return only those table rows where three of the columns match? For example on the attached doc we only want to return the third and fourth rows where the partnumber, serial no, and uid match. Any help will be greatly appreciated.

  Post Attachments 
RowData.xlsx (11 views, 9.02 KB)
Post #1507820
Posted Wednesday, October 23, 2013 2:35 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:32 PM
Points: 13,302, Visits: 12,168
Please post ddl and consumable data in the future. The query itself is pretty trivial but setting up the problem from a spreadsheet is painful.

Here is one way to do this.

create table #Something
(
ID int,
PartNum varchar(20),
SerialNum int,
UserID int
)

insert #Something
select 30448, '019-018-001', 376, 169132 union all
select 35739, '019-018-001', 232, 185155 union all
select 37658, '019-018-001', 232, 185155 union all
select 1283, '019-018-001', 242, 118818 union all
select 2022, '019-018-001', 240, 118453 union all
select 2023, '019-018-001', 249, 118452 union all
select 2030, '019-018-001', 187, 118454;

with matches as
(
select COUNT(*) as MyCount, PartNum, SerialNum, UserID
from #Something
group by PartNum, SerialNum, UserID
having COUNT(*) > 1
)

select s.*
from #Something s
join matches m on m.PartNum = s.PartNum and s.SerialNum = m.SerialNum and s.UserID = m.UserID;

drop table #Something



_______________________________________________________________

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)
Post #1507822
Posted Thursday, October 24, 2013 9:05 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, August 20, 2014 3:24 PM
Points: 266, Visits: 692
That worked great. Much appreciated.
Post #1508111
Posted Thursday, October 24, 2013 9:13 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:32 PM
Points: 13,302, Visits: 12,168
You are welcome. Glad that worked for you.

_______________________________________________________________

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)
Post #1508116
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse