> I can solve with code but it takes alot of it
Is it possible that you could open Notepad, copy your code in from the Excel VBEditor, save it as a Text document (TXT extension) and then post it as an attachment here in the Lounge?
![]() |
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 |
-
Replace values (Excel 2000 VBA)
Home » Forums » AskWoody support » Productivity software by function » Visual Basic for Applications » Replace values (Excel 2000 VBA)
- This topic has 7 replies, 3 voices, and was last updated 21 years, 4 months ago.
AuthorTopicWSunkamunka
AskWoody LoungerFebruary 10, 2004 at 3:49 pm #400508Viewing 0 reply threadsAuthorReplies-
WSmaxbaney
AskWoody LoungerFebruary 10, 2004 at 4:57 pm #781826Subject Edited by HansV to make it more descriptive than “Excel”
I have a problem with an Excel worksheet that I can solve with code but it takes alot of it. This problem relates to golf and a league I’m setting up for the year. On sheet1 I have i.g. 20 names in Col A and their newly updated handicaps in Col B. On sheet2 I have 100 names in Col A and their last years handicaps in Col B. What I would like to do is replace the handicaps on Sheet2 Col B with the newly updated handicaps from Sheet1 Col B. The names on sheet 1, Col A, will not be in the same order as the names on Sheet2 Col A. Sheet1 contains the golfers playing the current week which will change from week to week.
Hopefully I have submitted enough information. I would like to do this with alot less code.
Thank you,
Max -
H. Legare Coleman
AskWoody PlusFebruary 10, 2004 at 4:02 pm #781955Here is the easy way to do this without VBA:
Go to Sheet 2 and select an empty column. Insert the formula below into row 1 of that column:
=IF(ISERROR(VLOOKUP(A1,Sheet1!$A$1:$B$20,2,FALSE)),B1,VLOOKUP(A1,Sheet1!$A$1:$B$20,2,FALSE))
Copy this formula down the column as far as there are names and handicaps in columns A & B.
This column should now display the updated handicaps.
Now, select the column with the updated handicaps and select Copy from The Edit menu. Then select cell B1 and then select “Paste Special” from the edit menu. Put a tic mark next to Values in the Paste section of the dialog box. Click the OK button and the updated handicaps should be put into column B. Now you can delete the column with the formulas.
-
H. Legare Coleman
AskWoody PlusFebruary 10, 2004 at 4:02 pm #781956Here is the easy way to do this without VBA:
Go to Sheet 2 and select an empty column. Insert the formula below into row 1 of that column:
=IF(ISERROR(VLOOKUP(A1,Sheet1!$A$1:$B$20,2,FALSE)),B1,VLOOKUP(A1,Sheet1!$A$1:$B$20,2,FALSE))
Copy this formula down the column as far as there are names and handicaps in columns A & B.
This column should now display the updated handicaps.
Now, select the column with the updated handicaps and select Copy from The Edit menu. Then select cell B1 and then select “Paste Special” from the edit menu. Put a tic mark next to Values in the Paste section of the dialog box. Click the OK button and the updated handicaps should be put into column B. Now you can delete the column with the formulas.
-
H. Legare Coleman
AskWoody PlusFebruary 10, 2004 at 4:22 pm #781963If you want to do this with code, then the code below should do what you want (not really a lot of code). It has the additional advantage that if there is a name on sheet1 that is not on sheet2, the code will add it to sheet 2.
Public Sub UpdateHandicaps() Dim lLastRowNew As Long, lLastRowOld As Long, I As Long, J As Long lLastRowNew = Worksheets("Sheet1").Range("A65536").End(xlUp).Row - 1 For I = 0 To lLastRowNew lLastRowOld = Worksheets("Sheet2").Range("A65536").End(xlUp).Row - 1 For J = 0 To lLastRowOld If Worksheets("Sheet1").Range("A1").Offset(I, 0) = _ Worksheets("Sheet2").Range("A1").Offset(J, 0) Then Worksheets("Sheet2").Range("A1").Offset(J, 1) = _ Worksheets("Sheet1").Range("A1").Offset(I, 1) Exit For End If Next J If J > lLastRowOld Then Worksheets("Sheet2").Range("A1").Offset(J, 0) = _ Worksheets("Sheet1").Range("A1").Offset(I, 0) Worksheets("Sheet2").Range("A1").Offset(J, 1) = _ Worksheets("Sheet1").Range("A1").Offset(I, 1) End If Next I End Sub
-
H. Legare Coleman
AskWoody PlusFebruary 10, 2004 at 4:22 pm #781964If you want to do this with code, then the code below should do what you want (not really a lot of code). It has the additional advantage that if there is a name on sheet1 that is not on sheet2, the code will add it to sheet 2.
Public Sub UpdateHandicaps() Dim lLastRowNew As Long, lLastRowOld As Long, I As Long, J As Long lLastRowNew = Worksheets("Sheet1").Range("A65536").End(xlUp).Row - 1 For I = 0 To lLastRowNew lLastRowOld = Worksheets("Sheet2").Range("A65536").End(xlUp).Row - 1 For J = 0 To lLastRowOld If Worksheets("Sheet1").Range("A1").Offset(I, 0) = _ Worksheets("Sheet2").Range("A1").Offset(J, 0) Then Worksheets("Sheet2").Range("A1").Offset(J, 1) = _ Worksheets("Sheet1").Range("A1").Offset(I, 1) Exit For End If Next J If J > lLastRowOld Then Worksheets("Sheet2").Range("A1").Offset(J, 0) = _ Worksheets("Sheet1").Range("A1").Offset(I, 0) Worksheets("Sheet2").Range("A1").Offset(J, 1) = _ Worksheets("Sheet1").Range("A1").Offset(I, 1) End If Next I End Sub
-
WSmaxbaney
AskWoody Lounger -
WSmaxbaney
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
-
Excessive security alerts
by
WSSebastian42
4 hours, 48 minutes ago -
* CrystalDiskMark may shorten SSD/USB Memory life
by
Alex5723
5 hours, 36 minutes ago -
Ben’s excellent adventure with Linux
by
Ben Myers
4 minutes ago -
Seconds are back in Windows 10!
by
Susan Bradley
6 hours, 48 minutes ago -
WebBrowserPassView — Take inventory of your stored passwords
by
Deanna McElveen
2 hours, 39 minutes ago -
OS news from WWDC 2025
by
Will Fastie
6 hours, 50 minutes ago -
Need help with graphics…
by
WSBatBytes
5 hours, 31 minutes ago -
AMD : Out of Bounds (OOB) read vulnerability in TPM 2.0 CVE-2025-2884
by
Alex5723
21 hours, 4 minutes ago -
Totally remove or disable BitLocker
by
CWBillow
19 hours, 57 minutes ago -
Windows 10 gets 6 years of ESU?
by
n0ads
7 hours, 53 minutes ago -
Apple, Google stores still offer China-based VPNs, report says
by
Nibbled To Death By Ducks
1 day, 7 hours ago -
Search Forums only bring up my posts?
by
Deo
1 day, 8 hours ago -
Windows Spotlight broken on Enterprise and Pro for Workstations?
by
steeviebops
1 day, 19 hours ago -
Denmark wants to dump Microsoft for Linux + LibreOffice
by
Alex5723
1 day, 12 hours ago -
How to get Microsoft Defender to honor Group Policy Setting
by
Ralph
1 day, 20 hours ago -
Apple : Paragon’s iOS Mercenary Spyware Finds Journalists Target
by
Alex5723
2 days, 6 hours ago -
Music : The Rose Room – It’s Been A Long, Long Time album
by
Alex5723
2 days, 7 hours ago -
Disengage Bitlocker
by
CWBillow
1 day, 21 hours ago -
Mac Mini M2 Service Program for No Power Issue
by
Alex5723
2 days, 9 hours ago -
New Win 11 Pro Geekom Setup questions
by
Deo
1 day, 7 hours ago -
Windows 11 Insider Preview build 26200.5651 released to DEV
by
joep517
2 days, 16 hours ago -
Windows 11 Insider Preview build 26120.4441 (24H2) released to BETA
by
joep517
2 days, 16 hours ago -
iOS 26,, MacOS 26 : Create your own AI chatbot
by
Alex5723
2 days, 20 hours ago -
New PC transfer program recommendations?
by
DaveBoston
1 day, 1 hour ago -
Windows 11 Insider Preview Build 22631.5545 (23H2) released to Release Preview
by
joep517
3 days ago -
Windows 10 Build 19045.6029 (22H2) to Release Preview Channel
by
joep517
3 days ago -
Best tools for upgrading a Windows 10 to an 11
by
Susan Bradley
2 days, 13 hours ago -
The end of Windows 10 is approaching, consider Linux and LibreOffice
by
Alex5723
1 day, 17 hours ago -
Extended Windows Built-in Disk Cleanup Utility
by
bbearren
2 days, 1 hour ago -
Win 11 24H2 June 2025 Update breaks WIFI
by
dportenlanger
3 days, 19 hours ago
Recent blog posts
- Ben’s excellent adventure with Linux
- Seconds are back in Windows 10!
- WebBrowserPassView — Take inventory of your stored passwords
- OS news from WWDC 2025
- Best tools for upgrading a Windows 10 to an 11
- Master patch listing for June 10, 2025
- 24H2 may not be offered June updates
- June 2025 updates are out
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.