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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
Anonymous
Not applicable

Calculate formula dependent on multiple rows in a table

I've next data:

VoucherID | TimeTypeID | Value 
--------- | ---------- | -----
1 | Arrival | 10:00
1 | Departure | 15:00
1 | Break | 01:00
1 | Travel | 00:30
2 | Arrival | 09:00
2 | Departure | 22:00
2 | Break | 01:00
2 | Travel | 00:45
3 | Arrival | 10:30

Now I'll to calculate the time between the arrival and the departure substracting with the break only when the 3 times are known. The travel can be ignored at the formula. Something like this formula:

Departure - Arrival - Break

I'll get this data:

  • Voucher 1: 04:00
  • Voucher 2: 12:00
  • Voucher 3: null ('cause departure and break are not known)

How could I do that? I know that I must create a measure but I don't know how I could write the code for that.

With the result of that, I'll get a minimal, maximal and average value.

2 ACCEPTED SOLUTIONS
Mariusz
Community Champion
Community Champion

Hi @Anonymous 

You can Pivot the data in Query Editor and do the calculation easily like below.
However if for some reason you prefer Measure that can be arranged as well.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIsKsosS8wBsgwNrAwMlGJ1IOIuqQWJRSWlRakgGVNkGaei1MRsIG1giCwaUpRYlgoyxsDAyhgibIRivIElTLkRmvFGRsgymMYboRlvYgoWNkZ3PcjaWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [VoucherID = _t, TimeTypeID = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", type time}, {"VoucherID", Int64.Type}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[TimeTypeID]), "TimeTypeID", "Value", List.Average),
    #"Added Custom" = Table.AddColumn(#"Pivoted Column", "Custom", each Time.From(Number.From([Departure]) - Number.From([Arrival]) - Number.From([Break])), type time)
in
    #"Added Custom"

Regards,
Mariusz

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

Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

DAX Measure below.

 

Measure = 
VAR Departure = CALCULATE(
    SUM(Table1[Value]),
    ALLEXCEPT(Table1, Table1[VoucherID]),
    Table1[TimeTypeID] = "Departure"
)
VAR Arrival = CALCULATE(
    SUM(Table1[Value]),
    ALLEXCEPT(Table1, Table1[VoucherID]),
    Table1[TimeTypeID] = "Arrival"
)
VAR Break = CALCULATE(
    SUM(Table1[Value]),
    ALLEXCEPT(Table1, Table1[VoucherID]),
    Table1[TimeTypeID] = "Break"
)
RETURN IF( Departure > 0 && Break > 0, Departure - Arrival - Break)

 

Regards,
Mariusz

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

3 REPLIES 3
Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

DAX Measure below.

 

Measure = 
VAR Departure = CALCULATE(
    SUM(Table1[Value]),
    ALLEXCEPT(Table1, Table1[VoucherID]),
    Table1[TimeTypeID] = "Departure"
)
VAR Arrival = CALCULATE(
    SUM(Table1[Value]),
    ALLEXCEPT(Table1, Table1[VoucherID]),
    Table1[TimeTypeID] = "Arrival"
)
VAR Break = CALCULATE(
    SUM(Table1[Value]),
    ALLEXCEPT(Table1, Table1[VoucherID]),
    Table1[TimeTypeID] = "Break"
)
RETURN IF( Departure > 0 && Break > 0, Departure - Arrival - Break)

 

Regards,
Mariusz

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

Anonymous
Not applicable

@Mariusz: It's looks good but I only det the average, but it's not a problem to get a minimum and maximum.

Mariusz
Community Champion
Community Champion

Hi @Anonymous 

You can Pivot the data in Query Editor and do the calculation easily like below.
However if for some reason you prefer Measure that can be arranged as well.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIsKsosS8wBsgwNrAwMlGJ1IOIuqQWJRSWlRakgGVNkGaei1MRsIG1giCwaUpRYlgoyxsDAyhgibIRivIElTLkRmvFGRsgymMYboRlvYgoWNkZ3PcjaWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [VoucherID = _t, TimeTypeID = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", type time}, {"VoucherID", Int64.Type}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[TimeTypeID]), "TimeTypeID", "Value", List.Average),
    #"Added Custom" = Table.AddColumn(#"Pivoted Column", "Custom", each Time.From(Number.From([Departure]) - Number.From([Arrival]) - Number.From([Break])), type time)
in
    #"Added Custom"

Regards,
Mariusz

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

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.