+ Reply to Thread
Results 1 to 4 of 4

Change a cell populated by a dropdown when the value of the source range changes

Hybrid View

AAbrams Change a cell populated by a... 08-29-2013, 01:34 PM
JBeaucaire Re: Change a cell populated... 08-29-2013, 02:15 PM
AAbrams Re: Change a cell populated... 08-29-2013, 03:49 PM
JBeaucaire Re: Change a cell populated... 08-29-2013, 04:10 PM
  1. #1
    Registered User
    Join Date
    08-29-2013
    Location
    NC, USA
    MS-Off Ver
    Excel 2007
    Posts
    13

    Change a cell populated by a dropdown when the value of the source range changes

    I am trying to fill a series of cells from a dropdown box which refers to named range in a different worksheet within the same workbook. The values of the range are subject to change based on other variables and I want the end-use cells to vary as the range values change. In the attached demo sheet, On the worksheet "Labor" I want the values to change when the inflation escalators on the worksheet "Assumptions" change the labor rates in the named ranges on the worksheet "Assumptions."

    What actually happens is that when the range changes, then the selections in the dropdown change, but not the actual values in the fields, meaning my projections don't flow through the entire workbook properly.

    Any suggestions are welcome
    Attached Files Attached Files

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Change a cell populated by a dropdown when the value of the source range changes

    The only way to do this I know of is through VBA. When you use the drop downs to select a value on the LABOR sheet, the selection is immediately replaced with a formula that gives the same result. This way if you go back and change the Assumptions, the new values flow back to your previous selections on the LABOR sheet.

    This has been added to the LABOR sheet code module:
    Option Explicit
    
    Private Sub Worksheet_Change(ByVal Target As Range)
    'Author:    Jerry Beaucaire,  8/12/2011
    'Summary:   Make choices from DV drop downs into formulas, so any changes
    '           in the source lists will flow out to the already filled in cells
    Dim strValidationList As String
    Dim strVal As String
    Dim lngNum As Long
    
    If Target.Cells.Count > 1 Then Exit Sub
    If Target.Value = "" Then Exit Sub
    
    On Error GoTo Nevermind
    strValidationList = Mid(Target.Validation.Formula1, 2)
    strVal = Target.Value
    lngNum = Evaluate("MATCH(" & strVal & ", " & strValidationList & ", 0)")
    
    If strVal <> "" And lngNum > 0 Then
        Application.EnableEvents = False
        Target.Formula = "=INDEX(" & strValidationList & ", " & lngNum & ")"
    End If
    
    Nevermind:
        Application.EnableEvents = True
        
    End Sub

    Before that would work, however, I had to fix the decimal errors hidden in your ASSUMPTIONS. When you multiply decimal values the results are almost always LONG decimal values. $ values stop at 2 decimal values so your number formatting was hiding the errors. You should always apply rounding to decimal values that have been multiplied to insure the DISPLAYED value is the real value in the cell.
    Attached Files Attached Files
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  3. #3
    Registered User
    Join Date
    08-29-2013
    Location
    NC, USA
    MS-Off Ver
    Excel 2007
    Posts
    13

    Re: Change a cell populated by a dropdown when the value of the source range changes

    Awesome! Thank you, Jerry, for solving this for me. Why does the rounding issue create a problem here?

  4. #4
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Change a cell populated by a dropdown when the value of the source range changes

    The values look like 10.98 for instance, but instead were actually 10.9833423343 or something like that.

    Data validation is a TEXT function, so the Drop Down shows you the text that is displayed in those cells and enters that exact value into the cell.

    The way the macro works is it looks at the value just entered, then creates a formula that displays that same "position" from the data validation source list. So it searches the DV range for the value entered.... and wasn't finding them since the DV list had other values formatted to appear like two decimals.

    The ROUND() function makes the values IN the cell the same as the values DISPLAYED to the user. Two decimal places.

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED. Thanks.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Show a dropdown when another field is populated
    By Lata in forum Excel General
    Replies: 11
    Last Post: 01-29-2013, 03:43 PM
  2. Y Axis data source changes based on the Named range listed in Dropdown
    By aravindhan_31 in forum Excel Charting & Pivots
    Replies: 5
    Last Post: 11-09-2012, 12:43 AM
  3. Dropdown list cell populated automatically
    By processchip in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 02-16-2011, 03:22 PM
  4. Returning Last Populated Cell in a range
    By RDMRDM in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 05-08-2009, 07:17 PM
  5. Change populated cell names via macro
    By TJM in forum Excel General
    Replies: 2
    Last Post: 09-12-2006, 10:47 PM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1