+ Reply to Thread
Results 1 to 16 of 16

Extracting the common values found in Column "A" & Column "B" into Column "C"

  1. #1
    Registered User
    Join Date
    07-13-2019
    Location
    Mansehra, Pakistan
    MS-Off Ver
    2010
    Posts
    46

    Extracting the common values found in Column "A" & Column "B" into Column "C"

    Hello to All!!!

    Hope everyone is fine there. I have great respect for my seniors, teachers and Excel Experts out there. I really respect all of you!!!!

    Let's get to the problem.

    I have values in Columns "A" & "B".
    My problem is very simple. I want to compare the values found in column A and Column B, and extract the common values into the column "C".

    Any help would be greatly appreciated.

    Workbook named "ExtractingCommonValues" is attached.
    Attached Files Attached Files

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,025

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    One way:

    =IFERROR(INDEX($B:$B,SMALL(IF(ISNA(MATCH($B$2:$B$17,$A$2:$A$17,0)),"",ROW($B$2:$B$17)),ROWS($2:2))),"")

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Forum Guru sktneer's Avatar
    Join Date
    04-30-2011
    Location
    Kanpur, India
    MS-Off Ver
    Office 365
    Posts
    9,648

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Try this Array Formula which requires confirmation with Ctrl+Shift+Enter instead of Enter alone.

    In D2
    Please Login or Register  to view this content.
    Confirm with Ctrl+Shift+Enter and copy it down.
    Regards
    sktneer


    Treat people the way you want to be treated. Talk to people the way you want to be talked to.
    Respect is earned NOT given.

  4. #4
    Forum Expert
    Join Date
    06-08-2012
    Location
    Left the forum!
    MS-Off Ver
    Left the forum!
    Posts
    5,189

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Another way, doesn't need array confirmation.
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    or
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Last edited by jason.b75; 07-28-2019 at 07:12 AM.

  5. #5
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,025

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    or indeed, another non-array effort:

    =IFERROR(INDEX($A:$A,AGGREGATE(15,6,ROW($A$2:$A$17)/(ISNUMBER(MATCH($A$2:$A$17,$B$2:$B$17,0))),ROWS($1:1))),"")

  6. #6
    Forum Expert
    Join Date
    06-08-2012
    Location
    Left the forum!
    MS-Off Ver
    Left the forum!
    Posts
    5,189

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Useless fact for the day, with aggregate set to ignore errors, sign does the same as isnumber but less typing involved

  7. #7
    Registered User
    Join Date
    07-13-2019
    Location
    Mansehra, Pakistan
    MS-Off Ver
    2010
    Posts
    46

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    I cannot thank you enough, all of you! Thanks alot!

    Apart from array formulae, I tried another rather simple formula. I am copying the formula down.

    =IF(COUNTIF($B$2:$B$13,$A$2:$A$13)=1,INDEX($A$2:$A$13,ROWS($A$2:A2)),"")

    it is producing the same results as other array formulae. is that okay too?
    Last edited by Asad Mir; 07-28-2019 at 07:58 AM.

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,779

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    If it's producing the right results, then it must be OK! Where did you get this formula?

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


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  9. #9
    Forum Expert
    Join Date
    06-08-2012
    Location
    Left the forum!
    MS-Off Ver
    Left the forum!
    Posts
    5,189

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Quote Originally Posted by Asad Mir View Post
    it is producing the same results as other array formulae. is that okay too?
    Only you can answer that question. The real decider would be which one gives the answers how you want them.

    The formulae that I suggested would move all of the results to the top (no blanks in the middle). The results would be in numerical order, lowest value first.

    The formulae that Glenn and sktneer suggested appear to do the same with the blanks, but the results would be in list order instead of numeric.

    Your formula doesn't separate the results from the blanks, it just mirrors them in the same row as the original entry.
    If that is a good enough result then
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    will do the same.

  10. #10
    Registered User
    Join Date
    07-13-2019
    Location
    Mansehra, Pakistan
    MS-Off Ver
    2010
    Posts
    46

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    yes, my formula is producing the right results too. You are right, My formula mirrors them in the same row.

    I have another question regarding the 2nd formula presented by Respectable Jason.b75 copied below:

    =IFERROR(AGGREGATE(15,6,$A$2:$A$17/COUNTIF($B$2:$B$17,$A$2:$A$17),ROWS(D$2:D2)),"")

    in above formula, in countif function, if i interchange the column "B" for criteria argument of countif function and vice versa, like this, COUNTIF($A$2:$A$17,$B$2:$B$17).

    why is it producing the wrong results, here arrays are compared, not one cell. I am just confused. Please help me understand this concept.

  11. #11
    Forum Expert
    Join Date
    06-08-2012
    Location
    Left the forum!
    MS-Off Ver
    Left the forum!
    Posts
    5,189

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    You will see that the reference to column A appears in 2 places.

    =IFERROR(AGGREGATE(15,6,$A$2:$A$17/COUNTIF($B$2:$B$17,$A$2:$A$17),ROWS(D$2:D2)),"")

    If you swicth the order of countif then you would need to change the first one to B as well, otherwise the order will be incorrect.

    One thing to note, if any number appears more than once in A or B then there is a high risk of incorrect results with this method. I think that all of the other suggestions should be safe from this problem.

  12. #12
    Registered User
    Join Date
    07-13-2019
    Location
    Mansehra, Pakistan
    MS-Off Ver
    2010
    Posts
    46

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Understood! Loud and Clear, Thanks alot to all who replied to the thread. I am looking forward to contribute someday soon like all of you.
    I am marking this thread solved.

    Take Care

    Thanks & Regards

    Asad

  13. #13
    Forum Guru sktneer's Avatar
    Join Date
    04-30-2011
    Location
    Kanpur, India
    MS-Off Ver
    Office 365
    Posts
    9,648

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    With dynamic array functions in Office 365, this is as simple as this...

    Please Login or Register  to view this content.
    The above formula will return unique sorted common values from the two ranges.

    Dynamic Array Functions are just awesome.
    Attached Images Attached Images

  14. #14
    Registered User
    Join Date
    07-13-2019
    Location
    Mansehra, Pakistan
    MS-Off Ver
    2010
    Posts
    46

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Thanks Dear Sktneer...

  15. #15
    Forum Guru sktneer's Avatar
    Join Date
    04-30-2011
    Location
    Kanpur, India
    MS-Off Ver
    Office 365
    Posts
    9,648

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    You're welcome Asad!

  16. #16
    Registered User
    Join Date
    07-13-2019
    Location
    Mansehra, Pakistan
    MS-Off Ver
    2010
    Posts
    46

    Re: Extracting the common values found in Column "A" & Column "B" into Column "C"

    Mistakenly posted comment....
    Last edited by Asad Mir; 07-18-2021 at 06:40 AM.

+ 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. Replies: 6
    Last Post: 07-16-2017, 09:06 AM
  2. [SOLVED] Column X-Ref list - Sheet1 Col A "pages", Col B:FL "Req" to Sheet2 ColA "req", ColB "page"
    By excel-card-pulled in forum Excel Formulas & Functions
    Replies: 10
    Last Post: 04-07-2017, 09:30 AM
  3. Replies: 1
    Last Post: 08-20-2016, 01:59 AM
  4. [SOLVED] If there is any text in column "A$" on "sheet1" then move cell to column "A$" on "sheet2"
    By ckgeary in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 06-27-2013, 08:28 PM
  5. Replies: 2
    Last Post: 06-06-2013, 12:45 PM
  6. Replies: 3
    Last Post: 04-14-2013, 11:53 PM
  7. [SOLVED] Formula needed to display "Pass" or "Fail" if a column contains any values other than "yes
    By andreindy in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-26-2013, 05:49 PM

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