Slightly complicated Unique list

Beau the dog

Board Regular
Joined
Mar 8, 2021
Messages
72
Office Version
  1. 365
Platform
  1. Windows
Good afternoon

I have a table of data, over 25000 rows long. I need to extract a unique list of vehicle registrations per contract. the column which contains the vehicle registrations doesn't just have registrations in, sometimes it says workshop, consumables etc.

How do I extract the unique list, but only return the registrations, example snapshot below. I have put dummy registrations in, but they all follow the vehicle registration format (AB12 ABC).

For reference, Contracts are in column D and registrations and other stuff is in column G.

As always your help is very much appreciated
 

Attachments

  • Excel screen grab.PNG
    Excel screen grab.PNG
    24.1 KB · Views: 10

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
Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0
Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.

Unfortunately not, I tried adding XL2BB using the guide you linked to, but it's not available. Our company has blocked many things like this. Screenshot of my add-ins list pictured below
 

Attachments

  • Add ins screen grab.PNG
    Add ins screen grab.PNG
    34 KB · Views: 4
Upvote 0
In that case can you just copy/paste some sample data.
 
Upvote 0
Just like this?

Serco SiteDocCustomer Order NoExtra Info VRM
BRECKLANDVTAD129845VU16FEJ
CANTERBURYIIAD205652BD12 UEP
CANTERBURYIIAD205650VX13 LMU
CANTERBURYIIAD205674VX13 LMO
CANTERBURYIICR105140VX13 LMO
MID SUSSEXIIAD205673VK18OKB
MID SUSSEXIIAD205628VA16NVT
MID SUSSEXIIAD205668LJ64 FKU
MID SUSSEXIICR105139
MILTON KEYNESMMAD1464244102151533BV09FZT
MILTON KEYNESMMAD146481STOCK
MILTON KEYNESMMAD146444BV09FZT
MILTON KEYNESMMAD146477KY09CKE
MILTON KEYNESMMAD146481STOCK
MILTON KEYNESMMAD146445WORKSHOP
MILTON KEYNESMMAD146477LK15BBJ
MILTON KEYNESMMAD146476BD12VFL
Part WINFD1050 being transferred from branch BNBY
WYCOMBE & CHILTERNMMAD146431
 
Upvote 0
Thanks for that, how about
+Fluff 1.xlsm
DEFGHIJ
1Serco SiteDocCustomer Order NoExtra Info VRM
2BRECKLANDVTAD129845VU16 FEJBRECKLANDVU16 FEJ
3CANTERBURYIIAD205652BD12 UEPCANTERBURYBD12 UEP, VX13 LMU, VX13 LMO, VX13 LMO
4CANTERBURYIIAD205650VX13 LMUMID SUSSEXVK18 OKB, VA16 NVT, LJ64 FKU
5CANTERBURYIIAD205674VX13 LMOMILTON KEYNESBV09 FZT, BV09 FZT, KY09 CKE, LK15 BBJ, BD12 VFL
6CANTERBURYIICR105140VX13 LMOWYCOMBE & CHILTERNNo data
7MID SUSSEXIIAD205673VK18 OKB
8MID SUSSEXIIAD205628VA16 NVT
9MID SUSSEXIIAD205668LJ64 FKU
10MID SUSSEXIICR105139
11MILTON KEYNESMMAD1464244102151533BV09 FZT
12MILTON KEYNESMMAD146481STOCK
13MILTON KEYNESMMAD146444BV09 FZT
14MILTON KEYNESMMAD146477KY09 CKE
15MILTON KEYNESMMAD146481STOCK
16MILTON KEYNESMMAD146445WORKSHOP
17MILTON KEYNESMMAD146477LK15 BBJ
18MILTON KEYNESMMAD146476BD12 VFL
19MILTON KEYNESMMAD146476Part WINFD1050 being transferred from branch BNBY
20WYCOMBE & CHILTERNMMAD146431
21
Main
Cell Formulas
RangeFormula
I2:I6I2=UNIQUE(FILTER(D2:D200,D2:D200<>""))
J2:J6J2=TEXTJOIN(", ",,FILTER(G2:G200,(D2:D200=I2)*(LEN(G2:G200)=8)*(ISNUMBER(MID(G2:G200,3,2)+0)),"No data"))
Dynamic array formulas.
 
Upvote 0
Thanks for that, not quite what I need, but that's because of my explanation! But I feel we're close!

Could we get the unique list to be a vertical list, one registration per cell? It's because I will then reference this list with countifs and sumifs to extract data from the whole table.
 
Upvote 0
Like
+Fluff 1.xlsm
DEFGHIJKLM
1Serco SiteDocCustomer Order NoExtra Info VRMBRECKLANDCANTERBURYMID SUSSEXMILTON KEYNESWYCOMBE & CHILTERN
2BRECKLANDVTAD129845VU16 FEJVU16 FEJBD12 UEPVK18 OKBBV09 FZTNo data
3CANTERBURYIIAD205652BD12 UEPVX13 LMUVA16 NVTBV09 FZT
4CANTERBURYIIAD205650VX13 LMUVX13 LMOLJ64 FKUKY09 CKE
5CANTERBURYIIAD205674VX13 LMOVX13 LMOLK15 BBJ
6CANTERBURYIICR105140VX13 LMOBD12 VFL
7MID SUSSEXIIAD205673VK18 OKB
8MID SUSSEXIIAD205628VA16 NVT
9MID SUSSEXIIAD205668LJ64 FKU
10MID SUSSEXIICR105139
11MILTON KEYNESMMAD1464244102151533BV09 FZT
12MILTON KEYNESMMAD146481STOCK
13MILTON KEYNESMMAD146444BV09 FZT
14MILTON KEYNESMMAD146477KY09 CKE
15MILTON KEYNESMMAD146481STOCK
16MILTON KEYNESMMAD146445WORKSHOP
17MILTON KEYNESMMAD146477LK15 BBJ
18MILTON KEYNESMMAD146476BD12 VFL
19MILTON KEYNESMMAD146476Part WINFD1050 being transferred from branch BNBY
20WYCOMBE & CHILTERNMMAD146431
21
Main
Cell Formulas
RangeFormula
I1:M1I1=TRANSPOSE(UNIQUE(FILTER(D2:D200,D2:D200<>"")))
I2,M2,L2:L6,K2:K4,J2:J5I2=FILTER($G$2:$G$200,($D$2:$D$200=I1)*(LEN($G$2:$G$200)=8)*(ISNUMBER(MID($G$2:$G$200,3,2)+0)),"No data")
Dynamic array formulas.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,212,938
Messages
6,110,782
Members
448,297
Latest member
carmadgar

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