Weird date rounding

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • Edward

    Weird date rounding

    SQL Server 7.0

    The following SQL:

    SELECT TOP 100 PERCENT fldTSRID, fldDateEntered
    FROM tblTSRs WITH (NOLOCK)
    WHERE ((fldDateEntere d >= CONVERT(DATETIM E, '2003-11-21 00:00:00',
    102))
    AND
    (fldDateEntered <= CONVERT(DATETIM E, '2003-11-23 23:59:59', 102)))

    returns this record:

    fldTSRID: 4
    fldDateEntered: 24/11/2003

    Hello? How is 24/11/2003 <= '2003-11-23 23:59:59'?

    I tried decrementing the second predicate by seconds:

    (fldDateEntered <= CONVERT(DATETIM E, '2003-11-23 23:59:30', 102)))

    returns the record, but

    (fldDateEntered <= CONVERT(DATETIM E, '2003-11-23 23:59:29', 102)))

    does NOT.

    What is happening here?

    Edward

    =============== =============

    TABLE DEFINITION:

    if exists (select * from dbo.sysobjects where id =
    object_id(N'[dbo].[FK_tblTSRNotes_ tblTSRs]') and OBJECTPROPERTY( id,
    N'IsForeignKey' ) = 1)
    ALTER TABLE [dbo].[tblTSRNotes] DROP CONSTRAINT FK_tblTSRNotes_ tblTSRs
    GO

    if exists (select * from dbo.sysobjects where id =
    object_id(N'[dbo].[tblTSRs]') and OBJECTPROPERTY( id, N'IsUserTable') =
    1)
    drop table [dbo].[tblTSRs]
    GO

    CREATE TABLE [dbo].[tblTSRs] (
    [fldTSRID] [int] IDENTITY (1, 1) NOT NULL ,
    [fldDealerID] [int] NOT NULL ,
    [fldWorkshopGrou pID] [int] NULL ,
    [fldSubjectID] [int] NULL ,
    [fldReasonID] [int] NULL ,
    [fldFaultID] [int] NULL ,
    [fldContactID] [int] NULL ,
    [fldMileage] [int] NULL ,
    [fldFirstFailure] [smalldatetime] NULL ,
    [fldNumberOfFail ures] [int] NULL ,
    [fldTSRPriorityI D] [int] NULL ,
    [fldTSRStatusID] [int] NULL ,
    [fldAttachedFile Path] [char] (255) NULL ,
    [fldFileAttached] [smallint] NOT NULL ,
    [fldFaultDescrip tion] [ntext] NULL ,
    [fldFaultRectifi cation] [ntext] NULL ,
    [fldEmergency] [int] NOT NULL ,
    [fldDateEntered] [smalldatetime] NOT NULL ,
    [fldEnteredBy] [int] NOT NULL
    ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
    GO
  • David Portas

    #2
    Re: Weird date rounding

    DATETIME is only precise to 3 milliseconds, so '2003-11-23 23:59:59' rounds
    to '2003-11-24 00:00:00'. Use < instead of <= with dates to avoid this sort
    of problem:

    SELECT fldtsrid, flddateentered
    FROM tblTSRs
    WHERE fldDateEntered >= '20031121'
    AND fldDateEntered < '20031124'

    Stick to the ISO year-month-day formats and you don't need the extra CONVERT
    function in the query.

    --
    David Portas
    ------------
    Please reply only to the newsgroup
    --


    Comment

    • David Portas

      #3
      Re: Weird date rounding

      Correction: Although my solution should be work, my explanation wasn't
      accurate. It's true that the precision of DATETIME is limited to 3
      milliseconds but that doesn't appear to be the root of your problem since
      you haven't used milliseconds.

      The precision of SMALLDATETIME is 1 minute but the value of '23:59:59' in
      your query shouldn't get rounded up to the following midnight. Instead the
      SMALLDATETIME value from your table should be implicitly cast to DATETIME
      with no loss of precision. Your query is therefore sub-optimal since the
      implicit conversion will be performed for every row. However, the query
      should not produce the result you described.

      I can't actually reproduce your problem. Try the query I posted previously.
      If that doesn't help, please post some code to reproduce the problem,
      including INSERT statement(s) with sample data.

      --
      David Portas
      ------------
      Please reply only to the newsgroup
      --


      Comment

      • Simon Hayes

        #4
        Re: Weird date rounding

        teddysnips@hotm ail.com (Edward) wrote in message news:<25080b60. 0311250354.4fff 947b@posting.go ogle.com>...[color=blue]
        > SQL Server 7.0
        >
        > The following SQL:
        >
        > SELECT TOP 100 PERCENT fldTSRID, fldDateEntered
        > FROM tblTSRs WITH (NOLOCK)
        > WHERE ((fldDateEntere d >= CONVERT(DATETIM E, '2003-11-21 00:00:00',
        > 102))
        > AND
        > (fldDateEntered <= CONVERT(DATETIM E, '2003-11-23 23:59:59', 102)))
        >
        > returns this record:
        >
        > fldTSRID: 4
        > fldDateEntered: 24/11/2003
        >
        > Hello? How is 24/11/2003 <= '2003-11-23 23:59:59'?
        >
        > I tried decrementing the second predicate by seconds:
        >
        > (fldDateEntered <= CONVERT(DATETIM E, '2003-11-23 23:59:30', 102)))
        >
        > returns the record, but
        >
        > (fldDateEntered <= CONVERT(DATETIM E, '2003-11-23 23:59:29', 102)))
        >
        > does NOT.
        >
        > What is happening here?
        >
        > Edward
        >
        > =============== =============
        >
        > TABLE DEFINITION:
        >
        > if exists (select * from dbo.sysobjects where id =
        > object_id(N'[dbo].[FK_tblTSRNotes_ tblTSRs]') and OBJECTPROPERTY( id,
        > N'IsForeignKey' ) = 1)
        > ALTER TABLE [dbo].[tblTSRNotes] DROP CONSTRAINT FK_tblTSRNotes_ tblTSRs
        > GO
        >
        > if exists (select * from dbo.sysobjects where id =
        > object_id(N'[dbo].[tblTSRs]') and OBJECTPROPERTY( id, N'IsUserTable') =
        > 1)
        > drop table [dbo].[tblTSRs]
        > GO
        >
        > CREATE TABLE [dbo].[tblTSRs] (
        > [fldTSRID] [int] IDENTITY (1, 1) NOT NULL ,
        > [fldDealerID] [int] NOT NULL ,
        > [fldWorkshopGrou pID] [int] NULL ,
        > [fldSubjectID] [int] NULL ,
        > [fldReasonID] [int] NULL ,
        > [fldFaultID] [int] NULL ,
        > [fldContactID] [int] NULL ,
        > [fldMileage] [int] NULL ,
        > [fldFirstFailure] [smalldatetime] NULL ,
        > [fldNumberOfFail ures] [int] NULL ,
        > [fldTSRPriorityI D] [int] NULL ,
        > [fldTSRStatusID] [int] NULL ,
        > [fldAttachedFile Path] [char] (255) NULL ,
        > [fldFileAttached] [smallint] NOT NULL ,
        > [fldFaultDescrip tion] [ntext] NULL ,
        > [fldFaultRectifi cation] [ntext] NULL ,
        > [fldEmergency] [int] NOT NULL ,
        > [fldDateEntered] [smalldatetime] NOT NULL ,
        > [fldEnteredBy] [int] NOT NULL
        > ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
        > GO[/color]

        The smalldatetime data type is accurate to one minute - according to
        BOL, a smalldatetime value is rounded down if the seconds are 29 or
        less, or up or 30 or more seconds.

        Although I don't have a SQL7 installation to test this, I seem to
        remember that for comparisons, the column type took precedence over
        the expression. So your datetime is converted to smalldatetime and
        then compared. In SQL 2000, the reverse would happen, because data
        type precedence is strictly defined, and datetime is higher than
        smalldatetime.

        Simon

        Comment

        • Erland Sommarskog

          #5
          Re: Weird date rounding

          David Portas (REMOVE_BEFORE_ REPLYING_dporta s@acm.org) writes:[color=blue]
          > Correction: Although my solution should be work, my explanation wasn't
          > accurate. It's true that the precision of DATETIME is limited to 3
          > milliseconds but that doesn't appear to be the root of your problem since
          > you haven't used milliseconds.
          >
          > The precision of SMALLDATETIME is 1 minute but the value of '23:59:59' in
          > your query shouldn't get rounded up to the following midnight. Instead the
          > SMALLDATETIME value from your table should be implicitly cast to DATETIME
          > with no loss of precision. Your query is therefore sub-optimal since the
          > implicit conversion will be performed for every row. However, the query
          > should not produce the result you described.[/color]

          But the rules for implicit conversion were changed from SQL7 to SQL2000,
          and Edward runs SQL7.

          I am not going to try to explain the conversion rules for SQL7, as this
          was the version that I more or less skipped. However, testing I find
          that:

          create table #temp (a smalldatetime)
          insert #temp values ('20031123')
          insert #temp values ('20031124')
          go
          select * from #temp where a <=
          CONVERT(DATETIM E, '2003-11-23 23:59:59', 102)

          return two rows on SQL7 on SQL 6.5 and one row on SQL2000.

          David's suggestion to use:

          SELECT fldtsrid, flddateentered
          FROM tblTSRs
          WHERE fldDateEntered >= '20031121'
          AND fldDateEntered < '20031124'


          is of course the bulletproof way of running the query.

          --
          Erland Sommarskog, SQL Server MVP, sommar@algonet. se

          Books Online for SQL Server SP3 at
          Accelerate your AI application's time to market by harnessing the power of your own data and the built-in AI capabilities of SQL Server 2025, the enterprise database with best-in-class security, performance and availability.

          Comment

          • David Portas

            #6
            Re: Weird date rounding

            > But the rules for implicit conversion were changed from SQL7 to SQL2000,[color=blue]
            > and Edward runs SQL7.[/color]

            Ah, the light dawns! Sorry, I missed that vital piece of info from Edward's
            post.

            --
            David Portas
            ------------
            Please reply only to the newsgroup
            --


            Comment

            • louis nguyen

              #7
              Re: Weird date rounding

              Hi All,

              Why the "102"? I thought that was only needed to return the date in a
              character format/style. Just curious.

              CONVERT(DATETIM E, '2003-11-23 23:59:59', 102)

              Comment

              • Erland Sommarskog

                #8
                Re: Weird date rounding

                louis nguyen (louisducnguyen @hotmail.com) writes:[color=blue]
                > Why the "102"? I thought that was only needed to return the date in a
                > character format/style. Just curious.
                >
                > CONVERT(DATETIM E, '2003-11-23 23:59:59', 102)[/color]

                The 102 forces interpretation of the datetime literal according to that
                format.

                Using YYYYMMDD HH:MM:SS is easier - then you don't need to force any
                format, and you can skip the convert.



                --
                Erland Sommarskog, SQL Server MVP, sommar@algonet. se

                Books Online for SQL Server SP3 at
                Accelerate your AI application's time to market by harnessing the power of your own data and the built-in AI capabilities of SQL Server 2025, the enterprise database with best-in-class security, performance and availability.

                Comment

                • Edward

                  #9
                  Re: Weird date rounding

                  teddysnips@hotm ail.com (Edward) wrote in message news:<25080b60. 0311250354.4fff 947b@posting.go ogle.com>...

                  <Snippage>

                  Thanks to you all for your great help, as usual.

                  Edward
                  --
                  The reading group's reading group:

                  Comment

                  Working...