Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
alpeshparmar
Regular Visitor

Data validity and syntax

Hello All, I am building a data quality dashboard. One column is of PAN number. I to check its validity, I need to apply 3 rules and finally calculate validity % based on that. The rules are:

1) First 5 uppercase alphabets followed by 4 numeric digits and ending with one uppercase alphabet

2) The fourth character should be from list ("P","C", "H", "F", "A", "T", "B", "L", "J", "G")

3) Same PAN can't be present across multiple clients/rows

Please help. How can I achieve all these 3 rules? In power query editor or DAX?

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

I tried to follow the specifications of the following link:

https://en.wikipedia.org/wiki/Permanent_account_number 

 

Test if this function is right for you. 

 

 

 

let
checkPAN=(PAN as text) as logical =>
let
charsPAN=Text.ToList(PAN),
fourthChars=Text.ToList("ABCEFGHLJPT"),
len=Text.Length(PAN)=10,
upper=Text.Upper(PAN)=PAN,
btwAAAZZZ="AAA"<=Text.Start(PAN,3) and Text.Start(PAN,3)<="ZZZ",
fourthChar=List.Contains(fourthChars,charsPAN{3}),
fifthChar="A" < charsPAN{4} and charsPAN{4} <"Z",
digitsPAN="0000"<Text.Range(PAN,5,4) and Text.Range(PAN,5,4)<"9999",
lastCharPAN="A" < charsPAN{9} and charsPAN{9} <"Z"
in len and upper and btwAAAZZZ and fourthChar and digitsPAN and lastCharPAN
in checkPAN

 

 

View solution in original post

v-eachen-msft
Community Support
Community Support

Hi @alpeshparmar ,

 

You could refer to the following DAX:

Column =
VAR a =
    LEFT ( 'Table'[Column1], 5 )
VAR b1 =
    MID ( 'Table'[Column1], 1, 1 )
VAR b2 =
    MID ( 'Table'[Column1], 2, 1 )
VAR b3 =
    MID ( 'Table'[Column1], 3, 1 )
VAR b4 =
    MID ( 'Table'[Column1], 4, 1 )
VAR b5 =
    MID ( 'Table'[Column1], 5, 1 )
VAR b =
    ISERROR ( VALUE ( b1 ) ) && ISERROR ( VALUE ( b2 ) )
        && ISERROR ( VALUE ( b3 ) )
        && ISERROR ( VALUE ( b4 ) )
        && ISERROR ( VALUE ( b5 ) )
VAR c =
    NOT ( ISERROR ( VALUE ( MID ( 'Table'[Column1], 6, 4 ) ) ) )
VAR d =
    EXACT ( UPPER ( RIGHT ( 'Table'[Column1], 1 ) ), RIGHT ( 'Table'[Column1], 1 ) )
VAR e =
    ISERROR ( VALUE ( RIGHT ( 'Table'[Column1], 1 ) ) )
VAR f =
    CALCULATE (
        COUNTA ( 'Table'[Column1] ),
        ALLEXCEPT ( 'Table', 'Table'[Column1] )
    ) = 1
VAR g = b4 IN { "P", "C", "H", "F", "A", "T", "B", "L", "J", "G" }
RETURN
    IF (
        EXACT ( UPPER ( a ), a ) && ISTEXT ( a )
            && b
            && c
            && d
            && e
            && f
            && g,
        1,
        0
    )

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

View solution in original post

2 REPLIES 2
v-eachen-msft
Community Support
Community Support

Hi @alpeshparmar ,

 

You could refer to the following DAX:

Column =
VAR a =
    LEFT ( 'Table'[Column1], 5 )
VAR b1 =
    MID ( 'Table'[Column1], 1, 1 )
VAR b2 =
    MID ( 'Table'[Column1], 2, 1 )
VAR b3 =
    MID ( 'Table'[Column1], 3, 1 )
VAR b4 =
    MID ( 'Table'[Column1], 4, 1 )
VAR b5 =
    MID ( 'Table'[Column1], 5, 1 )
VAR b =
    ISERROR ( VALUE ( b1 ) ) && ISERROR ( VALUE ( b2 ) )
        && ISERROR ( VALUE ( b3 ) )
        && ISERROR ( VALUE ( b4 ) )
        && ISERROR ( VALUE ( b5 ) )
VAR c =
    NOT ( ISERROR ( VALUE ( MID ( 'Table'[Column1], 6, 4 ) ) ) )
VAR d =
    EXACT ( UPPER ( RIGHT ( 'Table'[Column1], 1 ) ), RIGHT ( 'Table'[Column1], 1 ) )
VAR e =
    ISERROR ( VALUE ( RIGHT ( 'Table'[Column1], 1 ) ) )
VAR f =
    CALCULATE (
        COUNTA ( 'Table'[Column1] ),
        ALLEXCEPT ( 'Table', 'Table'[Column1] )
    ) = 1
VAR g = b4 IN { "P", "C", "H", "F", "A", "T", "B", "L", "J", "G" }
RETURN
    IF (
        EXACT ( UPPER ( a ), a ) && ISTEXT ( a )
            && b
            && c
            && d
            && e
            && f
            && g,
        1,
        0
    )

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.
Anonymous
Not applicable

I tried to follow the specifications of the following link:

https://en.wikipedia.org/wiki/Permanent_account_number 

 

Test if this function is right for you. 

 

 

 

let
checkPAN=(PAN as text) as logical =>
let
charsPAN=Text.ToList(PAN),
fourthChars=Text.ToList("ABCEFGHLJPT"),
len=Text.Length(PAN)=10,
upper=Text.Upper(PAN)=PAN,
btwAAAZZZ="AAA"<=Text.Start(PAN,3) and Text.Start(PAN,3)<="ZZZ",
fourthChar=List.Contains(fourthChars,charsPAN{3}),
fifthChar="A" < charsPAN{4} and charsPAN{4} <"Z",
digitsPAN="0000"<Text.Range(PAN,5,4) and Text.Range(PAN,5,4)<"9999",
lastCharPAN="A" < charsPAN{9} and charsPAN{9} <"Z"
in len and upper and btwAAAZZZ and fourthChar and digitsPAN and lastCharPAN
in checkPAN

 

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.