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

Update Historical Table with Daily Data in Power Query

I start this exercice having two tables with the same Columns (ID, Offer, Price & Total Views). One of them acts as my Historical data, the second one is a daily update that I use to feed the first one. Both in Excel format.

In orther to do this, I run a JoinKind RightAnti to check first new items that later on I append into my Historical table. Now I would like to update the columns Offer & Price in case they have changed, so I use JoinKind RightAnti selecting ID & Offer to identify those rows (same operation for Price column). My first question is, how do I replace the values of the Historical Offer & Price columns with the Daily data I have obtained? When that, How can I create and if statement to add a new column and fill a cell in the same row with today's date in my Hitorical Table due to the status update? Also, Total Views column will be replace daily.

The final result will be my Historical Table having ID, Offer, Price, Date & Total Views columns. Is there any way to get it done inside power query? Please, any help would be much appreciated. Regards

 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Community Support
Community Support

Re: Update Historical Table with Daily Data in Power Query

Hi @MJimenez ,

You could refer to below M code yo see whether it work or not.

let
    Source = Table.NestedJoin(history, {"id"}, daily, {"id"}, "daily", JoinKind.LeftOuter),
    #"Expanded daily" = Table.ExpandTableColumn(Source, "daily", {"price", "view"}, {"daily.price", "daily.view"}),
    Custom1 = Table.ReplaceValue(#"Expanded daily",each [price], each if [price]=[daily.price] or [daily.price]=null then [price] else [daily.price], Replacer.ReplaceValue, {"price"}),
    Custom2 = Table.ReplaceValue(#"Custom1",each [view], each if [view]=[daily.view] or [daily.view]=null then [view] else [daily.view], Replacer.ReplaceValue, {"view"}),
    Custom3 = Table.ReplaceValue(#"Expanded daily",each [daily.view], each if [view]=[daily.view] and [price]=[daily.price] or [daily.view]=null then null else DateTime.LocalNow(), Replacer.ReplaceValue, {"daily.view"}),
    #"Removed Columns" = Table.RemoveColumns(Custom3,{"daily.price"})
in
    #"Removed Columns"

 In addition, if the date column in daily table, you could change code like below(you also need to exapnd this column in table)

Custom3 = Table.ReplaceValue(#"Expanded daily",each [daily.view], each if [view]=[daily.view] and [price]=[daily.price] or [daily.view]=null then null else [daily.date], Replacer.ReplaceValue, {"daily.view"})

 

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

2 REPLIES 2
Highlighted
Community Support
Community Support

Re: Update Historical Table with Daily Data in Power Query

Hi @MJimenez ,

You could refer to below M code yo see whether it work or not.

let
    Source = Table.NestedJoin(history, {"id"}, daily, {"id"}, "daily", JoinKind.LeftOuter),
    #"Expanded daily" = Table.ExpandTableColumn(Source, "daily", {"price", "view"}, {"daily.price", "daily.view"}),
    Custom1 = Table.ReplaceValue(#"Expanded daily",each [price], each if [price]=[daily.price] or [daily.price]=null then [price] else [daily.price], Replacer.ReplaceValue, {"price"}),
    Custom2 = Table.ReplaceValue(#"Custom1",each [view], each if [view]=[daily.view] or [daily.view]=null then [view] else [daily.view], Replacer.ReplaceValue, {"view"}),
    Custom3 = Table.ReplaceValue(#"Expanded daily",each [daily.view], each if [view]=[daily.view] and [price]=[daily.price] or [daily.view]=null then null else DateTime.LocalNow(), Replacer.ReplaceValue, {"daily.view"}),
    #"Removed Columns" = Table.RemoveColumns(Custom3,{"daily.price"})
in
    #"Removed Columns"

 In addition, if the date column in daily table, you could change code like below(you also need to exapnd this column in table)

Custom3 = Table.ReplaceValue(#"Expanded daily",each [daily.view], each if [view]=[daily.view] and [price]=[daily.price] or [daily.view]=null then null else [daily.date], Replacer.ReplaceValue, {"daily.view"})

 

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

Highlighted
Frequent Visitor

Re: Update Historical Table with Daily Data in Power Query

Wow! It hepls me to sort my code out! Thanks a lot Zoe.

Helpful resources

Announcements

August Community Highlights

Check out a full recap of the month!

August 2020 CYST Challenge

Check out the winners of the recent 'Can You Solve These?' community challenge!

Experience what’s next for Power BI

Join us for an in-depth look at the new Power BI features and capabilities at the free Microsoft Business Applications Launch Event.

Top Solution Authors