I have a user who needs to combine or merge two worksheets. He received one worksheet from human resources and the other from the state – the one from HR is more current and he needs to take that worksheet and add it to the state worksheet. The problem is that the state lists certain employees, say 1-1000 and they are sorted by SS#s. The HR lists new employees also in order by SS#s. How can you insert the new employees – into the state worksheet and keep the order the same. The state worksheets have blank columns that I want to populate with the HR info. I know this is hard to understand or maybe I just cannot explain it correctly. I looked at sharing documents and accepting and rejecting revisions, but the documents are NOT two versions of the same file. They are two separate workbooks.
![]() |
Patch reliability is unclear. Unless you have an immediate, pressing need to install a specific patch, don't do it. |
SIGN IN | Not a member? | REGISTER | PLUS MEMBERSHIP |
-
Merging worksheets (Excel 2000 sr-1)
Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » Merging worksheets (Excel 2000 sr-1)
- This topic has 9 replies, 3 voices, and was last updated 23 years, 2 months ago.
Viewing 0 reply threadsAuthorReplies-
WSBat17
AskWoody Lounger -
WSMelanie
AskWoody LoungerFebruary 1, 2002 at 5:17 pm #567756OK – I knew I didn’t explain this correctly. Two separate worksheets, let’s call them master sheet and update sheet. The master sheet has everyone’s name, rank, SS#, etc up to 10 columns, some of the columns are blank and will be populated by the update sheet. Once a week the state sends a new updated sheet with new employees and all their info. This info needs to be put into the master sheet but the columns do not match up. The existing employees are already on both the master and update sheet so if you paste each column, you get two of the same person. I will think about how to explain it better. thanks
-
H. Legare Coleman
AskWoody PlusFebruary 1, 2002 at 5:24 pm #567759It sounds this will require a macro to accomplish. However, it will be almost impossible to write a macro without seeing what the worksheets look like. Could you create a dummy workbook that has two worksheets that look like what you have and that have some dummy data in them and attach that workbook to a reply to this message?
-
WSMelanie
AskWoody Lounger -
WSMelanie
AskWoody Lounger -
H. Legare Coleman
AskWoody PlusFebruary 2, 2002 at 12:31 am #567856OK, I got the workbooks and I see the general idea of what you want to do. However, I still have a few questions:
1- Column A in both workbooks appears to be an ID number of some kind. However, in the Master workbook the values in this column are text and in the Update book they are numbers. Is this the way it will be in the real workbooks?
2- In these workbooks, it looks like column B in the Master and Column C in the Update book contain a name. However, in these workbooks, the names for the same ID number do not match. What do you want to happen when the master is updated from the Update book?
3- In the Update book that you sent, row 10 contains an ID number, but the other cells on this row are empty. What should the update do with this ID?
4- Column E in the Update book and Column C in the Master look like they might be the same information. What should the update do when the information in the update book is different from that in the Master?
5- In the Update book, columns B, D, F, G, H, and I do not appear to be in the Master. Should the update just add them as columns F, G, H, I, J, and K?
6- The update book you sent did not have any IDs that were not in the master. Is this how it will always be? If not, what should happen if there is an ID that is not in the Master? Just add it to the end of the Master?
-
WSMelanie
AskWoody Lounger -
H. Legare Coleman
AskWoody PlusFebruary 4, 2002 at 4:18 pm #568159Ok, glad you got it solved. In case you need to do this often and would rather use an all Excel solution, I am posting the macro I wrote last Friday. It does not take into account the questions I asked in my previous quote.
Public Sub UpdateMaster() Dim strWk As String Dim oUpdateBook As Workbook, oUpdate As Worksheet, oMaster As Worksheet Dim I As Long, J As Long, K As Long Dim vFileName As Variant Application.ScreenUpdating = False vFileName = Application.GetOpenFilename(Title:="Select Update File") If vFileName = False Then Exit Sub Workbooks.Open Filename:=vFileName Set oUpdateBook = ActiveWorkbook Set oUpdate = oUpdateBook.Worksheets("Sheet1") Set oMaster = ThisWorkbook.Worksheets("Sheet1") I = 0 While oUpdate.Range("A1").Offset(I, 0).Value "" J = 0 While oMaster.Range("A1").Offset(J, 0).Value "" And _ oMaster.Range("A1").Offset(J, 0).Value oUpdate.Range("A1").Offset(I, 0).Value J = J + 1 Wend oMaster.Range("A1").Offset(J, 0).Value = oUpdate.Range("A1").Offset(I, 0).Value oMaster.Range("A1").Offset(J, 1).Value = oUpdate.Range("A1").Offset(I, 2).Value oMaster.Range("A1").Offset(J, 2).Value = oUpdate.Range("A1").Offset(I, 4).Value oMaster.Range("A1").Offset(J, 5).Value = oUpdate.Range("A1").Offset(I, 1).Value oMaster.Range("A1").Offset(J, 6).Value = oUpdate.Range("A1").Offset(I, 3).Value oMaster.Range("A1").Offset(J, 7).Value = oUpdate.Range("A1").Offset(I, 5).Value oMaster.Range("A1").Offset(J, 8).Value = oUpdate.Range("A1").Offset(I, 6).Value oMaster.Range("A1").Offset(J, 9).Value = oUpdate.Range("A1").Offset(I, 7).Value oMaster.Range("A1").Offset(J, 10).Value = oUpdate.Range("A1").Offset(I, 8).Value oMaster.Range("A1").Offset(J, 11).Value = oUpdate.Range("A1").Offset(I, 9).Value I = I + 1 Wend oUpdateBook.Close Set oUpdateBook = Nothing Set oUpdate = Nothing Set oMaster = Nothing Application.ScreenUpdating = True End Sub
-
WSMelanie
AskWoody Lounger
-
-
-
-
Viewing 0 reply threads -

