cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Frequent Visitor

Replace Column Headers with current dates

Hi,

 

I'm new to this:

 

I'm trying to replace column headers with the current week in one column and iterate from there.  For example, I have columns that say "week 1", "week 2", "week 3".....etc.  I would like to replace "week 1" with the date of the current week (start or end doesn't matter), "week 2" as a week from now, "week 3" as two weeks from now, and so on.  Is that possible?

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Super User I
Super User I

Re: Replace Column Headers with current dates

Hello @jcbutts 

 

I recognized that I got you wrong. So week 1 is always the current week.

I fixed this now. Check out this one if it works

let
	Source = #table
	(
		{"week 1","week 2","week 3","other data","abc","week 52"},
		{
			{"","","","","",""}
		}
	),
    ColumnNames = Table.ColumnNames
    (
        Source
    ),
    TransformWeekInDate = List.Transform
    (
        ColumnNames,
        (row)=> try
        if Text.Contains(row,"week") or Text.Contains(row,"Week") then 
            Text.From(Date.AddDays(Date.AddDays( Date.From(DateTime.FixedLocalNow()), Date.DayOfWeek(DateTime.FixedLocalNow())*-1), (Number.From(Text.Replace(row, "week ", ""))-1)*7))
            else 
            row
        otherwise
        row
    ),
    RenameColumnHeader = Table.RenameColumns
    (
        Source,
        List.Zip({ColumnNames,TransformWeekInDate})
    )
in
	RenameColumnHeader

 

Jimmy

View solution in original post

14 REPLIES 14
Highlighted
Super User II
Super User II

Re: Replace Column Headers with current dates

Hi @jcbutts 

try smth

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i44FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Week1 = _t, Week2 = _t, Week3 = _t]),
    #"Renamed Columns" = Table.RenameColumns(Source,{"Week1", Text.From(Date.StartOfWeek(Date.From(DateTime.LocalNow())))}),
    #"Renamed Columns2" = Table.RenameColumns(#"Renamed Columns",{"Week2", Text.From(Date.StartOfWeek(Date.AddWeeks(Date.From(DateTime.LocalNow()),1)))})
in
    #"Renamed Columns2"

 

do not hesitate to give a kudo to useful posts and mark solutions as solution

LinkedIn

 


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

Highlighted
Frequent Visitor

Re: Replace Column Headers with current dates

Thanks.  I already have some modifications prior to this step, so how do I change your code to accept the existing source?  I get an error in the advanced editor saying the variable named 'source' is already defined.

Highlighted
Super User II
Super User II

Re: Replace Column Headers with current dates

@jcbutts 

you should replace source here

 #"Renamed Columns" = Table.RenameColumns(Source,{"Week1", Text.From(Date.StartOfWeek(Date.From(DateTime.LocalNow())))}),

