Assign value into cell on different worksheet using VBA

Dspace

New Member
Joined
Nov 2, 2020
Messages
17
Office Version
  1. 365
Platform
  1. Windows
I have this code that runs a simple macro all on one worksheet. I have multiple macros like this that are very similar but hide/unhide different rows of a master price worksheet.

What I'm looking to do is to have this macro enter 1 value into a cell (G1) into a different worksheet named "hardware". I have different sales teams using the same pricing tool but different pay margins based on the cell in G1 (password protected). I've never used a macro that changes values on a different worksheet.

Thanks for the help!

Sub UnHideITSC()
'Unhides everytying without a "1" in column B; our standard sales team/vCIOs
Unprotect Password:="password"
For Each cell In Range("b19:b837")
If cell.Value = 1 Then
cell.EntireRow.Hidden = False
Else:
cell.EntireRow.Hidden = True
End If
Next cell

'hiding grouped rows
Rows("20:27").EntireRow.Hidden = True
Rows("31:35").EntireRow.Hidden = True
Rows("38:40").EntireRow.Hidden = True
Rows("43").EntireRow.Hidden = True
Rows("48:55").EntireRow.Hidden = True
Rows("230:325").EntireRow.Hidden = True
Rows("328:423").EntireRow.Hidden = True
Rows("426:521").EntireRow.Hidden = True
Rows("524:619").EntireRow.Hidden = True

ActiveSheet.Protect Password:="password", AllowFormattingCells:=True
End Sub
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Add this line in the place where you want it to happen:
VBA Code:
Worksheets("hardware").Range("G1").Value = 1

However, if sheet hardware is password protected you will need more:
Rich (BB code):
With Worksheets("hardware")
   .Unprotect "password"
   .Range("G1").Value = 1
   .Protect "password"
End With

Replace password with whatever your password actually is.

What module is your code in? If it is in a standard module, like Module1, all of your references to things in a sheet like Range("b19:b837") will be assumed to be for the current ActiveSheet. If it is in a worksheet module, they will be assumed to be for that worksheet.

Also you don't need a ":" after your Else. I would suggest removing it to avoid any confusion.
 
Upvote 0
Add this line in the place where you want it to happen:
VBA Code:
Worksheets("hardware").Range("G1").Value = 1

However, if sheet hardware is password protected you will need more:
Rich (BB code):
With Worksheets("hardware")
   .Unprotect "password"
   .Range("G1").Value = 1
   .Protect "password"
End With

Replace password with whatever your password actually is.

What module is your code in? If it is in a standard module, like Module1, all of your references to things in a sheet like Range("b19:b837") will be assumed to be for the current ActiveSheet. If it is in a worksheet module, they will be assumed to be for that worksheet.

Also you don't need a ":" after your Else. I would suggest removing it to avoid any confusion.
Problem solved! thank you. And yes. It was password protected so thanks for that add-on. It was needed. I love this message board!
 
Upvote 0

Forum statistics

Threads
1,214,787
Messages
6,121,565
Members
449,038
Latest member
Guest1337

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