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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
moltra
Helper IV
Helper IV

Calculate downtime and uptime from a system log.

I am trying to calculate downtime and uptime from a system log that i am pulling from SQL Server.

The information is like below.  you can see how the device offline or online is in the description.  Below that I have shown how the calculations should be.  

 

 ABCDE
1TimestampPrioritySourceTargetDescription
29/22/2020 11:57ERRORGroup1device1Device offline
39/22/2020 12:07INFORMATIONGroup1device1Device online
49/26/2020 18:12ERRORGroup1device1Device offline
59/26/2020 18:22INFORMATIONGroup1device1Device online
611/28/2020 21:31ERRORGroup1device1Device offline
711/28/2020 21:41INFORMATIONGroup1device1Device online
812/2/2020 4:02ERRORGroup1device2Device offline
912/2/2020 4:12INFORMATIONGroup1device2Device online
10     
11 A3-A2=0:10:10(hh:mm:ss)Downtime
12 A4-43=102:04:49(hh:mm:ss)Uptime
13 A5-A4=0:10:15(hh:mm:ss)Downtime
14 A6-A5=1515:08:45(hh:mm:ss)Uptime
15 A7-A6=0:10:18(hh:mm:ss)Downtime
16 A8-A7=78:20:42(hh:mm:ss)Uptime
17 A9-A8=0:10:03(hh:mm:ss)Downtime

 

Any help or guidance is greatly appreciated.

1 ACCEPTED SOLUTION
Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @moltra please try the following in Power Query to see if this is what you are trying to achieve:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WstQ3MtI3MjAyUDA0tDI1V9JRcg0K8g8C0u5F+aUFhkBGSmpZZnIqiOUCZinkp6XlZOalKsXqoOg3sjIA6ff0c/MP8nUM8fT3w29KHrIhZlBDLKwMjchxBEK/kRF5jjA01DeygJhiZGhlbEiyK1ANMDEk0xnA4IQYYmJlgCcojHA4Akm7IcGQMMJ0QiwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Timestamp = _t, Priority = _t, Source = _t, Target = _t, Description = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Timestamp", type text}, {"Priority", type text}, {"Source", type text}, {"Target", type text}, {"Description", type text}}),
    #"Parsed Date Time" = Table.TransformColumns(#"Changed Type",{{"Timestamp", each DateTime.From(_, "en-Us"), type datetime}}),
    #"Added Index" = Table.AddIndexColumn(#"Parsed Date Time", "Table Row Index", 0, 1, Int64.Type),
    #"Added Index Offset" = Table.AddIndexColumn(#"Added Index", "Offset Row Index", 1, 1, Int64.Type),
    #"Merged Queries" = Table.NestedJoin(#"Added Index Offset", {"Offset Row Index"}, #"Added Index Offset", {"Table Row Index"}, "Added Index1", JoinKind.Inner),
    #"Expand Columns" = Table.ExpandTableColumn(#"Merged Queries", "Added Index1", {"Timestamp"}, {"End Timestamp"}),
    #"Sorted Rows" = Table.Sort(#"Expand Columns",{{"Table Row Index", Order.Ascending}}),
    #"Add Type" = Table.AddColumn(#"Sorted Rows", "Type", each if [Priority] = "ERROR" then "Downtime" else "Uptime", type text),
    #"Add Duration" = Table.AddColumn(#"Add Type", "Duration Day:Hours:Minutes:Seconds", each [End Timestamp] - [Timestamp] , type time)
in
    #"Add Duration"

 

View solution in original post

2 REPLIES 2
v-eqin-msft
Community Support
Community Support

Hi @moltra ,

 

Please try:

 

Duration = 
var _next= CALCULATE(MIN('Table'[Timestamp]),FILTER('Table',[Timestamp]>EARLIER('Table'[Timestamp])))
var _seconds= DATEDIFF([Timestamp],_next,SECOND)
var _hour=INT(_seconds/3600)
var _minutes= TRUNC((_seconds-_hour*3600)/ 60)
var _sec=MOD(_seconds,60)
return IF(_seconds<>BLANK(), _hour&":"&IF(_minutes<10,"0"&_minutes,_minutes) &":"&IF(_sec<10,"0"&_sec,_sec))
Type = SWITCH([Priority],"ERROR","Downtime","INFORMATION","Uptime")

Output:

 

Eyelyn9_0-1649147018941.png

 

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

Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @moltra please try the following in Power Query to see if this is what you are trying to achieve:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WstQ3MtI3MjAyUDA0tDI1V9JRcg0K8g8C0u5F+aUFhkBGSmpZZnIqiOUCZinkp6XlZOalKsXqoOg3sjIA6ff0c/MP8nUM8fT3w29KHrIhZlBDLKwMjchxBEK/kRF5jjA01DeygJhiZGhlbEiyK1ANMDEk0xnA4IQYYmJlgCcojHA4Akm7IcGQMMJ0QiwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Timestamp = _t, Priority = _t, Source = _t, Target = _t, Description = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Timestamp", type text}, {"Priority", type text}, {"Source", type text}, {"Target", type text}, {"Description", type text}}),
    #"Parsed Date Time" = Table.TransformColumns(#"Changed Type",{{"Timestamp", each DateTime.From(_, "en-Us"), type datetime}}),
    #"Added Index" = Table.AddIndexColumn(#"Parsed Date Time", "Table Row Index", 0, 1, Int64.Type),
    #"Added Index Offset" = Table.AddIndexColumn(#"Added Index", "Offset Row Index", 1, 1, Int64.Type),
    #"Merged Queries" = Table.NestedJoin(#"Added Index Offset", {"Offset Row Index"}, #"Added Index Offset", {"Table Row Index"}, "Added Index1", JoinKind.Inner),
    #"Expand Columns" = Table.ExpandTableColumn(#"Merged Queries", "Added Index1", {"Timestamp"}, {"End Timestamp"}),
    #"Sorted Rows" = Table.Sort(#"Expand Columns",{{"Table Row Index", Order.Ascending}}),
    #"Add Type" = Table.AddColumn(#"Sorted Rows", "Type", each if [Priority] = "ERROR" then "Downtime" else "Uptime", type text),
    #"Add Duration" = Table.AddColumn(#"Add Type", "Duration Day:Hours:Minutes:Seconds", each [End Timestamp] - [Timestamp] , type time)
in
    #"Add Duration"

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors