Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
I am looking for logic to determine how to pull the following data
I have a fact table that has transaction date and time and computer per transaction the second table is the device table showing who was logged into the device (there is no log out). My intended logic will be to link date, and device ID and then find the time that is the first time found less the log in time from the fact table . So the first entry I want to determine BOB was logged and second ROB
Date Time Device
Example : 1/1/17 08:10:53 RFGN3550
1/1/17 10:13:40 RFGN3560
I have a device Log table that says who was logged into that device
Log in Date Time Device Person
Example: 1/1/17 08:00:00 RFGN3550 BOB
1/1/17 09:00:00 RFGN3550 MARY
1/1/17 09:00:00 RFGN3560 SAM
1/1/17 10:00:00 RFGN3550 ROB
Solved! Go to Solution.
This seems to have been deemed an M question, but here is one of those "dime a dozen" DAX solutions:
Calculated column in Transactions:
Person = VAR TransactionDateTime = Transactions[DateTime] RETURN CALCULATE ( //Arbitrary tie-breaker FIRSTNONBLANK ( Logins[Person], 0 ), CALCULATETABLE ( LASTNONBLANK ( Logins[DateTime], 0 ), Logins[DateTime] <= TransactionDateTime ) )
Owen 🙂
I suspect you've modified @OwenAuger's formula to only look at your Time columns!
Note that he checks a Date/Time column.
So to address this create a Date-Time Column in both tables like this
Date-Time = [Date]&" "&[Time]
Both of these columns will default to Text - so you need to convert them to Data Type - Date/Time - again in both tables.
This should resolve it!
Good Luck!
@brett_walton wrote:
Date Time DeviceExample : 1/1/17 08:10:53 RFGN3550
1/1/17 10:13:40 RFGN3560
I have a device Log table that says who was logged into that device
Log in Date Time Device Person
Example: 1/1/17 08:00:00 RFGN3550 BOB
1/1/17 09:00:00 RFGN3550 MARY
1/1/17 09:00:00 RFGN3560 SAM
1/1/17 10:00:00 RFGN3550 ROB
Sam is the only one logged in device 3560!
Maybe you meant to have Rob log in device 3560 - but as you've written it the second should be Sam
This seems to have been deemed an M question, but here is one of those "dime a dozen" DAX solutions:
Calculated column in Transactions:
Person = VAR TransactionDateTime = Transactions[DateTime] RETURN CALCULATE ( //Arbitrary tie-breaker FIRSTNONBLANK ( Logins[Person], 0 ), CALCULATETABLE ( LASTNONBLANK ( Logins[DateTime], 0 ), Logins[DateTime] <= TransactionDateTime ) )
Owen 🙂
Thank you Owen, that worked well. I perferred the DAX solution over M as I actaully understand what you did. (work for a smaller company so I am not a full time data person) .
One other huddle I need to cross
If I have a transaction at 1/27/17 @ 00:10:00 AM AND the log in record am looking for is 1/26/17 22:40:00 (so they logged in the previous day) - is there another condition I can add to this to account for that ?
Thank You Again
Brett
I suspect you've modified @OwenAuger's formula to only look at your Time columns!
Note that he checks a Date/Time column.
So to address this create a Date-Time Column in both tables like this
Date-Time = [Date]&" "&[Time]
Both of these columns will default to Text - so you need to convert them to Data Type - Date/Time - again in both tables.
This should resolve it!
Good Luck!
Thank you , I noticed the merge I just didnt do 2 things 1) change my data type 2) open my device log fact tbale for mutiple days
The other thing this community will agree on @OwenAuger's solutions definitely do not fall in the "dime a dozen" category!
BTW Owen's sample file above includes Marcel's solution as well @MarcelBeug
@brett_waltonyou can create the Device table in Owen's solution in the Query Editor
Duplicate the table that has ALL Devices (right-click the table)
Rename It
Remove All Other Columns
Remove Duplicates (right-click the column)
Close and Apply
Good Luck!
Maybe DAX would be more appropriate, but in M (Edit Queries) it can be done with the following code.
I combined dates and times in each table to the field "DateTime".
Steps:
let Source = Table.NestedJoin(Transactions,{"Device"},Logins,{"Device"},"Logins",JoinKind.LeftOuter), AddedLoginsBeforeTransaction = Table.AddColumn(Source, "Logins before Transaction", (CT) => Table.SelectRows(CT[Logins], each [DateTime]<=CT[DateTime])), RemovedLogins = Table.RemoveColumns(AddedLoginsBeforeTransaction,{"Logins"}), LatestLogin = Table.TransformColumns(RemovedLogins, {{"Logins before Transaction", each Table.SelectRows(_, let latest = List.Max(_[DateTime]) in each _[DateTime] = latest)}}), NameFromLogin = Table.ExpandTableColumn(LatestLogin, "Logins before Transaction", {"Person"}, {"Person"}), Typed = Table.TransformColumnTypes(NameFromLogin,{{"Person", type text}}) in Typed
By the way, the second is SAM, not ROB.
Thank you .. Will give it a try but for point of clarity of what I am looking for the second one is Rob . The transaction was at 10:13 and he logged into the device at 10:00 so it was he who posted it not SAM .
Folks it seems @MarcelBeug maybe giving our undisputed M expert @ImkeF a run for her money!
Happy to hand-over 🙂
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
@ImkeFif we can poll this community one thing will be certain!
When it comes to DAX there are many so called "experts"
But when it comes to M everyone will vote for you!
So don't hand over anything yet!
When it comes to theoretical M knowledge, I think @ImkeF can more or less compete by now.
With regard to practical experience I'm definitely lagging behind.
But I have that screencasting software as a card in my sleeve.
And my userid is with a capital M...
@Sean Especially with Power Query I think that videos have enormous added value, as code is typically generated by clicking the right buttons on the menus.
A good example in https://community.powerbi.com/t5/Desktop/Parsing-Embedded-JSON/m-p/118765#M50133 in which the solution is basically simple and straightforward, but it requires a lot of clicks.
Even with a video it takes 3 minutes to explain.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
90 | |
77 | |
63 | |
47 | |
39 |
User | Count |
---|---|
118 | |
85 | |
80 | |
58 | |
40 |