to the name of your previous step,like you could see here (#"Renamed Columns" is a name of previous step)

    #"Renamed Columns2" = Table.RenameColumns(#"Renamed Columns",{"Week2", Text.From(Date.StartOfWeek(Date.AddWeeks(Date.From(DateTime.LocalNow()),1)))})

 

do not hesitate to give a kudo to useful posts and mark solutions as solution

 


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

Highlighted
Frequent Visitor

Re: Replace Column Headers with current dates

Hi Az38,

 

Sorry, that's not making sense to me.  My code looks like this:

 

let
Source = Excel.Workbook(File.Contents("V:\Dpmts\Forecast.xlsx"), null, true),
#"US_Forecast and Inventory Plann_Sheet" = Source{[Item="US_Forecast and Inventory Plann",Kind="Sheet"]}[Data],
#"Removed Top Rows" = Table.Skip(#"US_Forecast and Inventory Plann_Sheet",1),
#"Promoted Headers" = Table.PromoteHeaders(#"Removed Top Rows", [PromoteAllScalars=true]),
#"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"ASIN", type text}})
in
#"Changed Type"

 

I assume I need to keep the line calling out source= my excel workbook.  Do I put in a new "let"-> "in" sequence or does your code get nested in to what I have?

Highlighted
Super User II
Super User II

Re: Replace Column Headers with current dates

@jcbutts 

try

let
Source = Excel.Workbook(File.Contents("V:\Dpmts\Forecast.xlsx"), null, true),
#"US_Forecast and Inventory Plann_Sheet" = Source{[Item="US_Forecast and Inventory Plann",Kind="Sheet"]}[Data],
#"Removed Top Rows" = Table.Skip(#"US_Forecast and Inventory Plann_Sheet",1),
#"Promoted Headers" = Table.PromoteHeaders(#"Removed Top Rows", [PromoteAllScalars=true]),
#"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"ASIN", type text}}),
    #"Renamed Columns" = Table.RenameColumns(Source,{"Week1", Text.From(Date.StartOfWeek(Date.From(DateTime.LocalNow())))}),
    #"Renamed Columns2" = Table.RenameColumns(#"Renamed Columns",{"Week2", Text.From(Date.StartOfWeek(Date.AddWeeks(Date.From(DateTime.LocalNow()),1)))}),
    #"Renamed Columns3" = Table.RenameColumns(#"Renamed Columns2",{"Week3", Text.From(Date.StartOfWeek(Date.AddWeeks(Date.From(DateTime.LocalNow()),2)))})
in
    #"Renamed Columns3"

 

do not hesitate to give a kudo to useful posts and mark solutions as solution

LinkedIn


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

Highlighted
Super User I
Super User I

Re: Replace Column Headers with current dates

Hello @jcbutts 

 

this solution should be really dynamic and working for 2020. The column names have to be "week " and the number. 

let
	Source = #table
	(
		{"week 1","week 2","week 3","other data","abc","week 52"},
		{
			{"","","","","",""}
		}
	),
    ColumnNames = Table.ColumnNames
    (
        Source
    ),
    TransformWeekInDate = List.Transform
    (
        ColumnNames,
        (row)=> try
        if Text.Contains(row,"week") or Text.Contains(row,"Week") then 
            Text.From(Date.AddDays(#date(2019,12,30), (Number.From(Text.Replace(row, "week ", ""))-1)*7))
            else 
            row
        otherwise
        row
    ),
    RenameColumnHeader = Table.RenameColumns
    (
        Source,
        List.Zip({ColumnNames,TransformWeekInDate})
    )
in
	RenameColumnHeader

 

Copy paste this code to the advanced editor to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query, or I could create a custom function what makes it easier to apply if you are not used that much to power query.

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

Highlighted
Super User IV
Super User IV

Re: Replace Column Headers with current dates

Hi @jcbutts 

 

You can try this as an alternative.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i44FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Id = _t, #"week 1" = _t, #"week 2" = _t, #"week 3" = _t]),
    transformColumnNames = List.Transform( 
        List.Select( 
            Table.ColumnNames( Source ), 
            ( i ) => Text.Contains( i, "week" ) 
        ), 
        (i) => let 
            extractWeek = Number.From( Text.Replace( i, "week ", "" ) ),
            weekStart = Date.StartOfWeek( DateTime.LocalNow() ),
            newName = 
                Text.From( 
                    Date.From( 
                        Date.AddWeeks( weekStart, extractWeek - 1 ) 
                    ) 
                )
        in  
            { i, newName }
    ),
    #"Renamed Columns" = Table.RenameColumns(Source, transformColumnNames )
in
    #"Renamed Columns"

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

 

Highlighted
Frequent Visitor

Re: Replace Column Headers with current dates

I tried all of these.  For the first solution, I got an error saying the colunmn "Week 1" wasn't found.  My actual column header is "Week 1- Mean Forecast" so I modified the code to match (checking a few different iterations for the spacing between the dash and the words) but it all came up with the same error...."Week 1 - Mean Forecast" not found.

 

For the other two solutions, the code was accepted, but it resulted in a table with one line.   The headers were things like "Name" and "Hidden", and the data was just the name of my data file and the type.

Highlighted
Super User IV
Super User IV

Re: Replace Column Headers with current dates

Hi @jcbutts 

 

I've adjusted the code to accommodate the different Column name structure.

 

Please see the attached file.

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

 

 

Helpful resources

Announcements
August 2020 Community Challenge: Can You Solve These?

August 2020 Community Challenge: Can You Solve These?

We're excited to announce our first cross-community 'Can You Solve These?' challenge!

Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Upcoming Events

Upcoming Events

Wondering what events you could join or have an event to promote yourself? Check out our Upcoming Events.

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

We are thrilled to announce we will begin running a monthly webinar series named Power BI Dev Camp.

Top Solution Authors
Top Kudoed Authors