+ Reply to Thread
Results 1 to 6 of 6

Matching two colums with two constraints

  1. #1
    Registered User
    Join Date
    12-01-2008
    Location
    istanbul
    Posts
    8

    Matching two colums with two constraints

    Hi helpers,
    I have two lists that needs to be matched every month. one is;given loans the other one is; gurantee letters for that amounts of loans. As an example; when it's given $102 loan to a customer, they shall bring a $102 gurantee letter from a bank. We have the loan amounts and letter amounts in two different lists. Matching them manually takes ages.. I need to find an easier way..
    I can't use a vlookup formula, because there are 2500 items in a sheet and there can be several times the same amount. I have two main constraints; the currency of amounts should be same. Secondly; the date of the letter and date of loan should be very close (mostly one day after, but it s ok even if they are on the same month) Seldom if ever, same amounts are hitting the system on the same month. But it's ok, i can correct them manually..

    Example:
    Credit List :
    ID Currency Amounts Date
    200 CHF 885,00 06.01.2008
    836 CHF 8833,00 24.05.2007
    1 EUR 451944,0 30.07.2007
    3 EUR 9541,00 03.01.2008
    6 EUR 40200,00 07.08.2007
    7 EUR 74955,00 01.08.1990

    Letter List:
    ID Currency Amount Date
    1 TRY 7495,00 02.08.1990
    2 TRY 26,00 24.08.1990
    3 EUR 9541,00 01.08.1990
    4 TRY 3763,00 17.09.1996
    5 USD 41205,00 18.03.1997
    6 EUR 35279,00 25.08.1997
    7 CHF 8833,00 25.05.2007
    8 TRY 4200,00 31.12.1998

    At the list above only the CHF highlated in RED; in the 2 and 7th rows of the lists are matching, other amounts are not matching due to differences in currencies or dates..

    I know it s pretty complicated, but it s a pain in the as. to match all of them manually.. I tried sorting and grouping acc. to currencies or dates and also changing letter amounts to negative values and summing up to 0.. nothing works.. Can anyone help???
    Looking forward for aid...
    Last edited by amygdalus; 12-01-2008 at 09:02 AM.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    See if the attached helps....

    I tested for if the amount is the same and the date is within a month before or a month after the Credit list date... you can adjust as necessary.

    Formula used in E3 will return the ID number of the first match it finds.

    Please Login or Register  to view this content.
    NOTE: This is a special array formula. After you enter it in the cell, make adjustments to cell ranges, etc. Then hold the CTRLand SHIFT keys down and then press ENTER. You will see { } brackets appear around the formula... Then you can copy it down.
    Attached Files Attached Files
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Valued Forum Contributor rwgrietveld's Avatar
    Join Date
    09-02-2008
    Location
    Netherlands
    MS-Off Ver
    XL 2007 / XL 2010
    Posts
    1,671

    re: Matching two colums with two constraints

    Please Login or Register  to view this content.
    Date is within 2 days!
    Attached Files Attached Files
    Looking for great solutions but hate waiting?
    Seach this Forum through Google

    www.Google.com
    (e.g. +multiple +IF site:excelforum.com/excel-general/ )

    www.Google.com
    (e.g. +fill +combobox site:excelforum.com/excel-programming/ )

    Ave,
    Ricardo

  4. #4
    Valued Forum Contributor Shijesh Kumar's Avatar
    Join Date
    05-26-2008
    Location
    Bangalore / India
    MS-Off Ver
    2000
    Posts
    717
    Hi,

    Alternative..


    Please Login or Register  to view this content.

    All Non Zero values represent a match
    Enter the formula without Curly braces..
    Prese Ctrl + Shift + enter
    Assumption made ... date should be in the same month

  5. #5
    Registered User
    Join Date
    12-01-2008
    Location
    istanbul
    Posts
    8
    you guys are magicians!!! that s awasome ,)Thanks heaps!!!
    one more thing, my first constraint was; the currencies should be same. How can i add that one too? is it possible? or should i sort & group according to currencies each list and then extend the formula with the given cells?

  6. #6
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Quote Originally Posted by amygdalus View Post
    you guys are magicians!!! that s awasome ,)Thanks heaps!!!
    one more thing, my first constraint was; the currencies should be same. How can i add that one too? is it possible? or should i sort & group according to currencies each list and then extend the formula with the given cells?
    Yes, just add the constraint...

    Using my formula, it would be changed to:

    Please Login or Register  to view this content.
    again, confirmed with CTRL+SHIFT+ENTER

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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