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
anaescobararias
Regular Visitor

How to merge a dynamic column to a table

Hi all,

 

I have a database that's is updated daily. Every day a new column is added with the cumulative data.

anaescobararias_0-1606295474387.png

 

I want to find a way to merge the latest column (the name of the column will match today()) with another table, so I always have the latest numbers of the day for each country.

 

Any ideas on how to do this?

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @anaescobararias 

 

check out this solutions. The first approach is to select column Province and country and the last column (check out step GetProvinceCountryAndLastColumn ). The second approach calculates today date in format MM/DD/YY and then choose this column name instead of the last column. But I saw that the first may is written like 05-01-20 and so this logic would not work. (check step GetProvinceCountryAndTodayColumn).

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUXICYlMgNjQAESCWkYFSbCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Province = _t, Country = _t, #"11/23/20" = _t, #"11/24/20" = _t, #"11/25/20" = _t, #"11/26/20" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Province", type text}, {"Country", type text}, {"11/23/20", type text}, {"11/24/20", type text}, {"11/25/20", type text}, {"11/26/20", type text}}),
    GetProvinceCountryAndLastColumn = Table.SelectColumns(#"Changed Type", {"Province","Country"}& {List.Last(Table.ColumnNames(#"Changed Type"))}),
    GetDay = if Text.Length(Text.From(Date.Day(DateTime.FixedLocalNow())))=2 then Text.From(Date.Day(DateTime.FixedLocalNow())) else "0"&Text.From(Date.Day(DateTime.FixedLocalNow())),
    GetMonth =  if Text.Length(Text.From(Date.Month(DateTime.FixedLocalNow())))=2 then Text.From(Date.Month(DateTime.FixedLocalNow())) else "0"&Text.From(Date.Month(DateTime.FixedLocalNow())),
    GetYear = Text.End(Text.From(Date.Year(DateTime.FixedLocalNow())),2),
    CalculateTodayInFormatMMDDYY = GetMonth&"/"&GetDay&"/"&GetYear,
    GetProvinceCountryAndTodayColumn = Table.SelectColumns(#"Changed Type", {"Province","Country"}& {CalculateTodayInFormatMMDDYY})
   
in
    GetProvinceCountryAndTodayColumn

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

View solution in original post

2 REPLIES 2
Jimmy801
Community Champion
Community Champion

Hello @anaescobararias 

 

check out this solutions. The first approach is to select column Province and country and the last column (check out step GetProvinceCountryAndLastColumn ). The second approach calculates today date in format MM/DD/YY and then choose this column name instead of the last column. But I saw that the first may is written like 05-01-20 and so this logic would not work. (check step GetProvinceCountryAndTodayColumn).

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUXICYlMgNjQAESCWkYFSbCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Province = _t, Country = _t, #"11/23/20" = _t, #"11/24/20" = _t, #"11/25/20" = _t, #"11/26/20" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Province", type text}, {"Country", type text}, {"11/23/20", type text}, {"11/24/20", type text}, {"11/25/20", type text}, {"11/26/20", type text}}),
    GetProvinceCountryAndLastColumn = Table.SelectColumns(#"Changed Type", {"Province","Country"}& {List.Last(Table.ColumnNames(#"Changed Type"))}),
    GetDay = if Text.Length(Text.From(Date.Day(DateTime.FixedLocalNow())))=2 then Text.From(Date.Day(DateTime.FixedLocalNow())) else "0"&Text.From(Date.Day(DateTime.FixedLocalNow())),
    GetMonth =  if Text.Length(Text.From(Date.Month(DateTime.FixedLocalNow())))=2 then Text.From(Date.Month(DateTime.FixedLocalNow())) else "0"&Text.From(Date.Month(DateTime.FixedLocalNow())),
    GetYear = Text.End(Text.From(Date.Year(DateTime.FixedLocalNow())),2),
    CalculateTodayInFormatMMDDYY = GetMonth&"/"&GetDay&"/"&GetYear,
    GetProvinceCountryAndTodayColumn = Table.SelectColumns(#"Changed Type", {"Province","Country"}& {CalculateTodayInFormatMMDDYY})
   
in
    GetProvinceCountryAndTodayColumn

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

This works like a charm!

 

Thank you @Jimmy801 🙂

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