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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
Ronnie7
Helper II
Helper II

In a dire need for help - result based on a subquery (max)

Hello,

 

I'm using the PowerBI desktop version and trying to convert a code from SQL to Power Query.

I Need to filder the result of a table in the query editor the SQL query is:

select wf.projectname,wf.StageName
  from MS_Workflow wf
  where
  wf.StageEntryDate = (select max(wf2.StageEntryDate) from MS_Workflow wf2 where wf.projectid = wf2.ProjectId)
  group by wf.ProjectName,StageName
  order by StageName desc
I need to be able to het the latest entry date for each projectID.

I have merged the table to iteslf to create a self-join but not sure how to convert this sub-query.

 

Thanks in Advance!

 

1 ACCEPTED SOLUTION
v-qiuyu-msft
Community Support
Community Support

Hi @Ronnie7,

 

When you connect to the SQL Database in desktop, you can write the T-SQL Query in this window:

 

Sample data:

 

a8.PNG

 

a1.PNGa7.PNG

 

Also you can get data from the table MS_Workflow and duplicate this query as MS_Workflow (2) in Query Editor, then follow below steps:

 

1. In query MS_Workflow, Goup by ProjectId, and return maximum StageEntryDate.

 

a2.PNG

 

2. Merge this MS_Workflow with MS_Workflow (2).

 

a3.PNG

3. Expand the column "projectname", "StageName".

 

a5.PNG

4. Uncheck Enable Load for MS_Workflow (2), this table MS_Workflow (2) will not display in the report.

 

a6.PNG

 

 

Backend Power Query is below:

 

let
    Source = Sql.Database("sql2016ga", "qiuyun"),
    dbo_MS_Workflow = Source{[Schema="dbo",Item="MS_Workflow"]}[Data],
    #"Grouped Rows" = Table.Group(dbo_MS_Workflow, {"projectid"}, {{"MAX", each List.Max([StageEntryDate]), type date}}),
    #"Merged Queries" = Table.NestedJoin(#"Grouped Rows",{"MAX"},#"MS_Workflow (2)",{"StageEntryDate"},"NewColumn",JoinKind.LeftOuter),
    #"Expanded NewColumn" = Table.ExpandTableColumn(#"Merged Queries", "NewColumn", {"projectname", "StageName"}, {"projectname", "StageName"})
in
    #"Expanded NewColumn"

 

 

a4.PNG

 

Best Regards,
Qiuyun Yu

Community Support Team _ Qiuyun Yu
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

5 REPLIES 5
v-qiuyu-msft
Community Support
Community Support

Hi @Ronnie7,

 

When you connect to the SQL Database in desktop, you can write the T-SQL Query in this window:

 

Sample data:

 

a8.PNG

 

a1.PNGa7.PNG

 

Also you can get data from the table MS_Workflow and duplicate this query as MS_Workflow (2) in Query Editor, then follow below steps:

 

1. In query MS_Workflow, Goup by ProjectId, and return maximum StageEntryDate.

 

a2.PNG

 

2. Merge this MS_Workflow with MS_Workflow (2).

 

a3.PNG

3. Expand the column "projectname", "StageName".

 

a5.PNG

4. Uncheck Enable Load for MS_Workflow (2), this table MS_Workflow (2) will not display in the report.

 

a6.PNG

 

 

Backend Power Query is below:

 

let
    Source = Sql.Database("sql2016ga", "qiuyun"),
    dbo_MS_Workflow = Source{[Schema="dbo",Item="MS_Workflow"]}[Data],
    #"Grouped Rows" = Table.Group(dbo_MS_Workflow, {"projectid"}, {{"MAX", each List.Max([StageEntryDate]), type date}}),
    #"Merged Queries" = Table.NestedJoin(#"Grouped Rows",{"MAX"},#"MS_Workflow (2)",{"StageEntryDate"},"NewColumn",JoinKind.LeftOuter),
    #"Expanded NewColumn" = Table.ExpandTableColumn(#"Merged Queries", "NewColumn", {"projectname", "StageName"}, {"projectname", "StageName"})
in
    #"Expanded NewColumn"

 

 

a4.PNG

 

Best Regards,
Qiuyun Yu

Community Support Team _ Qiuyun Yu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thanks @v-qiuyu-msft, this was really helpful.

 

My data source is actually an ODATA feed from Project Online to i can't use SQL and hence my struggle. Different table names, different language,  nonetheless, you solution with the grouping and expanding worked well.

 

Thanks,

Ran

BhaveshPatel
Community Champion
Community Champion

Please post the sample file or data for recreating a solution.

 

What you would like to do as per my understanding,

 

1. Firstly find wf.projectid = wf2.ProjectId in your table from MS_Workflow wf2.

2. Secondly find the max date in wf2.StageEntryDate ( As the table is filtered because of first step). This would be your desired wf.StageEntryDate.

3. Remove unneccessary columns 

4. Group the results by Grouping By Project Name and Stage Name.

Thanks & Regards,
Bhavesh

Love the Self Service BI.
Please use the 'Mark as answer' link to mark a post that answers your question. If you find a reply helpful, please remember to give Kudos.

Hi Bhavesh,

 

Is there a way i can write that SQL query in Power Query?

I'm not so sure how to implement those steps in Power BI.

 

Thanks again.

 

 

You just need to use Query editor ribbon interface to achieve this. PowerQuery is using "M" and It has its own syntex. It is powerful enough to convert your SQL into M code. Ribbon interface would create a code for you. As I said before, Please post the sample data to provide you a exact solution.

Thanks & Regards,
Bhavesh

Love the Self Service BI.
Please use the 'Mark as answer' link to mark a post that answers your question. If you find a reply helpful, please remember to give Kudos.

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors