Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreShape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.
I have two tables, one for scan items with ScanDate and another table for warehouses with warehouse AccessTime. Am trying to get the nearest AccessTime to the ScanDate for each item. It could be before or after the ScanDate as long as it's the closest.
Below is sample data and desired results.
I have tried various examples and none works. I would appreciate any help.
Solved! Go to Solution.
Hi, @eWise
According to your description , there is no associated [AcessTime] field in the scan table and you want to show the [UserId] field in the 'Scans' table. I download your .csv files , the [warehouseId] in the fourth row of your 'Scans' table does not have the data to be associated with in the 'WarehouseAccess' table, so the display is empty.
Here are the steps you can follow:
(1)I use the data you provided, the two table do not need to create relationship.
(2)We can click "New column" create two calculated columns in 'Scans' table :
AccessTime = var _groupBy_ID =DISTINCT( SELECTCOLUMNS( FILTER('WarehouseAccess' , 'WarehouseAccess'[warehouseId]='Scans'[warehouseId]) ,"AccessTime", [AccessTime] ))
var _compare_table =ADDCOLUMNS( CROSSJOIN({'Scans'[ScanDate]},_groupBy_ID) , "diff" ,ABS( [AccessTime]-[ScanDate]) )
var _min_diff= MINX(_compare_table ,[diff])
var _min_date = FILTER(_compare_table , [diff] =_min_diff)
return
CONCATENATEX(_min_date,[AccessTime],",")
UserId = var _groupBy_ID =DISTINCT( SELECTCOLUMNS( FILTER('WarehouseAccess' , 'WarehouseAccess'[warehouseId]='Scans'[warehouseId]) ,"AccessTime", [AccessTime] ))
var _compare_table =ADDCOLUMNS( CROSSJOIN({'Scans'[ScanDate]},_groupBy_ID) , "diff" ,ABS( [AccessTime]-[ScanDate]) )
var _min_diff= MINX(_compare_table ,[diff])
var _min_date =SELECTCOLUMNS( FILTER(_compare_table , [diff] =_min_diff) , "date", [AccessTime])
var _user_table = FILTER('WarehouseAccess' , 'WarehouseAccess'[warehouseId]='Scans'[warehouseId] && 'WarehouseAccess'[AccessTime] in _min_date )
return
CONCATENATEX(_user_table,[userId],",")
(3)Then we can meet your need , the result is as follows:
If this method cannot meet your need ,you can provide special output data as a table so that we can help you better .
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi, @eWise
According to your description, you want to group according to [WhID] to find the closest [AccessTime] to the corresponding [ScanDate].Right?
This is the steps you can follow:
We don't need to establish a relationship between these two tables.
(1)This is my test data:
(2)We can create a calculated column : "AccessTime"
AccessTime = var _groupBy_ID =DISTINCT( SELECTCOLUMNS( FILTER('WarehouseAccess' , 'WarehouseAccess'[WhID]='Scans'[WhID]) ,"AccessTime", [AccessTime] ))
var _compare_table =ADDCOLUMNS( CROSSJOIN({'Scans'[ScanDate]},_groupBy_ID) , "diff" ,ABS( [AccessTime]-[ScanDate]) )
var _min_diff= MINX(_compare_table ,[diff])
var _min_date = FILTER(_compare_table , [diff] =_min_diff)
return
CONCATENATEX(_min_date,[AccessTime],",")
(3)Then we can meet your need , the result is as follows:
If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Thanks Aniya @v-yueyunzh-msft for that. It does look promising, however in some instances, it's not pulling the accesstime even where it there was an access time at the warehouse. Am attaching sample data, with an additonal twist where I need to also pull the user id corresponding to the closest [AccessTime]. I need all the columns in the scans table in final results and the calculated AccessTime and the userId.
Please let me know incase it's something is not clear.
Thanks.
Hi, @eWise
According to your description , there is no associated [AcessTime] field in the scan table and you want to show the [UserId] field in the 'Scans' table. I download your .csv files , the [warehouseId] in the fourth row of your 'Scans' table does not have the data to be associated with in the 'WarehouseAccess' table, so the display is empty.
Here are the steps you can follow:
(1)I use the data you provided, the two table do not need to create relationship.
(2)We can click "New column" create two calculated columns in 'Scans' table :
AccessTime = var _groupBy_ID =DISTINCT( SELECTCOLUMNS( FILTER('WarehouseAccess' , 'WarehouseAccess'[warehouseId]='Scans'[warehouseId]) ,"AccessTime", [AccessTime] ))
var _compare_table =ADDCOLUMNS( CROSSJOIN({'Scans'[ScanDate]},_groupBy_ID) , "diff" ,ABS( [AccessTime]-[ScanDate]) )
var _min_diff= MINX(_compare_table ,[diff])
var _min_date = FILTER(_compare_table , [diff] =_min_diff)
return
CONCATENATEX(_min_date,[AccessTime],",")
UserId = var _groupBy_ID =DISTINCT( SELECTCOLUMNS( FILTER('WarehouseAccess' , 'WarehouseAccess'[warehouseId]='Scans'[warehouseId]) ,"AccessTime", [AccessTime] ))
var _compare_table =ADDCOLUMNS( CROSSJOIN({'Scans'[ScanDate]},_groupBy_ID) , "diff" ,ABS( [AccessTime]-[ScanDate]) )
var _min_diff= MINX(_compare_table ,[diff])
var _min_date =SELECTCOLUMNS( FILTER(_compare_table , [diff] =_min_diff) , "date", [AccessTime])
var _user_table = FILTER('WarehouseAccess' , 'WarehouseAccess'[warehouseId]='Scans'[warehouseId] && 'WarehouseAccess'[AccessTime] in _min_date )
return
CONCATENATEX(_user_table,[userId],",")
(3)Then we can meet your need , the result is as follows:
If this method cannot meet your need ,you can provide special output data as a table so that we can help you better .
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Thanks @Greg_Deckler but it isn't working. All dates are showing as 12/30/1899 00:09:47 with the difference being only in the time.
Two questions, I dont see VAR _Whid = [Whid] being used. Not sure wether that's by design or not. Also, is VAR _AccessTimes = RELATED('WareHouseAccess') meant to call the table or the AccessTime?
Thanks,
@eWise Did you see my second post? I deleted the first one. I thought I had edited it but for some reason both posts stayed. I believe the second one is correct where it returns the dates versus the time differences like the first one.
I did see your second post @Greg_Deckler . I tired that and played around a lot but it still give me the off dates like Tue, 17 Jun 1777 19:21:45 which I can't even validate.
@eWise Thinking something like:
AccessTime Column =
VAR __WhID = [WhID]
VAR __ScanDate = [ScanDate]
VAR __AccessTimes = RELATED('WarehouseAccess')
VAR __Min = MAXX(FILTER(__AccessTimes,[AccessTime]<[ScanDate]),[AccessTime])
VAR __Max = MINX(FILTER(__AccessTimes,[AccessTime]>=[ScanDate]),[AccessTime])
VAR __MinOffset = __ScanDate - __Min
VAR __MaxOffset = __Max - __ScanDate
RETURN
IF(__MinOffset < __MaxOffset, __Min, __Max)
User | Count |
---|---|
89 | |
88 | |
84 | |
81 | |
49 |
User | Count |
---|---|
150 | |
142 | |
112 | |
73 | |
55 |