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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
Afiq_Danial
Helper II
Helper II

Power Query Adding of Columns

Hi I have a data that looks currently like this:

 

Afiq_Danial_0-1667147590804.png

The start date and end date in the table above are for each staff. For example, Chloe is assigned to Job A from 2 October 2022 to 21 October 2022. However, Job A has been running from 1 October 2022 to 31 October.

 

My goal right now is to take the minimum and maximum date of each job and put it in a new column. I want my data table to look like this now:

Afiq_Danial_1-1667147761245.png

 

Note: I have to do this in Power Query Editor, I'm not that familiar with Power Query so I would appreciate all the help i can get. 

 

Thank You!

1 ACCEPTED SOLUTION
hnguy71
Memorable Member
Memorable Member

Hi @Afiq_Danial ,

 

You may try this sample:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcsxLqVTSUfLKT1JwBNKGBvrG+kYGRkZQtiGEE6sTreRUVJmYh6rUEEmpoQlCqXNGTn4qqlIjJKVGSKYGJxYlZkCVOoGkDfXN4UoN9Y0NEEq9EnNTi1GVGhgjqUV2gWNxRk5qJZpiSyTFcDfEAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Staff Name" = _t, #"Job Name" = _t, #"Start Date" = _t, #"End Date" = _t]),
    DefaultDataTypes = Table.TransformColumnTypes(Source,{{"Start Date", type date}, {"End Date", type date}}),

    // start from here. Find your min and max dates for specific job.
    FindMinMax = Table.AddColumn(DefaultDataTypes, "Custom", each 
    let 
        getJobs = [Job Name],
        selectJobs = Table.SelectRows(DefaultDataTypes, each ([Job Name] = getJobs)),
        minMax = Table.Group(selectJobs, {"Job Name"}, { {"Start Job Duration", each List.Min([Start Date]), type nullable date}, {"End Job Duration", each List.Max([End Date]), type nullable date}  })
    in
        minMax
    ),
    
    // expand
    ExpandMinMax = Table.ExpandTableColumn(FindMinMax, "Custom", {"Start Job Duration", "End Job Duration"}, {"Start Job Duration", "End Job Duration"}),
    ChangeDateType = Table.TransformColumnTypes(ExpandMinMax,{{"Start Job Duration", type date}, {"End Job Duration", type date}})
in
    ChangeDateType

 

 

Here's the output of that:

hnguy71_0-1667161427935.png

 

EDIT: Attaching sample pbix just in case.



Did I answer your question?
Please help by clicking the thumbs up button and mark my post as a solution!

View solution in original post

2 REPLIES 2
hnguy71
Memorable Member
Memorable Member

Hi @Afiq_Danial ,

 

You may try this sample:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcsxLqVTSUfLKT1JwBNKGBvrG+kYGRkZQtiGEE6sTreRUVJmYh6rUEEmpoQlCqXNGTn4qqlIjJKVGSKYGJxYlZkCVOoGkDfXN4UoN9Y0NEEq9EnNTi1GVGhgjqUV2gWNxRk5qJZpiSyTFcDfEAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Staff Name" = _t, #"Job Name" = _t, #"Start Date" = _t, #"End Date" = _t]),
    DefaultDataTypes = Table.TransformColumnTypes(Source,{{"Start Date", type date}, {"End Date", type date}}),

    // start from here. Find your min and max dates for specific job.
    FindMinMax = Table.AddColumn(DefaultDataTypes, "Custom", each 
    let 
        getJobs = [Job Name],
        selectJobs = Table.SelectRows(DefaultDataTypes, each ([Job Name] = getJobs)),
        minMax = Table.Group(selectJobs, {"Job Name"}, { {"Start Job Duration", each List.Min([Start Date]), type nullable date}, {"End Job Duration", each List.Max([End Date]), type nullable date}  })
    in
        minMax
    ),
    
    // expand
    ExpandMinMax = Table.ExpandTableColumn(FindMinMax, "Custom", {"Start Job Duration", "End Job Duration"}, {"Start Job Duration", "End Job Duration"}),
    ChangeDateType = Table.TransformColumnTypes(ExpandMinMax,{{"Start Job Duration", type date}, {"End Job Duration", type date}})
in
    ChangeDateType

 

 

Here's the output of that:

hnguy71_0-1667161427935.png

 

EDIT: Attaching sample pbix just in case.



Did I answer your question?
Please help by clicking the thumbs up button and mark my post as a solution!

Thank you so much, it works! Appreciate it

 

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.