Filter (Also Highlight) Unique Digit Numbers in Google Sheets

Have you ever needed to find numbers where each digit appears only once? That’s exactly what this tutorial is about — how to filter (also highlight) unique digit numbers in Google Sheets.

Think of numbers like 12345 — every digit is different. But 12344? That one repeats the digit 4, so it doesn’t qualify. This trick is surprisingly useful in real life! I’ve used it to check serial numbers, spot cleaner data entries, and even for fun stuff like analyzing lottery picks.

Whether you’re working with PINs, raffle entries, product IDs, or just enjoy playing with numbers, this method helps you quickly identify the ones that stand out — without any repeats.

In this post, I’ll walk you through how to filter (also highlight) unique digit numbers in Google Sheets using formulas, step by step.

Let’s dive in!

How to Filter Unique Digit Numbers in Google Sheets

Assume you have PINs in column B (starting from B2) and you want to filter all the unique digit PINs from this list.

Example Data:

PIN Numbers
1234
4456
3216
6548
4425

You can use the following formula to filter numbers with all unique digits:

=FILTER(B2:B, MAP(B2:B, LAMBDA(row, LEN(row)=COUNTA(UNIQUE(MID(row, SEQUENCE(LEN(row)), 1))))))

Output:

Unique PINs
1234
3216
6548
If you're using this formula for a different range, replace B2:B with your actual range.

Formula Explanation

Let’s break it down:

  • MID(row, SEQUENCE(LEN(row)), 1) – splits each digit of the number into separate cells.
  • UNIQUE(...) – removes any repeated digits.
  • COUNTA(...) – counts how many unique digits remain.
  • LEN(row)=COUNTA(...) – returns TRUE only if all digits were unique (i.e., length of the number equals count of unique digits).
  • MAP(...) – applies this logic to every row in the given range.
  • FILTER(...) – returns only the rows for which the above logic is TRUE.

That’s how the formula filters unique digit numbers in Google Sheets.

How to Highlight Unique Digit Numbers in Google Sheets

To highlight unique digit numbers in the range B2:B:

  1. Select the range B2:B.
  2. Go to Format > Conditional formatting.
  3. Under “Format rules,” choose Custom formula is.
  4. Enter this formula:
    =LEN(B2)=ARRAYFORMULA(COUNTA(UNIQUE(MID(B2, SEQUENCE(LEN(B2)), 1))))
  5. Set your formatting style.
  6. Click Done.
Example of Highlighting Unique Digit Numbers in Google Sheets

Now, all numbers with unique digits in the selected range will be highlighted!

Resources – Other Interesting Google Sheets Tips

Prashanth KV
Prashanth KV
Your Trusted Google Sheets and Excel Guide Prashanth KV brings a wealth of experience in Google Sheets and Excel, cultivated through years of work with multinational corporations in Mumbai and Dubai. As a recognized Google Product Expert in Docs Editors, Prashanth shares his expertise through insightful blogging since 2012. Explore his blog for practical tips and guidance on maximizing your spreadsheet skills.

How to Sort Pie Slices in Google Sheets

To sort pie slices in a pie chart, you need to sort the data...

Filter Items Unique to Groups in Google Sheets

In this tutorial, we'll learn how to filter items unique to groups in Google...

Find Common Items Across Multiple Columns in Google Sheets

This tutorial explains how to find common items across multiple columns in Google Sheets....

Sort Column by Length of Text in Google Sheets

To sort a column by length of text, you can either use the QUERY...

More like this

How to Sort Pie Slices in Google Sheets

To sort pie slices in a pie chart, you need to sort the data...

Filter Items Unique to Groups in Google Sheets

In this tutorial, we'll learn how to filter items unique to groups in Google...

Find Common Items Across Multiple Columns in Google Sheets

This tutorial explains how to find common items across multiple columns in Google Sheets....

LEAVE A REPLY

Please enter your comment!
Please enter your name here

This site uses Akismet to reduce spam. Learn how your comment data is processed.