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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
credencial
Frequent Visitor

Transforming Data with M

Hi folks,

I have a table data:

 

Screenshot_2.png

 

I need create two more columns like this:

 

Screenshot_3.png

 

and fill in the START and END columns following the formula:

 

START = END OF PREVIOUS MONTH (in this case the month of september)

END = (START + ENTRANCE) - EXIT

 

The dates are varied, they can comprise several periods according to the user's parameter date filter. I always have the START number for the first month given through a "STARTDATE" measure DAX.

I imagine the path is to do in M, can you give me a light?

Thanks for any help.

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @credencial ,

 

Here is the whole M syntax:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WKk4t0DcyUNJRgiBDAwOlWJ1opfzkEoiwKYgwAysAiefll0HELUCEoRFcIiU1GSJhhKQhFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Entrance = _t, Exit = _t, End = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type text}, {"Entrance", Int64.Type}, {"Exit", Int64.Type}, {"End", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each try #"Added Index" [End] {[Index] - 1} otherwise null),
    #"Filled Down" = Table.FillDown(#"Added Custom",{"End"}),
    #"Added Custom1" = Table.AddColumn(#"Filled Down", "Custom.1", each if [Index]=0 then [End] else [End]+List.Sum(List.Range(#"Filled Down"[Entrance],1,[Index]))-List.Sum(List.Range(#"Filled Down"[Exit],1,[Index]))),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Custom"}),
    #"Added Custom2" = Table.AddColumn(#"Removed Columns", "Custom", each try #"Added Custom1" [Custom.1]{[Index] - 1} otherwise null),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom2",{"Index", "End"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns1",{{"Custom.1", "End"}, {"Custom", "Start"}})
in
    #"Renamed Columns"

The final result is this.

Screenshot 2021-07-09 173943.png

 

Best Regards,

Stephen Tao

 

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

4 REPLIES 4
credencial
Frequent Visitor

Thanks for solution @Anonymous. Perfect.

mahoneypat
Microsoft Employee
Microsoft Employee

Here's one way to do it in the query editor.  To see how it works, just create a blank query, open the Advanced Editor and replace the text there with the M code below.  Did you mean to do + Exit - Entrance, since the End date is before the Start date with the formula above?  You can adapt this, if so.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wyk8u0TcyUNJRMgURZgZKsTrRSnn5ZRBBCxBhaAQRTUlNhogawZTGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Entrance = _t, Exit = _t]),
    #"Added Custom" = Table.AddColumn(Source, "DateForCalc", each "1/"&[Date]),
    #"Changed Type" = Table.TransformColumnTypes(#"Added Custom",{{"Entrance", Int64.Type}, {"Exit", Int64.Type}, {"DateForCalc", type date}}),
    #"Added Custom1" = Table.AddColumn(#"Changed Type", "Start", each Date.EndOfMonth(Date.AddMonths([DateForCalc], -1)), type date),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "End", each Date.AddDays([Start], [Entrance] - [Exit]), type date)
in
    #"Added Custom2"

 

Pat

 





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Thanks @mahoneypat .

 

I tested your suggestion, but I didn't get the result. Maybe I didn't explain it right. I need this result:

 

credencial_1-1625621807101.png

 

Anonymous
Not applicable

Hi @credencial ,

 

Here is the whole M syntax:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WKk4t0DcyUNJRgiBDAwOlWJ1opfzkEoiwKYgwAysAiefll0HELUCEoRFcIiU1GSJhhKQhFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Entrance = _t, Exit = _t, End = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type text}, {"Entrance", Int64.Type}, {"Exit", Int64.Type}, {"End", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each try #"Added Index" [End] {[Index] - 1} otherwise null),
    #"Filled Down" = Table.FillDown(#"Added Custom",{"End"}),
    #"Added Custom1" = Table.AddColumn(#"Filled Down", "Custom.1", each if [Index]=0 then [End] else [End]+List.Sum(List.Range(#"Filled Down"[Entrance],1,[Index]))-List.Sum(List.Range(#"Filled Down"[Exit],1,[Index]))),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Custom"}),
    #"Added Custom2" = Table.AddColumn(#"Removed Columns", "Custom", each try #"Added Custom1" [Custom.1]{[Index] - 1} otherwise null),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom2",{"Index", "End"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns1",{{"Custom.1", "End"}, {"Custom", "Start"}})
in
    #"Renamed Columns"

The final result is this.

Screenshot 2021-07-09 173943.png

 

Best Regards,

Stephen Tao

 

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

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.