Plus Membership
Donations from Plus members keep this site going. You can identify the people who support AskWoody by the Plus badge on their avatars.
AskWoody Plus members not only get access to all of the contents of this site -- including Susan Bradley's frequently updated Patch Watch listing -- they also receive weekly AskWoody Plus Newsletters (formerly Windows Secrets Newsletter) and AskWoody Plus Alerts, emails when there are important breaking developments.
Get Plus!
Welcome to our unique respite from the madness.
It's easy to post questions about Windows 11, Windows 10, Win8.1, Win7, Surface, Office, or browse through our Forums. Post anonymously or register for greater privileges. Keep it civil, please: Decorous Lounge rules strictly enforced. Questions? Contact Customer Support.
Search Newsletters
Search Forums
View the Forum
Search for Topics
Recent Topics
-
Download speeds only 0.3Mbps after 24H2 upgrade on WiFi and Ethernet
by
John
4 hours, 43 minutes ago -
T-Mobile 5G Wireless Internet
by
WSmmi16
3 hours, 43 minutes ago -
Clock missing above calendar in Windows 10
by
WSCape Sand
2 hours, 8 minutes ago -
Formula to Calculate Q1, Q2, Q3, or Q4 of the Year?
by
WSJon5
2 hours, 50 minutes ago -
The time has come for AI-generated art
by
Catherine Barrett
17 hours, 31 minutes ago -
Hackers are using two-factor authentication to infect you
by
B. Livingston
11 hours, 32 minutes ago -
23 and you
by
Max Stul Oppenheimer
17 hours, 33 minutes ago -
April’s deluge of patches
by
Susan Bradley
4 hours ago -
Windows 11 Windows Updater question
by
Tex265
9 hours, 46 minutes ago -
Key, Key, my kingdom for a Key!
by
RetiredGeek
1 day, 8 hours ago -
Registry Patches for Windows 10
by
Drcard:))
1 day, 13 hours ago -
Cannot get line length to NOT wrap in Outlining in Word 365
by
CWBillow
19 hours, 45 minutes ago -
DDU (Display Driver Uninstaller) updates
by
Alex5723
5 hours, 3 minutes ago -
Align objects on a OneNote page
by
CWBillow
1 day, 18 hours ago -
OneNote Send To button?
by
CWBillow
1 day, 19 hours ago -
WU help needed with “Some settings are managed by your organization”
by
Peobody
2 days, 3 hours ago -
No Newsletters since 27 January
by
rog7
8 hours, 30 minutes ago -
Linux Mint Debian Edition 7 gets OEM support, death of Ubuntu-based Mint ?
by
Alex5723
1 day, 4 hours ago -
Windows Update “Areca Technology Corporation – System – 6.20.0.41”
by
Bruce
1 day, 3 hours ago -
Google One Storage Questions
by
LHiggins
11 hours, 6 minutes ago -
Button Missing for Automatic Apps Updates
by
pmcjr6142
18 hours, 22 minutes ago -
Ancient SSD thinks it’s new
by
WSila
1 day, 9 hours ago -
Washington State lab testing provider exposed health data of 1.6 million people
by
Nibbled To Death By Ducks
2 days, 18 hours ago -
WinRE KB5057589 fake out
by
Susan Bradley
5 hours, 20 minutes ago -
The April 2025 Windows RE update might show as unsuccessful in Windows Update
by
Susan Bradley
2 days, 2 hours ago -
Firefox 137
by
Charlie
5 hours, 17 minutes ago -
Whisky, a popular Wine frontend for Mac gamers, is no more
by
Alex5723
3 days, 7 hours ago -
Windows 11 Insider Preview build 26120.3863 (24H2) released to BETA
by
joep517
3 days, 7 hours ago -
Windows 11 Insider Preview build 26200.5551 released to DEV
by
joep517
3 days, 7 hours ago -
New Windows 11 PC setup — can I start over in the middle to set up a local id?
by
ctRanger
2 days, 3 hours ago
Recent blog posts
Key Links
Want to Advertise in the free newsletter? How about a gift subscription in honor of a birthday? Send an email to sb@askwoody.com to ask how.
Mastodon profile for DefConPatch
Mastodon profile for AskWoody
Home • About • FAQ • Posts & Privacy • Forums • My Account
Register • Free Newsletter • Plus Membership • Gift Certificates • MS-DEFCON Alerts
Copyright ©2004-2025 by AskWoody Tech LLC. All Rights Reserved.