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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
a100
Frequent Visitor

New column to pull from separate query where date is between

I have a table of products and the times they were being produced between (Changeover Table). I want to link this with an Output Table to pull in the product that was being produced at the time of the timestamp. However the timestamps in the second table do not typically match any of the timestamps in the Changeover Table.

 

Some example data is below. I would like to have the Product column populated with 'A'.

Table 1: Changeovers

Product

StartDateTime

EndDateDate

A

01/03/2021 09:32:30

04/03/2021 21:39:42

B

04/03/2021 21:39:43

21/03/2021 00:42:11

C

21/03/2021 00:42:12

03/04/2021 20:32:12

 

Table 2: Output

Timestamp

Output since last reading

Product

02/03/2021 00:10:00

10

 

02/03/2021 00:20:00

13

 

02/03/2021 00:30:00

9

 

 

1 ACCEPTED SOLUTION
Vera_33
Resident Rockstar
Resident Rockstar

Hi @a100 

 

Is it possible to return more than 1 product? Say Timestamp happens to be between Start and End for more than 1 product? In your case, just A, otherwise combine them?

Vera_33_0-1640156194157.png

= Table.AddColumn(yourPreviousStep, "Product", each [a=[Timestamp],
b=Table.SelectRows(Changeovers, each [StartDateTime]<=a and [EndDateDate]>=a),
c=Text.Combine(b[Product],",")][c])

 

View solution in original post

2 REPLIES 2
a100
Frequent Visitor

Hi @Vera_33, thank you this has worked!

Vera_33
Resident Rockstar
Resident Rockstar

Hi @a100 

 

Is it possible to return more than 1 product? Say Timestamp happens to be between Start and End for more than 1 product? In your case, just A, otherwise combine them?

Vera_33_0-1640156194157.png

= Table.AddColumn(yourPreviousStep, "Product", each [a=[Timestamp],
b=Table.SelectRows(Changeovers, each [StartDateTime]<=a and [EndDateDate]>=a),
c=Text.Combine(b[Product],",")][c])

 

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors