cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
obadaabdullah
New Member

Changes by Date and Items

hi all, i have a table in power bi desktop as in the following, i need to calculate the daily changes for each item starting from the minimum value whcih is already on the first date,new dates are added every day with new values (accumulated)

 

NameDateCumulative Value
item1date11
item2date16
item3date19
item1date26
item2date212
item3date216
item1date311
item2date326
item3date328
1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @obadaabdullah ,

You can try this query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WyixJzTVU0lEyMjAy1DfRBzENlWJ1IBJGqBJmcAljVAlLuASSUUYoOoxQJQyNsJkFljHDZhhIkSFWh4G1Y3UZmGmhFBsLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Date = _t, #"Cumulative Value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Date", type date}, {"Cumulative Value", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Name"}, {{"Data", each let tab=Table.AddIndexColumn(_,"Index",1,1,Int64.Type) in Table.AddColumn(tab,"New",(x)=>try Table.Max( Table.SelectRows(tab,(y)=>y[Index]=x[Index]-1),"Index")[Cumulative Value] otherwise (x)[Cumulative Value] ), type table [Name=nullable text, Date=nullable date]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "New Data", each Table.AddColumn([Data],"Diff", each [Cumulative Value] - [New])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Data"}),
    #"Expanded New Data" = Table.ExpandTableColumn(#"Removed Columns", "New Data", {"Date", "Cumulative Value", "Diff"}, {"New Data.Date", "New Data.Cumulative Value", "New Data.Diff"}),
    #"Sorted Rows" = Table.Sort(#"Expanded New Data",{{"New Data.Date", Order.Ascending}, {"Name", Order.Ascending}}),
    #"Renamed Columns" = Table.RenameColumns(#"Sorted Rows",{{"New Data.Date", "Date"}, {"New Data.Cumulative Value", "Cumulative Value"}, {"New Data.Diff", "Diff"}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Date", type date}, {"Cumulative Value", Int64.Type}, {"Diff", Int64.Type}})
in
    #"Changed Type1"

diff.png

 

Best Regards,
Community Support Team _ Yingjie Li
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
v-yingjl
Community Support
Community Support

Hi @obadaabdullah ,

You can try this query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WyixJzTVU0lEyMjAy1DfRBzENlWJ1IBJGqBJmcAljVAlLuASSUUYoOoxQJQyNsJkFljHDZhhIkSFWh4G1Y3UZmGmhFBsLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Date = _t, #"Cumulative Value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Date", type date}, {"Cumulative Value", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Name"}, {{"Data", each let tab=Table.AddIndexColumn(_,"Index",1,1,Int64.Type) in Table.AddColumn(tab,"New",(x)=>try Table.Max( Table.SelectRows(tab,(y)=>y[Index]=x[Index]-1),"Index")[Cumulative Value] otherwise (x)[Cumulative Value] ), type table [Name=nullable text, Date=nullable date]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "New Data", each Table.AddColumn([Data],"Diff", each [Cumulative Value] - [New])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Data"}),
    #"Expanded New Data" = Table.ExpandTableColumn(#"Removed Columns", "New Data", {"Date", "Cumulative Value", "Diff"}, {"New Data.Date", "New Data.Cumulative Value", "New Data.Diff"}),
    #"Sorted Rows" = Table.Sort(#"Expanded New Data",{{"New Data.Date", Order.Ascending}, {"Name", Order.Ascending}}),
    #"Renamed Columns" = Table.RenameColumns(#"Sorted Rows",{{"New Data.Date", "Date"}, {"New Data.Cumulative Value", "Cumulative Value"}, {"New Data.Diff", "Diff"}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Date", type date}, {"Cumulative Value", Int64.Type}, {"Diff", Int64.Type}})
in
    #"Changed Type1"

diff.png

 

Best Regards,
Community Support Team _ Yingjie Li
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

artemus
Microsoft
Microsoft

You can use the following formula, just replace MyTable with the name of the previous step:

 

= Table.FromColumns(Table.ToColumns(MyTable) & {List.Accumulate(MyTable[Cumulative Value], [List = {}, Prev = 0], (current, next) => [List = current[List] & {next - current[Prev]}, Prev = next - current[Prev]])[List]}, Table.ColumnNames(MyTable) & {"DoD"})

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors