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
PomJack
Frequent Visitor

How to return a value associated with the nearest time stamp in another table?

I have two tables, one that has a list of events and time stamps, time stamps that a fixture was used and the number of times that fixture has been used. I would like to pull the fixture and number of uses that most closely matches the timestamp of the event. See the example tables for a better idea of what is in each table and what I would like the end result to be. 

 

Event Table
Time StampEvent Name
8/1/2024 10:00A
8/1/2024 10:23A
8/1/2024 10:44A
8/1/2024 11:03B

 

 

Data Table
Time StampFixtureFixture Hits
8/1/2024 9:40X10
8/1/2024 9:45X11
8/1/2024 9:54X12
8/1/2024 10:02Y18
8/1/2024 10:06X13
8/1/2024 10:21Y19
8/1/2024 10:30Y20
8/1/2024 10:40Z5
8/1/2024 10:54X14
8/1/2024 11:05X15
8/1/2024 11:07Y21

 

Output Table
Time StampEvent NameFixtureFixture Hits
8/1/2024 10:00AY18
8/1/2024 10:23AY19
8/1/2024 10:44AZ5
8/1/2024 11:03BX15

 

I've tried the expression below based on the solution from a similar question, but I am getting this error: "A table of multiple values was supplied where a single value was expected"

 

column =
VAR _Current = 'Event Table'[TimeStamp]
VAR _Cross = CROSSJOIN('Event Table','Data Table')
VAR _Tbl = ADDCOLUMNS(_Cross, "@difference",ABS(INT('Data Table'[TimeStamp]-'Event Table'[Time Stamp])))
VAR _MinDiff = MINX(_Tbl,[@difference])
return SELECTCOLUMNS(FILTER(_Tbl,[@difference] = _MinDiff),"newCol", 'Data Table'[TimeStamp])
 
Any help would be appreciated.
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi, @PomJack 

 

You can try the following methods.

Column:

Nearest time = 
Var _Min=CALCULATE(MIN('Data Table'[Time Stamp]),FILTER('Data Table',[Time Stamp]>EARLIER('Event Table'[Time Stamp])))
Var _Max=CALCULATE(MAX('Data Table'[Time Stamp]),FILTER('Data Table',[Time Stamp]<EARLIER('Event Table'[Time Stamp])))
Var _Mindiff=ABS(DATEDIFF([Time Stamp],_Min,MINUTE))
Var _Maxdiff=ABS(DATEDIFF([Time Stamp],_Max,MINUTE))
RETURN
IF(_Maxdiff<_Mindiff,_Max,_Min)
Fixture = CALCULATE(MAX('Data Table'[Fixture]),FILTER('Data Table',[Time Stamp]=EARLIER('Event Table'[Nearest time])))
Fixture Hits = CALCULATE(MAX('Data Table'[Fixture Hits]),FILTER('Data Table',[Time Stamp]=EARLIER('Event Table'[Nearest time])))

vzhangtinmsft_0-1724307118031.png

Is this the result you expected?

 

Best Regards,

Community Support Team _Charlotte

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

1 REPLY 1
Anonymous
Not applicable

Hi, @PomJack 

 

You can try the following methods.

Column:

Nearest time = 
Var _Min=CALCULATE(MIN('Data Table'[Time Stamp]),FILTER('Data Table',[Time Stamp]>EARLIER('Event Table'[Time Stamp])))
Var _Max=CALCULATE(MAX('Data Table'[Time Stamp]),FILTER('Data Table',[Time Stamp]<EARLIER('Event Table'[Time Stamp])))
Var _Mindiff=ABS(DATEDIFF([Time Stamp],_Min,MINUTE))
Var _Maxdiff=ABS(DATEDIFF([Time Stamp],_Max,MINUTE))
RETURN
IF(_Maxdiff<_Mindiff,_Max,_Min)
Fixture = CALCULATE(MAX('Data Table'[Fixture]),FILTER('Data Table',[Time Stamp]=EARLIER('Event Table'[Nearest time])))
Fixture Hits = CALCULATE(MAX('Data Table'[Fixture Hits]),FILTER('Data Table',[Time Stamp]=EARLIER('Event Table'[Nearest time])))

vzhangtinmsft_0-1724307118031.png

Is this the result you expected?

 

Best Regards,

Community Support Team _Charlotte

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

 

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

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

July PBI25 Carousel

Power BI Monthly Update - July 2025

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