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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
BTATA
New Member

Help me validate an AlphaNumeric Text column with specific rules/pattern

I have student data from several sources that I can merge into a single table. 

Some sources are better at maintaining their data than others, and I'd like to "validate" a column if possible. 

 

Students in the UK have a 13-digit unique pupil number. This is made up of 1 letter at the start, followed by 12 numerical digits. 

 

I wanted to add a custom column in my PowerBI table which can return either a "Yes" or "No" (if the UPN matches the aforementioned rule - 1 letter, 12 digits).

 

For some reason, PowerBI doesn't like the following query...

 

= Table.AddColumn(#"Changed Type1", "UPN Validated", each IF(AND(NOT(ISNUMBER(LEFT([#"Unique Identifier*"], 1))),ISNUMBER(RIGHT([#"Unique Identifier*"], 12))), "Yes", "No"))

 

Can someone please help me figure out what's wrong with this formula? 

 

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

Use this

= Table.AddColumn(#"Changed Type1", "UPN Validated", each [First = Character.ToNumber(Text.Start([Unique Identifier], 1)), Last = Text.End([Unique Identifier], 12), a = First > 64 and First < 91, b = Value.FromText(Last) is number and Text.Length(Last) = 12, result = if (a and b) then "Yes" else "No"][result])

See the sample test code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("JYy7DcAgEMV2oU7xuM+7oyQZA1GyQJT9lSh0lmV5jNJDMtBcQUWZxygfpdCyVfAXp2jCNFhpspM0UNRr0PtuFGqB9IBvUb8JPfWi7c39rGeVOV8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Unique Identifier" = _t]),
    #"Added Custom" = Table.AddColumn(Source, "UPN Validated", each [First = Character.ToNumber(Text.Start([Unique Identifier], 1)), Last = Text.End([Unique Identifier], 12), a = First > 64 and First < 91, b = Value.FromText(Last) is number and Text.Length(Last) = 12, result = if (a and b) then "Yes" else "No"][result])
in
    #"Added Custom"

 

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

Use this

= Table.AddColumn(#"Changed Type1", "UPN Validated", each [First = Character.ToNumber(Text.Start([Unique Identifier], 1)), Last = Text.End([Unique Identifier], 12), a = First > 64 and First < 91, b = Value.FromText(Last) is number and Text.Length(Last) = 12, result = if (a and b) then "Yes" else "No"][result])

See the sample test code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("JYy7DcAgEMV2oU7xuM+7oyQZA1GyQJT9lSh0lmV5jNJDMtBcQUWZxygfpdCyVfAXp2jCNFhpspM0UNRr0PtuFGqB9IBvUb8JPfWi7c39rGeVOV8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Unique Identifier" = _t]),
    #"Added Custom" = Table.AddColumn(Source, "UPN Validated", each [First = Character.ToNumber(Text.Start([Unique Identifier], 1)), Last = Text.End([Unique Identifier], 12), a = First > 64 and First < 91, b = Value.FromText(Last) is number and Text.Length(Last) = 12, result = if (a and b) then "Yes" else "No"][result])
in
    #"Added Custom"

 

Thank you so much Vijay! 

That worked perfectly 🙂

 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors