Calculating Time Query

Collapse
X
 
  • Time
  • Show
Clear All
new posts
  • Blaize
    New Member
    • Nov 2007
    • 13

    Calculating Time Query

    Hi,

    I'm having an issue trying to calculate time. Its okay if the value does not exceed 24 hours otherwise I get a date and hours listed. For example, I have a loop which looks through a table and adds up the time spent.

    Code:
    Dim TempCount As Date
        Dim DEVCount As Date
    
    Do
        
            TempCount = rst!wtime
            DEVCount = DEVCount + TempCount
            rst.MoveNext
            i = i + "1"
        
        Loop Until rst!Anorder = 2
    I have two other loops looping at AnOrder 2 and 3 and calculating their totals. They seems to be okay as their total are 9h:25m and 17h:35m. But DEVCount value for anOrder 1 is: 2/1/1900 22:24:00. I guess because its exceeding a 24hour period its adding days? Is there any way of getting a figure like 37h:44m or 57h:24m??

    I know a way round it would be to set DEVCount as a date and time and calculate from there but it seems very long winded for what I think should be an easy task.

    Please help!!
    Last edited by Scott Price; Feb 28 '08, 02:17 PM. Reason: code tags
  • ADezii
    Recognized Expert Expert
    • Apr 2006
    • 8834

    #2
    Originally posted by Blaize
    Hi,

    I'm having an issue trying to calculate time. Its okay if the value does not exceed 24 hours otherwise I get a date and hours listed. For example, I have a loop which looks through a table and adds up the time spent.

    Dim TempCount As Date
    Dim DEVCount As Date

    Do

    TempCount = rst!wtime
    DEVCount = DEVCount + TempCount
    rst.MoveNext
    i = i + "1"

    Loop Until rst!Anorder = 2

    I have two other loops looping at AnOrder 2 and 3 and calculating their totals. They seems to be okay as their total are 9h:25m and 17h:35m. But DEVCount value for anOrder 1 is: 2/1/1900 22:24:00. I guess because its exceeding a 24hour period its adding days? Is there any way of getting a figure like 37h:44m or 57h:24m??

    I know a way round it would be to set DEVCount as a date and time and calculate from there but it seems very long winded for what I think should be an easy task.

    Please help!!
    If you convert the Time Values to minutes, it then becomes a simple matter. For instance, 1997 minutes would be:
    [CODE=vb]Debug.Print Str$(Int(1997 / 60)) & "h:" & Trim$(Str$(1997 Mod 60)) & "m"[/CODE]
    OUTPUT:
    [CODE=text] 33h:17m[/CODE]

    Comment

    • Blaize
      New Member
      • Nov 2007
      • 13

      #3
      I can't get that to work, the data is coming from a query which looks similar to below but more data!

      User anOrder Time
      A 1 00:15 (15 Minutes)
      B 1 15:45 (15 Hours 45 Minutes)
      C 1 13:30 (13 Hours 30 Minutes)
      D 2 05:00 (5 Hours)
      E 2 00:30 (30 Minutes)
      F 3 03:00 (3 Hours)

      These are the figures I'm trying to get Visual Basic to calculate.

      anOrder 1 = 29:30 (29 hours 30 Minutes)
      anOrder 2 = 05:30 (5 Hours 30 Minutes)
      anOrder 3 = 03:00 (3 Hours)


      anOrder 2 and anOrder 3 are fine (at the moment) because they don't exceed 24 hours but anOrder 3 does and I get a date. Is there anyway around this?

      Comment

      • Scott Price
        Recognized Expert Top Contributor
        • Jul 2007
        • 1384

        #4
        Just my personal opinion here, and I'm sure ADezii will come up with a much more spiffy solution :-)

        You need to stop treating these as Dates! You have declared your variables in the Date data type, which makes Access, understandably, think they are date values. What you really have, is a String that holds Time data, not a Date that holds Time data.

        You will find it much simpler to use some string manipulation functions to split the string down, then concatenate it back.

        Regards,
        Scott

        Comment

        • Blaize
          New Member
          • Nov 2007
          • 13

          #5
          I did think about that but I'm having issues converting, for example one line in the query is "00:15:00" (which is 15 minutes) to an integer value 0.25? If I could do that then I think I can crack it.

          Comment

          • Scott Price
            Recognized Expert Top Contributor
            • Jul 2007
            • 1384

            #6
            Why do you want to convert it to an Integer?

            Based on this string: "00:15:00", what output are you looking for? "15 minutes" "0 hours, 15 minutes, 0 seconds"??

            Is the time always in this format?

            A simple Select query can break the string down and rebuild it in this way:

            [CODE=sql]SELECT tblHOURMINSEC.T imeID, Left([HOURMINSEC],2) & " hours " & Mid([HOURMINSEC],4,2) & " minutes " & Right([HOURMINSEC],2) & " seconds." AS TIMEVAL
            FROM tblHOURMINSEC;
            [/CODE]

            This takes a value of 00:15:00 and returns an output of "00 hours 15 minutes 00 seconds". It takes 29:34:15 and returns "29 hours 34 minutes 15 seconds".

            Regards,
            Scott

            Comment

            • Scott Price
              Recognized Expert Top Contributor
              • Jul 2007
              • 1384

              #7
              With the addition of some IIF() functions:

              [CODE=sql]SELECT tblHOURMINSEC.T imeID, IIf(Left([HOURMINSEC],1)="0",Left([HOURMINSEC],1),Left([HOURMINSEC],2)) & " hours " & Mid([HOURMINSEC],4,2) & " minutes " & IIf(Right([HOURMINSEC],2)="00","0",Ri ght([HOURMINSEC],2)) & " seconds." AS TIMEVAL
              FROM tblHOURMINSEC;
              [/CODE]

              Returns "0 hours 15 minutes 0 seconds". You can tune this as your wish, but it's the general idea.

              Regards,
              Scott

              Comment

              • Blaize
                New Member
                • Nov 2007
                • 13

                #8
                Sorry maybe I'm not being clear, I'm trying to add multiple time figures together to get a total figure.

                00:15:00 + 01:15:00 = 01:30

                The data i have is split into three sections, Team 1, Team 2 & Team 3. I'm trying to get the total time figure for each Team. This isn't a problem at the moment for Team 2 and Team 3 as the total number only goes up to 11:00 and 07:15. Team 1 should be about 37:45.

                The reason why I need to convert it to an integeter is because once I have the total figure I need to divide it by daily hours. This works fine on a Access report I've developed but I now want to do the same thing in VB and export the result to Excel. The report formula is: =Format(Sum([Wtime])/CDate('7.24'),' Fixed')

                so another example would be total hours of 14:48 with the above formula would equal: 2.

                2 is the figure I'm after so I can populate a spreadsheet. Hope this makes more sense..

                Comment

                • Scott Price
                  Recognized Expert Top Contributor
                  • Jul 2007
                  • 1384

                  #9
                  That certainly does change the issue! I'll have to give a little more thought on this, and get back to you.

                  Regards,
                  Scott

                  Comment

                  • Scott Price
                    Recognized Expert Top Contributor
                    • Jul 2007
                    • 1384

                    #10
                    Sorry to be so long getting back to you, Blaize. Today has been a bit hectic.

                    Here is a quick and dirty function, place it in a standard code module and call it from within a query (or vba code if you like). It assumes an input string of "HH:MM" and returns a Single value corresponding to how many hours and minutes there are. For example, using the strings "00:15" and "29:61" it will return 0.25 and 30.01666 etc.

                    [CODE=vb]Option Compare Database
                    Option Explicit

                    Public Function ConvTime(timeIn As String) As Single

                    Dim hours As Integer
                    Dim minutes As Integer
                    Dim convertedTime As Single

                    hours = CInt(Left(timeI n, 2))
                    minutes = CInt(Mid(timeIn , 4, 2))


                    If hours <> 0 Then
                    convertedTime = hours * 60 + minutes
                    Else
                    convertedTime = minutes
                    End If

                    ConvTime = convertedTime / 60

                    End Function
                    [/CODE]

                    To call it from within a query: [CODE=sql]Expr1: ConvTime(Left([HOURMINSEC],5))[/CODE]

                    ADezii probably has a much more spiffy way to do this, as I said earlier :-) However, this is what I could come up with on the spur of the moment.

                    Regards,
                    Scott

                    Comment

                    • ADezii
                      Recognized Expert Expert
                      • Apr 2006
                      • 8834

                      #11
                      Originally posted by Blaize
                      Hi,

                      I'm having an issue trying to calculate time. Its okay if the value does not exceed 24 hours otherwise I get a date and hours listed. For example, I have a loop which looks through a table and adds up the time spent.

                      Code:
                      Dim TempCount As Date
                          Dim DEVCount As Date
                      
                      Do
                          
                              TempCount = rst!wtime
                              DEVCount = DEVCount + TempCount
                              rst.MoveNext
                              i = i + "1"
                          
                          Loop Until rst!Anorder = 2
                      I have two other loops looping at AnOrder 2 and 3 and calculating their totals. They seems to be okay as their total are 9h:25m and 17h:35m. But DEVCount value for anOrder 1 is: 2/1/1900 22:24:00. I guess because its exceeding a 24hour period its adding days? Is there any way of getting a figure like 37h:44m or 57h:24m??

                      I know a way round it would be to set DEVCount as a date and time and calculate from there but it seems very long winded for what I think should be an easy task.

                      Please help!!
                      Here's a solution, but first a couple of Assumptions:
                      1. Table Name: tblTimes.
                      2. [Time] Field is String with Required Property set to Yes.
                      3. Sample Table Data:
                        [CODE=text]
                        ID User Order Time
                        1 A 1 00:15
                        2 B 1 15:45
                        3 C 1 13.30
                        4 D 2 05:00
                        5 E 2 00:30
                        6 F 3 03:00
                        8 H 7 00:16[/CODE]
                      4. The following code will create a Recordset based on tblTimes, covert the [Time] Field Values to Minutes, keep a Running Total of the accumulated Minutes, assign the Aggregate Total to a Variable, Format the Aggregate Value in the manner in which you requested, and Print it to the Immediate Window:
                        [CODE=vb]Dim MyDB As DAO.Database, MyRS As DAO.Recordset
                        Dim intTotalMinutes As Long, intHours As Integer, intMinutes As Integer
                        Dim intRunningMinut es As Integer

                        Set MyDB = CurrentDb()
                        Set MyRS = MyDB.OpenRecord set("tblTimes", dbOpenForwardOn ly)

                        Do While Not MyRS.EOF
                        intHours = Val(Left$(MyRS![Time], 2))
                        intMinutes = Val(Right$(MyRS ![Time], 2))
                        intRunningMinut es = intRunningMinut es + ((intHours * 60) + intMinutes)
                        MyRS.MoveNext
                        Loop

                        intTotalMinutes = intRunningMinut es

                        Debug.Print str$(Int(intTot alMinutes / 60)) & "h:" & Trim$(str$(intT otalMinutes Mod 60)) & "m"

                        MyRS.Close
                        Set MyRS = Nothing[/CODE]
                      5. Based on the previously displayed data, the OUTPUT is:
                        [CODE=text]38h:16m[/CODE]
                      6. Let me know what you think.
                      7. To Filter the data, create a Query which returns only the desired Records, then create the Recordset based on that Query, and not tblTimes.

                      Comment

                      • Blaize
                        New Member
                        • Nov 2007
                        • 13

                        #12
                        Scott, ADezii, Thank you both so much it works a treat...your both life savers! here's my amended code...
                        [CODE=vb]
                        Dim MyDB As DAO.Database, MyQD As DAO.QueryDef, MyRS As DAO.Recordset
                        Dim intTotalMinutes As Long, intHours As Integer, intMinutes As Integer, intNewTotal As Double

                        Dim intRunningMinut es As Integer

                        Set MyDB = CurrentDb()
                        Set MyQD = MyDB.QueryDefs! qryDailyDevStat s_Output

                        MyQD.Parameters ![Pram1] = Now()

                        Set MyRS = MyQD.OpenRecord set

                        Do While Not MyRS.EOF
                        intHours = Val(Left$(MyRS![wtime], 2))
                        intMinutes = Val(Mid$(MyRS![wtime], 4, 2))
                        intRunningMinut es = intRunningMinut es + ((intHours * 60) + intMinutes)
                        MyRS.MoveNext
                        Loop

                        intTotalMinutes = intRunningMinut es

                        Debug.Print Str$(Int(intTot alMinutes / 60)) & "h:" & Trim$(Str$(intT otalMinutes Mod 60)) & "m"

                        intNewTotal = CDec((intTotalM inutes / 60))

                        intNewTotal = CDec((intNewTot al / 7.4))

                        MyRS.Close
                        Set MyRS = Nothing[/CODE]

                        Comment

                        • ADezii
                          Recognized Expert Expert
                          • Apr 2006
                          • 8834

                          #13
                          Originally posted by Blaize
                          Scott, ADezii, Thank you both so much it works a treat...your both life savers! here's my amended code...
                          [CODE=vb]
                          Dim MyDB As DAO.Database, MyQD As DAO.QueryDef, MyRS As DAO.Recordset
                          Dim intTotalMinutes As Long, intHours As Integer, intMinutes As Integer, intNewTotal As Double

                          Dim intRunningMinut es As Integer

                          Set MyDB = CurrentDb()
                          Set MyQD = MyDB.QueryDefs! qryDailyDevStat s_Output

                          MyQD.Parameters ![Pram1] = Now()

                          Set MyRS = MyQD.OpenRecord set

                          Do While Not MyRS.EOF
                          intHours = Val(Left$(MyRS![wtime], 2))
                          intMinutes = Val(Mid$(MyRS![wtime], 4, 2))
                          intRunningMinut es = intRunningMinut es + ((intHours * 60) + intMinutes)
                          MyRS.MoveNext
                          Loop

                          intTotalMinutes = intRunningMinut es

                          Debug.Print Str$(Int(intTot alMinutes / 60)) & "h:" & Trim$(Str$(intT otalMinutes Mod 60)) & "m"

                          intNewTotal = CDec((intTotalM inutes / 60))

                          intNewTotal = CDec((intNewTot al / 7.4))

                          MyRS.Close
                          Set MyRS = Nothing[/CODE]
                          Glad Scott and I got it working for you. Remember to keep three things in mind, or else the code will not function properly:
                          1. Your Time Field, [wtime], must be a String Data Type.
                          2. Your Time Field, [wtime], must be in the Format hh:mm.
                          3. Your Time Field, [wtime], cannot contain a Null Value, so either set the Required Property to Yes in the Table, or set a Criteria in the Query of Not Is Null, and base the Recordset on it.
                          4. Nice job of following through and arriving at a solution using two alternative approaches.
                          5. Thanks Scott!

                          Comment

                          • Blaize
                            New Member
                            • Nov 2007
                            • 13

                            #14
                            Have got one final issue though! Works fine at the moment in development as a MDB file. I've compliled and saved then created an MDE file for distribution and get the error: "The expression On Click you enetered as the event property setting produced the following error: The expression may not result in the name of a macro, the name of a user-defined fuction or [Event Procedure]. + There may have been an error evaluating the function, event, or macro"??

                            I've narrowed it down and it seems to fall over on this line:

                            MyQD.Parameters ![Pram1]=Now()

                            But i can see anything wrong with it? Like I say it would fine when you run it as an MDB file. I've changed it to a string as I thought it was an issue with the 'Now()' function

                            Any Idea's?

                            Comment

                            • Scott Price
                              Recognized Expert Top Contributor
                              • Jul 2007
                              • 1384

                              #15
                              ADezii is on vacation for a few days :-)

                              Now() is an intrinsic VBA function that returns an integer value of the current date and time. VBA shouldn't have any trouble evaluating it, but you never know :-)

                              Can you see a way to restructure the code to do away with that part? I'm a bit busy right now, and don't have the time to test it through myself, but I'd say you might need to restructure that part of the code. I'll try to snatch a minute later on today to take a closer look at it.

                              Regards,
                              Scott

                              what version of Access are you using? Can't remember if you've said yet...

                              Comment

                              Working...