get any value once

amit96

New Member
Joined
Feb 15, 2022
Messages
27
Office Version
  1. 2013
Platform
  1. Windows
How do I get a list in the "main" sheet of entries that appear in the "data" sheet in column B, that I get each entry once!
I mean there are values that appear several times, and I want to get them only once. And that I also get a value that appears only once.
one of each.
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
is that still the version of excel you have 2013 - newer versions have functions like unique()

otherwise - something like an array formula - control+shift+enter
=INDEX(data!$B$2:$B$1000, MATCH(0, COUNTIF($D1:D$1, data!$B$2:$B$2000), 0))

=IF(OR(INDEX(data!$B$2:$B$100, MATCH(0, COUNTIF($L1:L$1, data!$B$2:$B$100), 0))=0,ISERROR(INDEX(data!$B$2:$B$100, MATCH(0, COUNTIF($L1:L$1, data!$B$2:$B$100), 0)))),"",INDEX(data!$B$2:$B$100, MATCH(0, COUNTIF($L1:L$1, data!$B$2:$B$100), 0)))

Note: Images are difficult to see , and also requires that I input all the data myself, which is very time consuming.

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC , then put the sample spreadsheet onto a share
I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.

See extract on column L - from B on same sheet for simple visual example

Extract a unique list and then Sum various criteria.xlsx
ABCDEFGHIJKL
1
2A1 LA12314.9LA12
3A2LA15515.2LA15
4A1LA12614.5 
5A2LA15914.1 
6A1 LA12312 
7A2LA15517 
8A1LA12618 
9A2LA15915 
Sheet1
Cell Formulas
RangeFormula
L2L2=IF(OR(INDEX($B$2:$B$100, MATCH(0, COUNTIF($L1:L$1, $B$2:$B$100), 0))=0,ISERROR(INDEX($B$2:$B$100, MATCH(0, COUNTIF($L1:L$1, $B$2:$B$100), 0)))),"",INDEX($B$2:$B$100, MATCH(0, COUNTIF($L1:L$1, $B$2:$B$100), 0)))
L3:L9L3=IF(OR(INDEX($B$2:$B$100, MATCH(0, COUNTIF($L$1:L2, $B$2:$B$100), 0))=0,ISERROR(INDEX($B$2:$B$100, MATCH(0, COUNTIF($L$1:L2, $B$2:$B$100), 0)))),"",INDEX($B$2:$B$100, MATCH(0, COUNTIF($L$1:L2, $B$2:$B$100), 0)))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
VBA Code:
Sub Advanced()

     Set sh2 = Sheets("sheet2")
     sh2.Columns("A").ClearContents                             'make destionation empty

     With Sheets("sheet1")
          With .Range(.Range("B1"), .Range("B" & Rows.Count).End(xlUp))     'your B-column
               If Len(.Cells(1, 1)) = 0 Then .Cells(1, 1).Value = "Header_B"     'add a header
               .AdvancedFilter Action:=xlFilterCopy, CopyToRange:=sh2.Range("A1"), Unique:=True
          End With
     End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,950
Messages
6,175,582
Members
452,653
Latest member
craigje92

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top