Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add AtTimeZoneExpression and some relevant translations #26972

Merged
merged 1 commit into from
May 24, 2022

Conversation

roji
Copy link
Member

@roji roji commented Dec 12, 2021

  • Adds AtTimeZoneExpression support to relational, along with support in QuerySqlGenerator, SqlNullabilityProcessor.
  • Adds SQL Server-specific EF.Functions.AtTimeZone for datetimeoffset -> datetimeoffset and for datetime/datetime2 -> datetimeoffset

Closes #26199
Closes #26971

@smitpatel
Copy link
Contributor

Build failing.

TimeZoneInfo.ConvertTimeBySystemTimeZoneId

Does string timezone identifier C# always matches the Server side strings? If not, we should add translation for this. EF.Functions one is fine since it corresponds to server always.

@roji
Copy link
Member Author

roji commented Dec 14, 2021

Does string timezone identifier C# always matches the Server side strings? If not, we should add translation for this. EF.Functions one is fine since it corresponds to server always.

Here's what the docs say:

This method retrieves information on the time zone whose identifier is specified by the destinationTimeZoneId parameter from the registry on Windows systems and from the ICU Library on Linux and macOS.

So the interpretation of that string on .NET is platform-dependent, based on whether on Windows or Linux - so even in pure .NET this parameter isn't cross-platform (i.e. no fixed meaning). I think the method corresponds well for this translation (I've also done this for PG), but I can change to EF.Functions if you think that's better.

@bricelam
Copy link
Contributor

bricelam commented Jan 12, 2022

🤔 I wonder if we should translate when the string is localtime or utc on SQLite. Probably a bit of a stretch...

.NET SQL
EF.Functions.AtTimeZone(date, "localtime") datetime($date, 'localtime')
EF.Functions.AtTimeZone(date, "utc") datetime($date, 'utc')

@roji
Copy link
Member Author

roji commented Jan 12, 2022

Don't forget there's DateTime.ToUniversalTime and ToLocalTime, should we just translate those? That seems like a pretty good fit if SQLite does the right thing...

Otherwise if we have to do it on EF.Functions, I'd go with two different functions rather than a string parameter (e.g. AtUtc, AtLocalTime)

@roji
Copy link
Member Author

roji commented Jan 12, 2022

@smitpatel updated PR ready for review

@stevendarby
Copy link
Contributor

Does this function work when the time zone is a column, and if so is it worth adding a test for that? I read a good blog on storing time zones in the database... 😃

@sommmen
Copy link

sommmen commented Apr 14, 2022

Any reason this is still not merged in or?

_sqlExpressionFactory.ApplyDefaultTypeMapping(operand),
_sqlExpressionFactory.ApplyDefaultTypeMapping(timeZone),
typeof(DateTimeOffset),
_typeMappingSource.FindMapping(typeof(DateTimeOffset)));
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Should we assign typemapping here or should it be inferred from outside (if this is top level we assign default anyway).
Hypothetical scenario
a + (b + c) where c is our above translation and a is column with type mapping. If we assign type mapping here then b will take default from here rather than b/c taking type mapping from a which could be more appropriate.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I remember thinking about this... The thing is, the AT TIME ZONE construct is documented very clearly to return a SQL Server datetimeoffset, so I'm leaning towards encoding that in the translation rather than allowing inference.

Here's an opposite scenario: .Where(b => EF.Functions.AtTimeZone(b.ColumnWithTypeMapping, "UTC") == someParameter. In this case someParameter has no type mapping, but I think we'd want it to be inferred to datetimeoffset based on the result of AtTimeZone on the other side...

But am fine either way if you want to leave unassigned and allow inference - let me know. I guess it's a general question when translating to functions which have a single, documented return type...

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The scenario you mentioned is comparison so if neither side has type mapping then it will get default one for the type. expression.Type is DateTimeOffset and default of that we need to assign then inference would work fine for that.
Isn't datetimeoffset time on SqlServer has different precision or is it datetime thing only?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Good questions.

Yeah, datetimeoffset does support precision and scale (docs); and it bubbles up those facets from the operand (for both datetime2 and datetimeoffset operands).

So if I'm getting things right, that means that if the operand has a type mapping (column), we should bubble it up (and for datetime/datetime2 mapping, bubble up the facets and return the appropriate datetimeoffset mapping. But if the operand has no mapping, we shouldn't set a result mapping to allow it to be inferred from the outside.

Does that sound good? If so I'll implement that.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

For reference, here's the T-SQL with the investigation:

-- Default precision/scale for datetimeoffset is 34, 7
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset), 'BaseType'); -- datetimeoffset
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset), 'Precision'); -- 34
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset), 'Scale'); -- 7

-- datetimeoffset with non-default precision/scale
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset(2)), 'BaseType'); -- datetimeoffset
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset(2)), 'Precision'); -- 29
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset(2)), 'Scale'); -- 2

-- AT TIME ZONE with datetimeoffset operand - bubbles up precision/scale
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset(2)) AT TIME ZONE 'UTC', 'Precision'); -- 29
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00+02:00' AS datetimeoffset(2)) AT TIME ZONE 'UTC', 'Scale'); -- 2

-- AT TIME ZONE with datetimeoffset operand - bubbles up precision/scale
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00' AS datetime2(2)) AT TIME ZONE 'UTC', 'Precision'); -- 29
SELECT SQL_VARIANT_PROPERTY(CAST('2020-01-01T12:00:00' AS datetime2(2)) AT TIME ZONE 'UTC', 'Scale'); -- 2

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Bubbling up as-is type mapping and inferring from outside sounds good. Bubbling precision/scale up is a good thing though we don't do it anywhere else at present so I will let you decide if you want to do it or not. If it is too complex, we can choose to not do it. datetimeoffset(2) will fit in just fine with datetimeoffset(7) type so there is no data loss or truncation.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

OK, I went ahead and implemented bubbling of precision - in both directions. This means that for x.SomeColumn == EF.Functions.AtTimeZone(someParam, "UTC"), someParam will get SomeColumn's precision, just as if it's compared directly without AtTimeZone. This stuff may be important - I'm not sure how SQL Server behaves when comparing datetimeoffsets with different precisions...

Note that there's now a SqlServerSqlExpressionFactory to have the specific bubbling logic. This is a bit more complicated than I originally thought, let me know what you think and if we should simplify.

Copy link
Contributor

@smitpatel smitpatel left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Minor comments

@roji roji requested a review from smitpatel May 24, 2022 08:46
@ghost
Copy link

ghost commented May 24, 2022

Hello @roji!

Because this pull request has the auto-merge label, I will be glad to assist with helping to merge this pull request once all check-in policies pass.

p.s. you can customize the way I help with merging this pull request, such as holding this pull request until a specific person approves. Simply @mention me (@msftbot) and give me an instruction to get started! Learn more here.

@smitpatel
Copy link
Contributor

Did you remove SqlServerSqlExpressionFactory?

@roji
Copy link
Member Author

roji commented May 24, 2022

Nope, just botched the squashing...

@roji roji merged commit 176f301 into dotnet:main May 24, 2022
@roji roji deleted the AtTimeZone branch May 24, 2022 22:45
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

SQL Server basic translations for AT TIME ZONE Add support for AT TIME ZONE
5 participants