Automate goal seek in two separate worksheets?

tbl921

New Member
Joined
Aug 15, 2018
Messages
1
Hi, I have a model that takes inputs to calculate the estimated cost of a new building. A second output is the estimated monthly payment to finance that cost. This output is based on one of two financing options, which a user selects from a drop down menu. The calculations for that monthly payment are on a distinct tab for each financing option. The calculation lays out, month by month, the loan principle, the monthly payment, and the end of month balance, for the entire term (one option's term is 30 years, the other is 40). I can of course use goal seek for the last end of month balance in each term to determine what the monthly payment would be. But on my forecast sheet, where the user can select inputs (e.g., how many people will live in the building and which financing option to use), the monthly payment is not correct until I manually go to that financing option's tab and run goal seek.

Is there a way to automate goal seek on each of those tabs, so that when the other model parameters change, the goal seek function runs automatically to determine the estimated monthly payment? I have tried some VBA codes pulled from forums, and also tried to record a macro for each tab, but am so far unsuccessful.

Thanks for any help!
 

Worf

Well-known Member
Joined
Oct 30, 2011
Messages
3,802
Welcome to the Board

Code:
'ThisWorkbook module
Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
Dim sh1 As Worksheet, sh2 As Worksheet
Set sh1 = Sheets("sheet1")
Set sh2 = Sheets("sheet2")
Select Case Sh.Name
    Case "Sheet1"
        If Not Intersect(Target, sh1.[c4:c13]) Is Nothing Then sh2.[c11].GoalSeek sh2.[e9], sh2.[c4]
    Case "Sheet2"
        If Not Intersect(Target, sh2.[c4:c13]) Is Nothing Then sh1.[c11].GoalSeek sh1.[e9], sh1.[c4]
End Select
End Sub
 

Forum statistics

Threads
1,082,316
Messages
5,364,483
Members
400,802
Latest member
RichBRich

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top