Skip to content

Conversation

kevinoid
Copy link
Contributor

@kevinoid kevinoid commented Jan 1, 2022

At compatibility level 100 and below, the addition operator accepts an operand of type DATE, TIME, DATETIME2, or DATETIMEOFFSET if the other operand has type DATETIME or SMALLDATETIME. At compatibility level 110 and higher, an operand of type DATE, TIME, DATETIME2, or DATETIMEOFFSET causes an error. For example:

SELECT CAST('2021-12-31T00:00:00' AS DATETIME) + CAST('17:00:00' AS TIME);

At compatibilty level 100:

2021-12-31 17:00:00.000

At compatibility level 110:

Msg 402, Level 16, State 1, Line 1
The data types datetime and time are incompatible in the add operator.

I did not see this change described in the "Differences between Lower Compatibility Levels and Levels 100 and 110" in the ALTER DATABASE Compatibility Level (Transact-SQL) page. This PR adds it.

To confirm the behavior, you may find the following reproduction useful:

SQL script to test date/time addition behavior
CREATE DATABASE testdb;
ALTER DATABASE testdb
-- Change 100 to 110 to confirm behavior at that level.
SET COMPATIBILITY_LEVEL = 100;
GO
USE testdb;
DECLARE @DateTime2Value DATETIME2;
DECLARE @DateTimeOffsetValue DATETIMEOFFSET;
DECLARE @DateTimeValue DATETIME;
DECLARE @DateValue DATE;
DECLARE @SmallDateTimeValue SMALLDATETIME;
DECLARE @TimeValue TIME;
-- Works at all levels:
SELECT @DateTimeValue + @SmallDateTimeValue;
SELECT @DateTimeValue + @DateTimeValue;
SELECT @SmallDateTimeValue + @DateTimeValue;
SELECT @SmallDateTimeValue + @SmallDateTimeValue;
-- Causes 402 at 110, works at 100 and below:
SELECT @DateTime2Value + @DateTimeValue;
SELECT @DateTime2Value + @SmallDateTimeValue;
SELECT @DateTimeOffsetValue + @DateTimeValue;
SELECT @DateTimeOffsetValue + @SmallDateTimeValue;
SELECT @DateTimeValue + @DateTime2Value;
SELECT @DateTimeValue + @DateTimeOffsetValue;
SELECT @DateTimeValue + @DateValue;
SELECT @DateTimeValue + @TimeValue;
SELECT @DateValue + @DateTimeValue;
SELECT @DateValue + @SmallDateTimeValue;
SELECT @SmallDateTimeValue + @DateTime2Value;
SELECT @SmallDateTimeValue + @DateTimeOffsetValue;
SELECT @SmallDateTimeValue + @DateValue;
SELECT @SmallDateTimeValue + @TimeValue;
SELECT @TimeValue + @DateTimeValue;
SELECT @TimeValue + @SmallDateTimeValue;
-- Causes 8117 at all levels:
SELECT @DateTime2Value + @DateTime2Value;
SELECT @DateTime2Value + @DateTimeOffsetValue;
SELECT @DateTime2Value + @DateValue;
SELECT @DateTime2Value + @TimeValue;
SELECT @DateTimeOffsetValue + @DateTime2Value;
SELECT @DateTimeOffsetValue + @DateTimeOffsetValue;
SELECT @DateTimeOffsetValue + @DateValue;
SELECT @DateTimeOffsetValue + @TimeValue;
SELECT @DateValue + @DateTime2Value;
SELECT @DateValue + @DateTimeOffsetValue;
SELECT @DateValue + @DateValue;
SELECT @DateValue + @TimeValue;
SELECT @TimeValue + @DateTime2Value;
SELECT @TimeValue + @DateTimeOffsetValue;
SELECT @TimeValue + @DateValue;
SELECT @TimeValue + @TimeValue;
GO
USE [master];
DROP DATABASE testdb;

Thanks for considering,
Kevin

At compatibility level 100 and below, the addition operator accepts an operand
of type `DATE`, `TIME`, `DATETIME2`, or `DATETIMEOFFSET` if the other operand
has type `DATETIME` or `SMALLDATETIME`.  At compatibility level 110 and
higher, an operand of type `DATE`, `TIME`, `DATETIME2`, or `DATETIMEOFFSET`
causes an error.  For example:

```sql
SELECT CAST('2021-12-31T00:00:00' AS DATETIME) + CAST('17:00:00' AS TIME);
```

At compatibilty level 100:

> 2021-12-31 17:00:00.000

At compatibility level 110:

> Msg 402, Level 16, State 1, Line 1
> The data types datetime and time are incompatible in the add operator.

Add this to the "Differences between Lower Compatibility Levels and Levels 100
and 110" in the [ALTER DATABASE Compatibility Level (Transact-SQL)] page.

[ALTER DATABASE Compatibility Level (Transact-SQL)]: https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-database-transact-sql-compatibility-level

Signed-off-by: Kevin Locke <kevin@kevinlocke.name>
@PRMerger10
Copy link
Contributor

@kevinoid : Thanks for your contribution! The author(s) have been notified to review your proposed change.

@ktoliver
Copy link
Contributor

ktoliver commented Jan 2, 2022

#label:"aq-pr-triaged"

@PRMerger8 PRMerger8 added the aq-pr-triaged tracking label for the PR review team label Jan 2, 2022
@WilliamDAssafMSFT
Copy link
Contributor

First off @kevinoid, congrats on submitting your first PR to the sql-docs repo! Thanks for taking the time to research and propose this edit. This change looks good and I've tested using your scripts. Your commit will be merged and this article update is in flight. After the updated article is published, GitHub will list you as an article contributor.

Thanks again for this feedback, your suggestions help improve our documentation.

#sign-off

@ktoliver ktoliver merged commit fdeb288 into MicrosoftDocs:live Jan 5, 2022
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

7 participants