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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
AlanP514
Helper V
Helper V

Conditional Dynamic Custom Column

Hai All, I need help with this requirement on this which we want to do in the power query editor.
Background 
I work on the sales dashboard, so every month users will send a new version table with the same schema, so I use the appending option for every month to append every table.
So based on this column we can assure the different versions which appending every month(Attaching below)


alanpjames_0-1654242923229.png

And now I want to create  one custom conditional  numerical column based on this 
Requirement
For 2021 versions will go like this format
V5-May-2021
V6-June-2021
V7-July-2021
V8-August-2021
V9-September-2021
V10-October-2021
V11-November-2021
V12-December-2021
based on 2021 data is ok but what about 2022 or Coming years it will be collapse
1st  requirement
So I want to create one custom numerical column that should only present numerical values
for eg. v5-may-2021 For the custom should only return 5
2nd requirement 
From the next year 2022
The custom column values should show like this 122 , 222, 322 , 422, etc(1 Is the version, 22 is the year)
From the next year 2023
The custom column values should show like this 123, 223, 323 , 423, etc(1 Is the version, 23 is the year)
So desired Custom column output 

Custom column 
8
9
10
11
12
122
222
322
 422




The top table from  8 to till 12 shows 2021 versions data and down it is showing next year's (2022) desired values 
and this should be dynamically created for every version.
Note:  this I want to do in power query as a custom column 

please help me to achieve this logic

1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

@AlanP514 
Updated code as follows https://we.tl/t-G7j4BoCrdG

let
    Source = Excel.Workbook(File.Contents("C:\Users\Tamer.Juma\TiSUN Dropbox\tamer tisunenergy\Tamer - Personal\Work\PBI Community\Community 2\Community 161.xlsx"), null, true),
    Versions_Sheet = Source{[Item="Versions",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Versions_Sheet, [PromoteAllScalars=true]),
    Version = Table.AddColumn(#"Promoted Headers", "Text Between Delimiters", each Text.BetweenDelimiters([Version], "V", "-"), Int16.Type),
    Year = Table.AddColumn(Version, "Text After Delimiter", each Text.AfterDelimiter([Version], "20"), Int16.Type),
    #"Change to Intiger" = Table.TransformColumnTypes(Year,{{"Text Between Delimiters", Int64.Type}, {"Text After Delimiter", Int64.Type}, {"Version", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Change to Intiger",null,21,Replacer.ReplaceValue,{"Text After Delimiter"}),
    #"Inserted Addition" = Table.AddColumn(#"Replaced Value", "New Version", each [Text Between Delimiters] + 100 * [Text After Delimiter], Int16.Type ),
    #"Removed Columns" = Table.RemoveColumns(#"Inserted Addition",{"Text Between Delimiters", "Text After Delimiter"})
in
    #"Removed Columns"

 

View solution in original post

4 REPLIES 4
v-kkf-msft
Community Support
Community Support

Hi @AlanP514 ,

 

Has your problem been solved? If it is solved, please mark a reply which is helpful to you.

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.


Best Regards,
Winniz

v-kkf-msft
Community Support
Community Support

Hi @AlanP514 ,

 

Does your 2022/2023 version table contain year information? If it does, try tamerj1 's solution.

 

If not, based on my testing, you will have to specify the appropriate year when appending monthly queries, like this.

 

= Text.Select([Version],{"0".."9"}) & Text.End("2022" , 2)

vkkfmsft_0-1654672071193.png

vkkfmsft_1-1654672094901.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

tamerj1
Super User
Super User

@AlanP514 
Updated code as follows https://we.tl/t-G7j4BoCrdG

let
    Source = Excel.Workbook(File.Contents("C:\Users\Tamer.Juma\TiSUN Dropbox\tamer tisunenergy\Tamer - Personal\Work\PBI Community\Community 2\Community 161.xlsx"), null, true),
    Versions_Sheet = Source{[Item="Versions",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Versions_Sheet, [PromoteAllScalars=true]),
    Version = Table.AddColumn(#"Promoted Headers", "Text Between Delimiters", each Text.BetweenDelimiters([Version], "V", "-"), Int16.Type),
    Year = Table.AddColumn(Version, "Text After Delimiter", each Text.AfterDelimiter([Version], "20"), Int16.Type),
    #"Change to Intiger" = Table.TransformColumnTypes(Year,{{"Text Between Delimiters", Int64.Type}, {"Text After Delimiter", Int64.Type}, {"Version", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Change to Intiger",null,21,Replacer.ReplaceValue,{"Text After Delimiter"}),
    #"Inserted Addition" = Table.AddColumn(#"Replaced Value", "New Version", each [Text Between Delimiters] + 100 * [Text After Delimiter], Int16.Type ),
    #"Removed Columns" = Table.RemoveColumns(#"Inserted Addition",{"Text Between Delimiters", "Text After Delimiter"})
in
    #"Removed Columns"

 

tamerj1
Super User
Super User

Hi @AlanP514 

Here is the sample file with the solution https://we.tl/t-lkm4UtAKrG

https://we.tl/t-akHIBCeHpB

This the PQ code 

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\Tamer.Juma\TiSUN Dropbox\tamer tisunenergy\Tamer - Personal\Work\PBI Community\Community 2\Community 161.xlsx"), null, true),
    Versions_Sheet = Source{[Item="Versions",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Versions_Sheet, [PromoteAllScalars=true]),
    Version = Table.AddColumn(#"Promoted Headers", "Text Between Delimiters", each Text.BetweenDelimiters([Version], "V", "-"), Int16.Type),
    Year = Table.AddColumn(Version, "Text After Delimiter", each Text.AfterDelimiter([Version], "20"), Int16.Type),
    #"Change to Intiger" = Table.TransformColumnTypes(Year,{{"Text Between Delimiters", Int64.Type}, {"Text After Delimiter", Int64.Type}, {"Version", type text}}),
    #"Inserted Addition" = Table.AddColumn(#"Change to Intiger", "Addition", each [Text Between Delimiters] + 100 * [Text After Delimiter], Int16.Type ),
    #"Changed Type" = Table.TransformColumnTypes(#"Inserted Addition",{{"Addition", Int64.Type}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"Text Between Delimiters", "Text After Delimiter"})
in
    #"Removed Columns"

 

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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