+ Reply to Thread
Results 1 to 6 of 6

Get only the values that exist in every column

  1. #1
    Registered User
    Join Date
    01-22-2021
    Location
    Brasília, Brazil
    MS-Off Ver
    Office 365
    Posts
    3

    Question Get only the values that exist in every column

    Hello, guys

    I'm new to the forum, so I apologise in advance if this is not an appropriate question.

    Well, I have a spreadsheet with several columns (months from jan/2018 to dec/2020), the data in each column are unique IDs that I compiled using spreadsheets that I receive monthly (avarage 300k rows/month). I need to know which IDs are present in every column, from jan/2018 to dec/2020.

    The data attached was generated by me as an example that I think suffices to give an understanding of the problem. If not, let me know. I really need help with this one.

    The IDs 0000009 to 0000019 are the only ones that appear in every single column, I highlighted it in red. The ID 0000002 is duplicate only in the first two columns.
    Attached Files Attached Files

  2. #2
    Forum Expert XLent's Avatar
    Join Date
    10-13-2010
    Location
    Northumberland, UK
    MS-Off Ver
    various
    Posts
    2,704

    Re: Get only the values that exist in every column

    one option, given O365:

    =TEXT(UNIQUE(SEQUENCE(MAX(A2:I20+0),1,MIN(A2:I20+0))*(COUNTIF(A2:I20,SEQUENCE(MAX(A2:I20+0),1,MIN(A2:I20+0)))=COLUMNS(A2:I20)),,TRUE),"000000")

    the above would return 000009 to 000019 in a list

  3. #3
    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,036

    Re: Get only the values that exist in every column

    OK, here is a formula (shamelessly copied from XOR LX)...

    NamedRanges used (CTRL-F3 to view/edit):

    Range1:
    =Planilha1!$A$2:$I$20

    Arry1:
    =COLUMN(Range1)-MIN(COLUMN(Range1))

    Arry2:
    =ROW(INDEX(Range1,,1))-MIN(ROW(INDEX(Range1,,1)))+1

    Arry3:
    =MMULT(0+(COUNTIF(OFFSET(INDEX(Range1,,1),,Arry1,,),INDEX(Range1,,1))>0),ROW(INDIRECT("1:"&COLUMNS(Range1)))^0)

    And then a formula:
    =IFERROR(INDEX(INDEX(Range1,,1),SMALL(IF(FREQUENCY(IF(INDEX(Range1,,1)<>"",IF(Arry3=COLUMNS(Range1),MATCH(INDEX(Range1,,1),INDEX(Range1,,1),0))),Arry2),Arry2),ROWS($1:1))),"")

    In Brazil, you may need to use ; instead of ,

    You seem to be using an older version of Excel than me. So, please refer to the attached file. If the formulae are enclosed within a pair of { }, these are array formulae.

    These 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 the curly brackets { } 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

  4. #4
    Registered User
    Join Date
    01-22-2021
    Location
    Brasília, Brazil
    MS-Off Ver
    Office 365
    Posts
    3

    Re: Get only the values that exist in every column

    Wow! Thank you so much, Mr. Glenn Kennedy! Your solution is great, solves my problem, and helps me to understand it better.

  5. #5
    Registered User
    Join Date
    01-22-2021
    Location
    Brasília, Brazil
    MS-Off Ver
    Office 365
    Posts
    3

    Re: Get only the values that exist in every column

    Thank you, XLent! I was surprised by how clever your solution is and how it turned out to be so efficient.

  6. #6
    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,036

    Re: Get only the values that exist in every column

    You're welcome.



    It would be very nice if you were to just click the Add Reputation button at the foot of any of the posts of members who helped you reach a solution.

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

+ 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. [SOLVED] Check if values exist and add 1 in the column at the right
    By okela in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 11-25-2019, 06:13 AM
  2. [SOLVED] Check if ALL Row Values Exist In Another Column
    By excel-help in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 04-24-2019, 02:11 AM
  3. Replies: 5
    Last Post: 07-18-2017, 02:45 PM
  4. Vlookup with Match and Iferror for confirming is values exist in a column
    By Mr.Magoo in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 12-09-2014, 06:57 AM
  5. Replies: 7
    Last Post: 12-07-2013, 02:33 PM
  6. Hide Row if no values exist in row column X through Y
    By 13reak in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 03-15-2012, 03:35 PM
  7. Replies: 3
    Last Post: 03-08-2012, 03:32 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