Remove Duplicates in Column & Move All Other Values Into Same Row

funkdoctaspock

New Member
Joined
Jan 22, 2018
Messages
3
Good Evening, I have a export file for work that will export employee shifts by job code. In column A of the file there will be ~ 500 rows. I think what I am trying to achieve can be best explained as: I will have repeating values in column A (employee name like Dave, Tom etc etc.) It is only necessary to keep the first instance of the employee's name in column A. In columns B-H (days of the week) employees will have different jobs assigned (not included on the export / not important for this exercise). Complicating things would be that Dave could have 4 different job codes each of which would show in a different row. I will need to group all values in columns B:H into the first row (with the employee's name) so that they may read a proper work schedule when posted. Currently I cannot post a dummy file for an example - but does anyone have any good suggestions on how to accomplish this? I have searched quite a bit and nothing is jumping out at me. What I can paste into this post looks like this - MONDAY TUESDAY WEDNESDAY THURSDAY FRIDAY SATURDAY SUNDAY DAVE 8-5 7-3 DAVE 8-5 8-5 8-5 DAVE 7-3 7-3 DAVE I would like it to read Dave 8-5 7-3 (I think you get the picture) Any help would be greatly appreciated - VBA is ok too. Thanks for reading!
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
A copyable sheet of the original layout along with the desired result (entered manually) would help replying.

Thank you Istvan -

I see below my post here that I "may not post attachments"

I can upload to a sharepoint and see if that is within the forum rules. If it is not - please see table below. This what one employee would look like after the file gets exported. The end file could have any number of employees so the solution would have to be "dynamic" for sure.

[TABLE="width: 100"]
<tbody>[TR]
[TD]ID
[/TD]
[TD]Name[/TD]
[TD]Monday
[/TD]
[TD]Tuesday
[/TD]
[TD]Wednesday
[/TD]
[TD]Thursday[/TD]
[TD]Friday
[/TD]
[TD]Saturday
[/TD]
[TD]Sunday[/TD]
[/TR]
[TR]
[TD]989
[/TD]
[TD]Matt
[/TD]
[TD][/TD]
[TD][/TD]
[TD]11-5
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]989
[/TD]
[TD]Matt
[/TD]
[TD]8-3
[/TD]
[TD][/TD]
[TD][/TD]
[TD]9-3
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]989
[/TD]
[TD]Matt
[/TD]
[TD][/TD]
[TD]7-4
[/TD]
[TD][/TD]
[TD][/TD]
[TD]4-10
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]989
[/TD]
[TD]Matt
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

And achieve

[TABLE="width: 100"]
<tbody>[TR]
[TD]ID
[/TD]
[TD]NAME
[/TD]
[TD]Monday
[/TD]
[TD]Tuesday
[/TD]
[TD]Wednesday
[/TD]
[TD]Thursday
[/TD]
[TD]Friday
[/TD]
[TD]Saturday
[/TD]
[TD]Sunday
[/TD]
[/TR]
[TR]
[TD]989
[/TD]
[TD]Matt
[/TD]
[TD]8-3
[/TD]
[TD]7-4
[/TD]
[TD]11-5
[/TD]
[TD]9-3
[/TD]
[TD]4-10
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

Thanks for reading!
 
Upvote 0
If you can list the employees names (or do you want this to be done by the formula too), you can do someting like this. Copy the formula in cell C13 and confirm with Ctrl + Shift + Enter. Then drag the formula across and down :

Excel Workbook
ABCDEFGHI
1IDNameMondayTuesdayWednesdayThursdayFridaySaturdaySunday
2989Matt11-May
3989Matt08-Mar
4989Matt07-Apr04-Oct
5989Matt
6990Pat09-Mar22-Feb11-Jun
7990Pat04-Jan06-Mar
8989Matt09-Mar
9990Pat
10
11
12IDNameMondayTuesdayWednesdayThursdayFridaySaturdaySunday
13989Matt08-Mar07-Apr11-May09-Mar04-Oct
14990Pat09-Mar04-Jan22-Feb06-Mar11-Jun
Sheet1
 
Upvote 0
If you can list the employees names (or do you want this to be done by the formula too), you can do someting like this. Copy the formula in cell C13 and confirm with Ctrl + Shift + Enter. Then drag the formula across and down :

Sheet1

ABCDEFGHI
IDNameMondayTuesdayWednesdayThursdayFridaySaturdaySunday
Matt
Matt
Matt
Matt
Pat
Pat
Matt
Pat
IDNameMondayTuesdayWednesdayThursdayFridaySaturdaySunday
Matt
Pat

<tbody>
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]1[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]2[/TD]
[TD="align: right"]989[/TD]

[TD="align: right"]11-May[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]3[/TD]
[TD="align: right"]989[/TD]

[TD="align: right"]08-Mar[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]4[/TD]
[TD="align: right"]989[/TD]

[TD="align: right"]07-Apr[/TD]

[TD="align: right"]04-Oct[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]5[/TD]
[TD="align: right"]989[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]6[/TD]
[TD="align: right"]990[/TD]

[TD="align: right"]09-Mar[/TD]

[TD="align: right"]22-Feb[/TD]

[TD="align: right"]11-Jun[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]7[/TD]
[TD="align: right"]990[/TD]

[TD="align: right"]04-Jan[/TD]

[TD="align: right"]06-Mar[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]8[/TD]
[TD="align: right"]989[/TD]

[TD="align: right"]09-Mar[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]9[/TD]
[TD="align: right"]990[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]10[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]11[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]12[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]13
[/TD]
[TD="align: right"]989[/TD]

[TD="align: right"]08-Mar[/TD]
[TD="align: right"]07-Apr[/TD]
[TD="align: right"]11-May[/TD]
[TD="align: right"]09-Mar[/TD]
[TD="align: right"]04-Oct[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]14
[/TD]
[TD="align: right"]990[/TD]

[TD="align: right"]09-Mar[/TD]
[TD="align: right"]04-Jan[/TD]
[TD="align: right"]22-Feb[/TD]
[TD="align: right"]06-Mar[/TD]
[TD="align: right"]11-Jun[/TD]

</tbody>

Spreadsheet Formulas
Cell
Formula
C13{=INDEX(C$2:C$9,MATCH(1,($B$2:$B$9=$B13)*(C$2:C$9<>""),0))}

<tbody>
</tbody>
Formula Array:
Produce enclosing
{ } by entering
formula with CTRL+SHIFT+ENTER!


<tbody>
</tbody>
Excel tables to the web >> Excel Jeanie HTML 4

Works great! Thank you Istvan.

May I ask a follow up question -

How would this work with a named dynamic range(s)? For example -in the workbook I'll name one range "SHIFTS" & another one "EMP_NAME"

SHIFTS = OFFSET(Sheet1!$C$2,0,0,COUNTA(Sheet1!$B:$B)-1,7) where C2 would be the first shift below Monday in the header row.

EMP_NAMES=OFFSET(Sheet1!$B$2,0,0,COUNTA(Sheet1!C:C)-1,1)

I'd like to revise the formula to read something like this

=IFERROR(INDEX(shifts,MATCH(1,(emp_names=$B2)*(shifts<>""),0)),"")

(confirmed with Ctrl + Shift + Enter)

This would seem to cover the ever changing export from the facility's scheduling application safely and eliminate the need for absolute references. I've tried it quickly in my workbook and it doesn't seem to work - mostly NA errors.

Thank you for your help so far, you've been great!
 
Upvote 0
Your are welcome, thanks for the feedback.

I do not know why your version with named ranges does not work. An analysis using the Formula/Evaluate function may help to locate the function where the N/A error comes from.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top