+ Reply to Thread
Results 1 to 15 of 15

Find Duplicates, check value in another column for each duplicate

  1. #1
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Find Duplicates, check value in another column for each duplicate

    I am trying to write a fairly simple formula but I do not know how to complete it. I believe I need to use Index and Match but am stumped.

    I have attached a sample sheet with the formula requirement written in plain English.

    Essentially, it is checking that where a duplicate value exists in column B, check the values for both duplicates in column D and then return a result. However for usability I have set up the worksheet a bit differently with an additional column that identifies duplicates that preferably needs to be taken into account - as this is part of a larger file and process.
    Attached Files Attached Files
    Last edited by labrooy; 07-31-2012 at 11:10 PM. Reason: Update Title

  2. #2
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    15,592

    Re: Index with Match or Sumproduct

    Your post does not comply with Rule 1 of our Forum RULES. Your post title should accurately and concisely describe your problem, not your anticipated solution. Use terms appropriate to a Google search. Poor thread titles, like Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will be addressed according to the OP's experience in the forum: If you have less than 10 posts, expect (and respond to) a request to change your thread title. If you have 10 or more posts, expect your post to be locked, so you can start a new thread with an appropriate title.
    To change a Title on your post, click EDIT then Go Advanced and change your title, if 2 days have passed ask a moderator to do it for you.


  3. #3
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    Sorry, amended

  4. #4
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    Can anyone assist with this query?

  5. #5
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,926

    Re: Find Duplicates, check value in another column for each duplicate

    not sure if i understand your requests in the workbook, but see if this gives yoy what you want?

    =IF(C5="Y",VLOOKUP(B5,B6:$B$22,1,FALSE),"N")
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  6. #6
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    Thanks for the feedback. Your formula identified that the duplicate exists and returned the value in column B. This is the first 2 steps of the process.

    From there, after identifying the duplicate, I need the formula to look for the duplicates value in column D i.e. in your example it finds cell B6 - next step is to check for a "N" in cell D6.

    ---------- Post added at 11:07 AM ---------- Previous post was at 10:50 AM ----------

    Something like this is what I am after
    (if(D5="Y",if(C5="Y",match(B:B,B5),if(vlookup(matchedBcell,B:D,3,false)="N","N","Y"))))
    where matchedBcell refers to the match found from match(B:B,B5)

    The formula also needs to account for more than 1 duplicate being present in column B.

  7. #7
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,926

    Re: Find Duplicates, check value in another column for each duplicate

    try this in row 2 (any column) and let me know if this is what you need for the 2nd part?

    =IF(C1="Y",VLOOKUP(VLOOKUP(B1,B2:$B$22,1,FALSE),B2:$D$22,3,FALSE),"N")

  8. #8
    Forum Expert icestationzbra's Avatar
    Join Date
    01-07-2004
    MS-Off Ver
    2007, 2010
    Posts
    1,421

    Re: Find Duplicates, check value in another column for each duplicate

    see if this works - start in, say, H2 and drag-fill down:

    Please Login or Register  to view this content.
    - i.s.z -
    CSE, aka Array aka { }, formulae are confirmed with CONTROL+SHIFT+ENTER.
    Replace commas ( , ) with semicolons ( ; ) in formulae, if your locale setting demands.
    All good ideas are courtesy resources from this forum as well as others around the web.
    - e.o.m -

  9. #9
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    Quote Originally Posted by FDibbins View Post
    try this in row 2 (any column) and let me know if this is what you need for the 2nd part?

    =IF(C1="Y",VLOOKUP(VLOOKUP(B1,B2:$B$22,1,FALSE),B2:$D$22,3,FALSE),"N")
    Thanks, this is getting close. What your formula is doing is finding any instances of the B.Value in the cells below it, and checking for the value in column D. The issue then becomes - what about when a duplicate value needs to check the cells above it? All duplicates need to be checked against each other.
    For example, if I could write a formula like this, it might give me the value required in most instances - however it still leaves the problem of what if there is more than 1 duplicate - the vlookup will only check the first value it finds, not the next.
    =IF(C5="Y",VLOOKUP(VLOOKUP(B5,B2:$B$4 & B6:$B$22,1,FALSE),B2:$B$4 & B6:$D$22,3,FALSE),"N")
    =IF(C6="Y",VLOOKUP(VLOOKUP(B6,B2:$B$5 & B7:$B$22,1,FALSE),B2:$B$5 & B7:$D$22,3,FALSE),"N")

    ---------- Post added at 12:28 PM ---------- Previous post was at 12:25 PM ----------

    Quote Originally Posted by icestationzbra View Post

    Please Login or Register  to view this content.
    Yes this works. Added bonus - I actually understand what it is doing.

    One further question, is there a way of limiting this calculation / formula to only the "used range" in the columns? I have 30 formula and 10,000 rows in the file I am working with and my macros are taking a long time to run so I am looking at optimising everything.

    Edit: the "Used Range" changes daily.
    Last edited by labrooy; 08-05-2012 at 10:36 PM. Reason: Additional information

  10. #10
    Forum Expert icestationzbra's Avatar
    Join Date
    01-07-2004
    MS-Off Ver
    2007, 2010
    Posts
    1,421

    Re: Find Duplicates, check value in another column for each duplicate

    i am on Excel 2007 and your profile says that you are on 2003 (although your sample workbook was XLSX). i do not know if this suggestion works in 2003 (in its entirety), so you may have to google it if it does not work exactly this way. if you want another approach, revert here and someone (or i, whoever gets to it first) will help.

    the simplest way to accomplish this would be to use the TABLE feature in Excel - Excel Tables autoextend their ranges and autopopulate their formulae.

    in the sample workbook that you attached in post #1, highlight cell A1 and then using the keyboard invoke the Table feature (CTRL + T or ALT > N > T).

    once that feature is invoked, it will ask you to provide the range of your table. use A1:E22 as the range for your table, and DO NOT forget to check the box for "my table has headers".

    once you accomplish this successfully, you will see that the colour of the table has change to the default theme offered by Excel. at this time, while your table range is highlighted, you may attempt to change the theme (or Table Style) by using the keyboard shortcut ALT > JT > S and looking through other options.

    once your table is established, put the formula in cell E2 and drag-fill down to E22. after this, whenever you add a new "contiguous" row of record, the table will autoextend and auto-drag-fill any formula down to the latest row.

    i have done this for you in the attached file.
    Attached Files Attached Files

  11. #11
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    Thanks, I have updated my profile to 2007 and started researching optimisation. Tables are certainly something I will consider using.

  12. #12
    Forum Expert icestationzbra's Avatar
    Join Date
    01-07-2004
    MS-Off Ver
    2007, 2010
    Posts
    1,421

    Re: Find Duplicates, check value in another column for each duplicate

    if you want to use Dynamic Named Ranges, a formulaic way of autoextending ranges, you will be well served, too.

  13. #13
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    The formula ended up taking far too long to run for the 11,000 rows of data, so I have optimised this to an extent, by calculating any non-relevant rows first and then moving on to the sumproduct. This is still taking around 10 minutes to calculate for the approximately 1,000 rows of affected data.

    =IF(C2="N","N/A",(IF(SUMPRODUCT((B:B=B2)*(D:D="Y"))=COUNTIF(B:B,B2),"Y","N")))

    Can anyone offer an alternate solution using Index / Match / Vlookup that may be faster?

  14. #14
    Forum Expert icestationzbra's Avatar
    Join Date
    01-07-2004
    MS-Off Ver
    2007, 2010
    Posts
    1,421

    Re: Find Duplicates, check value in another column for each duplicate

    why are you using whole column ranges when you have only 11000 rows of data? Excel 2007 has a million rows in the entire column. fix that and try for performance.

  15. #15
    Registered User
    Join Date
    10-24-2011
    Location
    Australia
    MS-Off Ver
    Excel 2010
    Posts
    45

    Re: Find Duplicates, check value in another column for each duplicate

    Thanks again, I have learnt some valuable information about tables and have a much faster macro now.

    For the benefit of any future users, I named the range of data (see sample file attached to firstpost) as a table "msum" and the following formula has changed from
    =IF(C2="N","N/A",(IF(SUMPRODUCT((B:B=B2)*(D:D="Y"))=COUNTIF(B:B,B2),"Y","N")))

    to
    =IF(msum[[#This Row],[MM]]="N","N/A",(IF(SUMPRODUCT((msum[[#All],[SP]]=msum[[#This Row],[SP]])*(msum[[#All],[PR]]="Y"))=COUNTIF(msum[[#All],[SP]],msum[[#This Row],[SP]]),"Y","N")))

    or alternately - for better readability -
    =IF(C2="N","N/A",(IF(SUMPRODUCT((msum[[#All],[SP]]=B2)*(msum[[#All],[PR]]="Y"))=COUNTIF(msum[[#All],[SP]],B2),"Y","N")))

+ 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