Replace values on multiple worksheets

excel_2009

Active Member
Joined
Sep 14, 2009
Messages
318
Hi All,

I have the following information on my "Home" worksheet:

[TABLE="width: 500"]
<tbody>[TR]
[TD]Column A[/TD]
[TD]Column B[/TD]
[/TR]
[TR]
[TD]Sku[/TD]
[TD]8008989[/TD]
[/TR]
[TR]
[TD]Title[/TD]
[TD]Brand new in box[/TD]
[/TR]
[TR]
[TD]Quantity[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Brand[/TD]
[TD]Sergio Technini[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

I also have several worksheets called: Data 1, DataSheet 2, Misc which contains near identical information, the aim is to replace the current values in these worksheets with the values above (in column B, Home worksheet) IF the values are populated, if they're blank then nothing will be replaced i.e in the example above the Quantity value would be ignored and the original Quantity value would remain as is on the Data 1, DataSheet2 and Misc worksheet.

The worksheet information is structured in the following manner (in one Column, always Column A - irrespective of worksheet):

[TABLE="width: 500"]
<tbody>[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"]"Sku": "5170092602",[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"]"Title": "Test do not buy",[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"] "Quantity": 1,[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"] "Brand": "Nike",[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

So with the above in mind the following would be updated to show the following (based on the input provided on the Home worksheet):

[TABLE="width: 500"]
<tbody>[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"]"Sku": "8008989",[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"]"Title": "Brand new in box",[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"] "Quantity": 1,[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 186"]
<tbody>[TR]
[TD="class: xl65, width: 186"] "Brand": "Sergio Technini",[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Does anyone know how this can be achieved?

Many thanks!!!
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Try:
Code:
Sub ReplaceVal()
    Application.ScreenUpdating = False
    Dim LastRow As Long, rng As Range, splitRng As Range, ws As Worksheet, srcWS As Worksheet, fnd As Range
    Set srcWS = Sheets("Home")
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    For Each rng In srcWS.Range("A1:A" & LastRow)
        If rng.Offset(0, 1) <> "" Then
            For Each ws In Sheets
                If ws.Name <> "Home" Then
                    Set fnd = ws.Range("A:A").Find("""" & rng & """", LookIn:=xlValues, lookat:=xlPart)
                    If Not fnd Is Nothing Then
                        fnd = Replace(fnd, Split(fnd, ": ")(1), """" & rng.Offset(0, 1) & """,")
                    End If
                End If
            Next ws
        End If
    Next rng
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Actually there is one last thing!, I did try and merge some exisisting working coding alongside yours but the values aren't updating, any idea why this might be? (the previous code is stored in the sheet and not as a macro, the idea is for the dropdown to be selected and the values are updated (if any) thereafter the selected worksheet is copied to the clipboard :)

Code:
Private Sub Worksheet_Change(ByVal Target As Range)



    
    Dim LastRow As Long, rng As Range, splitRng As Range, ws As Worksheet, srcWS As Worksheet, fnd As Range
    Set srcWS = Sheets("Home")
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    For Each rng In srcWS.Range("D4:D9" & LastRow)
        If rng.Offset(0, 1) <> "" Then
            For Each ws In Sheets
                If ws.Name <> "Home" Then
                    Set fnd = ws.Range("A:A").Find("""" & rng & """", LookIn:=xlValues, lookat:=xlPart)
                    If Not fnd Is Nothing Then
                        fnd = Replace(fnd, Split(fnd, ": ")(1), """" & rng.Offset(0, 1) & """,")
                    End If
                End If
            Next ws
        End If
    Next rng










If Target.Address = Range("D10").Address Then
If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
On Error GoTo M
Dim LastRow2 As Long
Dim ans As String
ans = Target.Value
LastRow2 = Sheets(ans).Cells(Rows.Count, "A").End(xlUp).Row
Sheets(ans).Range("A1:A" & LastRow2).Copy
End If




Exit Sub
M:
MsgBox "There is no sheet named  " & ans


    Application.ScreenUpdating = True


End Sub
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,260
Members
452,627
Latest member
KitkatToby

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