VBA to change a formula in a cell with a command button?

Robert_G

New Member
Joined
Jul 13, 2018
Messages
48
I have this code started in C12 and continues down to C31......

=IF(ROW()<$D$4+12,$F$4-((($F$4-($F$4/$B$4))/($D$4-1))*(ROW()-12)),"")

There's a few things going on here but essentially the value will "turn down" in division based on a value in B4 and Full Scale in F4.

I was thinking how valuable it would be with a click of a command button to now have it Multiply, "Turn Up" the value in F4 if needed. The formula would be the exact same formula except where I highlighted the formula it would now multiply instead of divide.

Anyone have an idea what might be the best way for this to be done or written in VBA?
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
Ok create a sheet button and change the text to read: Click for turn up
Then create the macro and assign it to the button.

Code:
Sub clickformulatoggle()
lastrow = ActiveSheet.Cells.Find(What:="*", SearchDirection:=xlPrevious, SearchOrder:=xlByRows).Row
If ActiveSheet.Buttons(Application.Caller).Text = "Click for turn down" Then
'divide
ActiveSheet.Buttons(Application.Caller).Text = "Click for turn up"
Range("C12").Formula = "=IF(ROW()<$D$4+12,$F$4-((($F$4-([B]$F$4/$B$4[/B]))/($D$4-1))*(ROW()-12)),"""")"
Else
'multiply
ActiveSheet.Buttons(Application.Caller).Text = "Click for turn down"
Range("C12").Formula = "=IF(ROW()<$D$4+12,$F$4-((($F$4-([B]$F$4*$B$4[/B]))/($D$4-1))*(ROW()-12)),"""")"
End If
'autofill
Range("C12").AutoFill Destination:=Range("C12:C" & lastrow), Type:=xlFillDefault
End Sub
It will change the text of the button when pressed and will also drag down the formula to the last row dynamically.
 
Upvote 0

Forum statistics

Threads
1,214,585
Messages
6,120,394
Members
448,957
Latest member
Hat4Life

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