+ Reply to Thread
Results 1 to 6 of 6

Drop-down lists - circular reference

  1. #1
    Registered User
    Join Date
    07-25-2010
    Location
    UK
    MS-Off Ver
    Excel 2008 Mac
    Posts
    4

    Question Drop-down lists - circular reference

    Hi all,

    I wonder if anyone can help me...

    I have a spreadsheet (attached) which I am working on to keep account of purchasing expenditure.

    I have two columns - 'account code' and 'account description'. I am looking to achieve the following:

    Users should be able to type in the account code if they know it, or find the relevant account description (via drop down) instead. So far, I have used VLOOOKUP so that if you type in the code, it will update the description field... HOWEVER... I cannot get it to work the other way round without causing a circular reference.

    For example, I want to be able to select the 'Cleaning Materials' account, and excel will automatically populate the relevant account code (113001).

    Any assistance would be greatly appreciated!

    Cheers,
    Martin
    Attached Files Attached Files

  2. #2
    Forum Contributor
    Join Date
    05-16-2010
    Location
    UK
    MS-Off Ver
    2003 and 2007
    Posts
    252

    Re: Drop-down lists - circular reference

    Using your existing named ranges, you could use Data Validation lists. When cell E4 has a value, there will be only one option in the Data Validation list in cell F4 and vice versa. You would have to select the value to populate the cell.

    Cell E4 on Expenditure worksheet. Data Validation - List - Source:

    =IF($F$4="",GL_Account_Code,INDEX(GL_Account_Code,MATCH(F4,GL_Account_Description,0)))

    Cell F4 on Expenditure worksheet. Data Validation - List - Source:

    =IF($E$4="",GL_Account_Description,INDEX(GL_Account_Description,MATCH(E4,GL_Account_Code,0)))

    VBA is another option.
    Last edited by pb71; 07-25-2010 at 05:07 PM. Reason: Clarification of Data Validation List and not cell formula

  3. #3
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,082

    Re: Drop-down lists - circular reference

    You'd have to do this with VBA. You cant have a formula for the Account Code AND the Account Description.

    You need a WorkSheet Change Event which will look something like:

    Please Login or Register  to view this content.

    You'll need to remove the existing formula but retain both drop down lists.

    Regards

  4. #4
    Registered User
    Join Date
    07-25-2010
    Location
    UK
    MS-Off Ver
    Excel 2008 Mac
    Posts
    4

    Re: Drop-down lists - circular reference

    Quote Originally Posted by pb71 View Post
    Using your existing named ranges, you could use Data Validation lists. When cell E4 has a value, there will be only one option in the Data Validation list in cell F4 and vice versa. You would have to select the value to populate the cell.

    Cell E4 on Expenditure worksheet. Source:

    =IF($F$4="",GL_Account_Code,INDEX(GL_Account_Code,MATCH(F4,GL_Account_Description,0)))

    Cell F4 on Expenditure worksheet. Source:

    =IF($E$4="",GL_Account_Description,INDEX(GL_Account_Description,MATCH(E4,GL_Account_Code,0)))

    VBA is another option.
    Thanks for that, I've input those formulas

    However, I seem to have a hit a problem whereby, whichever cell I select first (code or description) while it now updates the 2nd cell, if I go in to change the 2nd cell - it won't update the original.

    For example, I go in and select 121005, it updates the description to 'Transportation Services' but if I was to then change the description drop down to say 'Cleaning Materials, the code would not update?

    Quote Originally Posted by TMShucks View Post
    You'd have to do this with VBA. You cant have a formula for the Account Code AND the Account Description.

    You need a WorkSheet Change Event which will look something like:

    You'll need to remove the existing formula but retain both drop down lists.

    Regards
    Thanks again, I won't be able to try VBA until I am in work as I am currently working on a mac with Office 2008.

    A question for both of you, what exactly can the above VBA code do that the Data Validation lists cant?

    Just incase I am over complicating things... is there any other way of giving the user the option to either enter in a code or select from a drop down list to give the same result?

    I appreciate your assistance so far.

  5. #5
    Forum Contributor
    Join Date
    05-16-2010
    Location
    UK
    MS-Off Ver
    2003 and 2007
    Posts
    252

    Re: Drop-down lists - circular reference

    The Data Validation List method will not update the corresponding cell value automatically. If you change the value in either cell E4 or F4 manually, the validation list dropdown in the other cell will have the single corresponding Account Code or Description and you will have to select this single value from the list to populate the cell.

    If you delete either of the cell values you will see the full list in the other cell.

    VBA code should update the corresponding cell value automatically.

    EDIT:

    Just incase I am over complicating things... is there any other way of giving the user the option to either enter in a code or select from a drop down list to give the same result?
    I would probably use the Worksheet Change event approach with the following Data Validation lists:

    Cell E4: Data Validation - List - Source:

    =GL_Account_Code

    Cell F4: Data Validation - List - Source:

    =GL_Account_Description
    Last edited by pb71; 07-25-2010 at 06:14 PM.

  6. #6
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,082

    Re: Drop-down lists - circular reference

    I hadn't realised that you could use Data Validation in the way described ... that's quite impressive. As pb71 has explained, you need to select a value from one list and then choose the only available option from the second list. Hence, you have to make two selections (albeit, the second is a foregone conclusion). I *think" you will need to delete both entries in order to change corresponding values.

    If you do elect to use this approach, I'd recommend using dynamic ranges to eliminate the blank entries in each of the drop down lists. For example, GL_Account_Code would be:

    Please Login or Register  to view this content.

    and GL_Account_Description would be:

    Please Login or Register  to view this content.

    Note that I have also deleted the two blank rows at the top of the SetUp page to make this work.

    Using VBA, the second entry will be updated automatically whichever column you choose as the selection. From a user perspective, I think this is easier BUT it does mean you / they need to enable macros ... and not every environment allows this.

    Hope this helps

    Regards

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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