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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
dcormiernj
Helper I
Helper I

Need help to Merge two queries between date range

I have two tables very simply represented below

Extract of employee table which has many columns but these are the two key ones for this issue.  each employee has a start date.  We track our weekly hours weekly with the week end date being Sunday.  I am trying to do a visual that shows Total new employees by week associated with the week end date.  So for example the first three in the table below started on 2/1/21.  The week end date for that week is Sunday 2/7/21 so I want to show 3 employees started during week ending 2/7/21.  I have another table that has the hours data and two of the columns are week start date and week end date.  I have tried several ways, power query and DAx to try to get this data and not sure what I am doing wrong.  Below the pasted emp table extract I show two other extracts; the hours table and then the result i am looking for.   I need to create a graph of total new emps by week.  Not sure I explained this correctly but can anyone help???  thank you

 

Emp data

dcormiernj_1-1657416134803.png

 

Hours Table extract

dcormiernj_0-1657416098270.png

 

Result I am looking for

dcormiernj_2-1657416200426.png

 

 

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("RcrBEYAgDETRXjjjLFlJHIqwAoaDZdi9RERuP3lbayAETJQQex4jW6xBIMkvduhto10y8oT8jxwUZYJCdAH37bzu982y3gabe4Pwg/YA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Week Start Date" = _t, #"Week End Date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Week Start Date", type date}, {"Week End Date", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.SelectRows(#"Emp data", (x)=> x[Start Date]>=[Week Start Date] and x[Start Date]<=[Week End Date]){0}[Count], Int64.Type)
in
    #"Added Custom"

CODE FOR Emp data table

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZcvRCcAgDAXAXfItpHmatA7QKcT91zBVKIH8HtwY9AoVAgvjgtAsLkhSkzQXYakf4ZA6NbYgluR2Ue5Bni3QQN3J/jYX", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee Name" = _t, #"Start Date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee Name", type text}, {"Start Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Start Date"}, {{"Count", each Table.RowCount(_), Int64.Type}})
in
    #"Grouped Rows"

 Dowbload pbix file from here - https://1drv.ms/u/s!Akd5y6ruJhvhug7AWcPW9kkOhHHs?e=KoxVqn 

View solution in original post

2 REPLIES 2
dcormiernj
Helper I
Helper I

Thank you

Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("RcrBEYAgDETRXjjjLFlJHIqwAoaDZdi9RERuP3lbayAETJQQex4jW6xBIMkvduhto10y8oT8jxwUZYJCdAH37bzu982y3gabe4Pwg/YA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Week Start Date" = _t, #"Week End Date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Week Start Date", type date}, {"Week End Date", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.SelectRows(#"Emp data", (x)=> x[Start Date]>=[Week Start Date] and x[Start Date]<=[Week End Date]){0}[Count], Int64.Type)
in
    #"Added Custom"

CODE FOR Emp data table

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZcvRCcAgDAXAXfItpHmatA7QKcT91zBVKIH8HtwY9AoVAgvjgtAsLkhSkzQXYakf4ZA6NbYgluR2Ue5Bni3QQN3J/jYX", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee Name" = _t, #"Start Date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee Name", type text}, {"Start Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Start Date"}, {{"Count", each Table.RowCount(_), Int64.Type}})
in
    #"Grouped Rows"

 Dowbload pbix file from here - https://1drv.ms/u/s!Akd5y6ruJhvhug7AWcPW9kkOhHHs?e=KoxVqn 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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