├── .gitattributes ├── .gitignore ├── Contributing.md ├── Database ├── Database.sqlproj ├── Functions │ ├── ConvertZone.sql │ ├── GetZoneAbbreviation.sql │ ├── GetZoneId.sql │ ├── GetZoneId_Inline.sql │ ├── LocalToUtc.sql │ ├── SwitchZone.sql │ └── UtcToLocal.sql ├── Procedures │ ├── AddLink.sql │ ├── AddZone.sql │ ├── SetIntervals.sql │ └── SetVersion.sql ├── Schema.sql ├── Tables │ ├── Intervals.sql │ ├── Links.sql │ ├── VersionInfo.sql │ └── Zones.sql └── Types │ └── IntervalTable.sql ├── LICENSE ├── NodaTime.CurrentTzdbProvider ├── AsyncLazy.cs ├── CachedAsyncLazy.cs ├── CurrentTzdbProvider.cs ├── NodaTime.CurrentTzdbProvider.csproj ├── Properties │ └── AssemblyInfo.cs └── packages.config ├── README.md ├── SqlTimeZone.sln └── SqlTzLoader ├── AsyncPump.cs ├── Options.cs ├── Program.cs ├── Properties └── AssemblyInfo.cs ├── SqlTzLoader.csproj └── packages.config /.gitattributes: -------------------------------------------------------------------------------- 1 | # Auto detect text files and perform LF normalization 2 | * text=auto 3 | 4 | # Custom for Visual Studio 5 | *.cs diff=csharp 6 | *.sln merge=union 7 | *.csproj merge=union 8 | *.vbproj merge=union 9 | *.fsproj merge=union 10 | *.dbproj merge=union 11 | 12 | # Standard to msysgit 13 | *.doc diff=astextplain 14 | *.DOC diff=astextplain 15 | *.docx diff=astextplain 16 | *.DOCX diff=astextplain 17 | *.dot diff=astextplain 18 | *.DOT diff=astextplain 19 | *.pdf diff=astextplain 20 | *.PDF diff=astextplain 21 | *.rtf diff=astextplain 22 | *.RTF diff=astextplain 23 | 24 | #Visual Basic 6 25 | *.vbg text eol=crlf 26 | *.vbp text eol=crlf 27 | *.cls text eol=crlf 28 | *.bas text eol=crlf -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Build Folders (you can keep bin if you'd like, to store dlls and pdbs) 2 | [Bb]in/ 3 | [Oo]bj/ 4 | 5 | # mstest test results 6 | TestResults 7 | 8 | ## Ignore Visual Studio temporary files, build results, and 9 | ## files generated by popular Visual Studio add-ons. 10 | 11 | # User-specific files 12 | *.suo 13 | *.user 14 | *.sln.docstates 15 | .vs/ 16 | 17 | # Build results 18 | [Dd]ebug/ 19 | [Rr]elease/ 20 | x64/ 21 | *_i.c 22 | *_p.c 23 | *.ilk 24 | *.meta 25 | *.obj 26 | *.pch 27 | *.pdb 28 | *.pgc 29 | *.pgd 30 | *.rsp 31 | *.sbr 32 | *.tlb 33 | *.tli 34 | *.tlh 35 | *.tmp 36 | *.log 37 | *.vspscc 38 | *.vssscc 39 | .builds 40 | 41 | # Visual C++ cache files 42 | ipch/ 43 | *.aps 44 | *.ncb 45 | *.opensdf 46 | *.sdf 47 | 48 | # Visual Studio profiler 49 | *.psess 50 | *.vsp 51 | *.vspx 52 | 53 | # Guidance Automation Toolkit 54 | *.gpState 55 | 56 | # ReSharper is a .NET coding add-in 57 | _ReSharper* 58 | 59 | # NCrunch 60 | *.ncrunch* 61 | .*crunch*.local.xml 62 | 63 | # Installshield output folder 64 | [Ee]xpress 65 | 66 | # DocProject is a documentation generator add-in 67 | DocProject/buildhelp/ 68 | DocProject/Help/*.HxT 69 | DocProject/Help/*.HxC 70 | DocProject/Help/*.hhc 71 | DocProject/Help/*.hhk 72 | DocProject/Help/*.hhp 73 | DocProject/Help/Html2 74 | DocProject/Help/html 75 | 76 | # Click-Once directory 77 | publish 78 | 79 | # Publish Web Output 80 | *.Publish.xml 81 | 82 | # NuGet Packages Directory 83 | /packages 84 | 85 | # Windows Azure Build Output 86 | csx 87 | *.build.csdef 88 | 89 | # Windows Store app package directory 90 | AppPackages/ 91 | 92 | # Others 93 | [Bb]in 94 | [Oo]bj 95 | sql 96 | TestResults 97 | [Tt]est[Rr]esult* 98 | *.Cache 99 | ClientBin 100 | [Ss]tyle[Cc]op.* 101 | ~$* 102 | *.dbmdl 103 | Generated_Code #added for RIA/Silverlight projects 104 | 105 | # Backup & report files from converting an old project file to a newer 106 | # Visual Studio version. Backup files are not needed, because we have git ;-) 107 | _UpgradeReport_Files/ 108 | Backup*/ 109 | UpgradeLog*.XML 110 | 111 | # Debug Data Directories 112 | App_Data -------------------------------------------------------------------------------- /Contributing.md: -------------------------------------------------------------------------------- 1 | # Introduction: 2 | First off, thank you for considering contributing to SQL Server Time Zone Support. If you're passionate about Time zones, passionate about SQL Server, or you just want to make the SQL world a little better, you're in the right place. 3 | 4 | Following these guidelines helps to communicate that you respect the time of the developers managing and developing this open source project. In return, the maintainers will reciprocate that respect in addressing your issue, assessing changes, and helping you finalize your pull requests. 5 | 6 | We're looking for and eagerly accepting all contributions. Whether you want to improve performance or fix bugs, or improve documentation, triage bugs, or write tutorials, any contribution is welcome. 7 | 8 | 9 | ## Ground Rules 10 | Please review the [Contributor covenant](https://www.contributor-covenant.org/version/1/4/code-of-conduct.md) for acceptable behavior guidelines. 11 | 12 | ## Your First Contribution 13 | Unsure where to begin contributing? Look for issues with an up-for-grabs or help-wanted tag. 14 | 15 | Working on your first Pull Request? You can learn how from this free series, [How to Contribute to an Open Source Project on GitHub](https://egghead.io/series/how-to-contribute-to-an-open-source-project-on-github) 16 | 17 | # Getting started: 18 | For something that is bigger than a one or two line fix: 19 | 20 | - Create your own fork of the code 21 | - Do the changes in your fork 22 | - If you like the change and think the project could use it, just send a pull request! 23 | 24 | Small contributions such as fixing spelling errors, where the content is small enough to not be considered intellectual property, can be submitted by a contributor directly. 25 | 26 | As a rule of thumb, changes are obvious fixes if they do not introduce any new functionality or creative thinking. As long as the change does not affect functionality, some likely examples include the following: 27 | 28 | * Spelling / grammar fixes 29 | * Typo correction, white space and formatting changes 30 | * Comment clean up 31 | * Bug fixes that change default return values or error codes stored in constants 32 | * Adding logging messages or debugging output 33 | * Changes to ‘metadata’ files like Gemfile, .gitignore, build scripts, etc. 34 | * Moving source files from one directory or package to another 35 | 36 | ## How to report a bug 37 | If you find a security vulnerability, do NOT open an issue. Email [mj1865](mailto://mj1856@hotmail.com) instead. In order to determine whether you are dealing with a security issue, ask yourself these two questions: 38 | 39 | Can I access something that's not mine, or something I shouldn't have access to? 40 | Can I disable something for other people? 41 | If the answer to either of those two questions are "yes", then you're probably dealing with a security issue. Note that even if you answer "no" to both questions, you may still be dealing with a security issue, so if you're unsure, just contact us directly. 42 | 43 | 44 | When filing an issue, make sure to answer these questions: 45 | * What "IDE" are you using (Visual Studio 2015 with SSDT, SSMS directly, notepad++, etc)? (if applicable) 46 | * What SQL Server version are you using (both management tools / client and SQL Engine)? (if applicable) 47 | * What operating system and processor architecture are you using? 48 | * What did you do? 49 | * What did you expect to see? 50 | * What did you see instead? 51 | 52 | ## How to suggest a feature or enhancement 53 | As noted in the introduction, SQL Server 2016 includes built-in support for Windows time zones using a new AT TIME ZONE syntax. If you only need support for Windows time zones (not IANA time zones), consider using this feature instead of this project. Read [the news here](http://blogs.technet.com/b/dataplatforminsider/archive/2015/11/30/sql-server-2016-community-technology-preview-3-1-is-available.aspx), and documentation [here](https://msdn.microsoft.com/en-us/library/mt612795.aspx). 54 | 55 | ## Code review process 56 | The core team (basically Matt) looks at Pull Requests on a best effort basis. We seek to get better, and are looking for volunteers to co-maintain the library to increase the cadence. 57 | 58 | ## How to contact core team 59 | Right now the core team is Matt. You can reach me via [email](mailto://mj1856@hotmail.com) or on [twitter](https://twitter.com/mj1856) 60 | 61 | -------------------------------------------------------------------------------- /Database/Database.sqlproj: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | Debug 6 | AnyCPU 7 | Database 8 | 2.0 9 | 4.1 10 | {ea37f5f7-fd91-47ef-b7dc-eecb4cf286d9} 11 | Microsoft.Data.Tools.Schema.Sql.SqlAzureDatabaseSchemaProvider 12 | Database 13 | 14 | 15 | Database 16 | Database 17 | 1033, CI 18 | BySchemaAndSchemaType 19 | True 20 | v4.5 21 | CS 22 | Properties 23 | False 24 | True 25 | True 26 | True 27 | Tzdb 28 | 29 | 30 | bin\Release\ 31 | $(MSBuildProjectName).sql 32 | False 33 | pdbonly 34 | true 35 | false 36 | true 37 | prompt 38 | 4 39 | 40 | 41 | bin\Debug\ 42 | $(MSBuildProjectName).sql 43 | false 44 | true 45 | full 46 | false 47 | true 48 | true 49 | prompt 50 | 4 51 | 52 | 53 | 11.0 54 | 55 | True 56 | 11.0 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | 83 | 84 | 85 | 86 | -------------------------------------------------------------------------------- /Database/Functions/ConvertZone.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION [Tzdb].[ConvertZone] 2 | ( 3 | @dt datetime2, 4 | @source_tz varchar(50), 5 | @dest_tz varchar(50), 6 | @SkipOnSpringForwardGap bit = 1, 7 | @FirstOnFallBackOverlap bit = 1 8 | ) 9 | RETURNS datetimeoffset 10 | AS 11 | BEGIN 12 | DECLARE @utc datetimeoffset 13 | SET @utc = [Tzdb].[LocalToUtc](@dt, @source_tz, @SkipOnSpringForwardGap, @FirstOnFallBackOverlap) 14 | RETURN [Tzdb].[UtcToLocal](@utc, @dest_tz) 15 | END 16 | -------------------------------------------------------------------------------- /Database/Functions/GetZoneAbbreviation.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION [Tzdb].[GetZoneAbbreviation] 2 | ( 3 | @dto datetimeoffset, 4 | @tz varchar(50) 5 | ) 6 | RETURNS varchar(10) 7 | AS 8 | BEGIN 9 | DECLARE @utc datetime2 10 | SET @utc = CONVERT(datetime2, SWITCHOFFSET(@dto, 0)) 11 | 12 | DECLARE @ZoneId int 13 | SET @ZoneId = [Tzdb].GetZoneId(@tz) 14 | 15 | DECLARE @Abbreviation varchar(10) 16 | SELECT TOP 1 @Abbreviation = [Abbreviation] 17 | FROM [Tzdb].[Intervals] 18 | WHERE [ZoneId] = @ZoneId 19 | AND [UtcStart] <= @utc AND [UtcEnd] > @utc 20 | 21 | RETURN @Abbreviation 22 | END 23 | -------------------------------------------------------------------------------- /Database/Functions/GetZoneId.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION [Tzdb].[GetZoneId] 2 | ( 3 | @tz varchar(50) 4 | ) 5 | RETURNS int 6 | AS 7 | BEGIN 8 | DECLARE @ZoneId int 9 | 10 | SELECT TOP 1 @ZoneId = l.[CanonicalZoneId] 11 | FROM [Tzdb].[Zones] z 12 | JOIN [Tzdb].[Links] l on z.[Id] = l.[LinkZoneId] 13 | WHERE z.[Name] = @tz 14 | 15 | IF @ZoneId IS NULL 16 | SELECT TOP 1 @ZoneId = [Id] 17 | FROM [Tzdb].[Zones] 18 | WHERE [Name] = @tz 19 | 20 | RETURN @ZoneId 21 | END 22 | -------------------------------------------------------------------------------- /Database/Functions/GetZoneId_Inline.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION [Tzdb].GetZoneId_Inline 2 | ( 3 | @tz VARCHAR(50) 4 | ) 5 | RETURNS TABLE WITH SCHEMABINDING AS 6 | RETURN ( 7 | SELECT ISNULL(l.CanonicalZoneId, z.Id) AS ZoneId 8 | FROM Tzdb.Zones z LEFT JOIN Tzdb.Links l ON l.LinkZoneId = z.Id 9 | WHERE z.Name = @tz 10 | ) 11 | -------------------------------------------------------------------------------- /Database/Functions/LocalToUtc.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION Tzdb.LocalToUtc 2 | ( 3 | @local datetime2, 4 | @tz varchar(50), 5 | @SkipOnSpringForwardGap bit = 1, -- if the local time is in a gap, 1 skips forward and 0 will return null 6 | @FirstOnFallBackOverlap bit = 1 -- if the local time is ambiguous, 1 uses the first (daylight) instance and 0 will use the second (standard) instance 7 | ) 8 | RETURNS datetimeoffset 9 | WITH SCHEMABINDING AS 10 | BEGIN 11 | DECLARE @OffsetMinutes int 12 | 13 | IF @FirstOnFallBackOverlap = 1 14 | SELECT TOP 1 @OffsetMinutes = [OffsetMinutes] 15 | FROM [Tzdb].[Intervals] i INNER JOIN Tzdb.GetZoneId_Inline(@tz) z ON z.ZoneId = i.ZoneId 16 | WHERE [LocalStart] <= @local AND [LocalEnd] > @local 17 | ORDER BY [UtcStart] 18 | ELSE 19 | SELECT TOP 1 @OffsetMinutes = [OffsetMinutes] 20 | FROM [Tzdb].[Intervals] i INNER JOIN Tzdb.GetZoneId_Inline(@tz) z ON z.ZoneId = i.ZoneId 21 | WHERE [LocalStart] <= @local AND [LocalEnd] > @local 22 | ORDER BY [UtcStart] DESC 23 | 24 | IF @OffsetMinutes IS NULL 25 | BEGIN 26 | IF @SkipOnSpringForwardGap = 0 RETURN NULL 27 | 28 | SET @local = DATEADD(MINUTE, CASE @tz WHEN 'Australia/Lord_Howe' THEN 30 ELSE 60 END, @local) 29 | SELECT TOP 1 @OffsetMinutes = [OffsetMinutes] 30 | FROM [Tzdb].[Intervals] i INNER JOIN Tzdb.GetZoneId_Inline(@tz) z ON z.ZoneId = i.ZoneId 31 | WHERE [LocalStart] <= @local AND [LocalEnd] > @local 32 | END 33 | 34 | RETURN TODATETIMEOFFSET(DATEADD(MINUTE, -@OffsetMinutes, @local), 0) 35 | END 36 | -------------------------------------------------------------------------------- /Database/Functions/SwitchZone.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION [Tzdb].[SwitchZone] 2 | ( 3 | @dto datetimeoffset, 4 | @tz varchar(50) 5 | ) 6 | RETURNS datetimeoffset 7 | AS 8 | BEGIN 9 | DECLARE @utc datetime2 10 | SET @utc = CONVERT(datetime2, SWITCHOFFSET(@dto, 0)) 11 | RETURN [Tzdb].[UtcToLocal](@utc, @tz) 12 | END 13 | -------------------------------------------------------------------------------- /Database/Functions/UtcToLocal.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION Tzdb.UtcToLocal 2 | ( 3 | @utc DATETIME2, 4 | @tz VARCHAR(50) 5 | ) 6 | RETURNS DATETIMEOFFSET 7 | WITH SCHEMABINDING AS 8 | BEGIN 9 | DECLARE @OffsetMinutes INT 10 | 11 | SELECT TOP 1 @OffsetMinutes = [OffsetMinutes] 12 | FROM [Tzdb].[Intervals] i INNER JOIN Tzdb.GetZoneId_Inline(@tz) z ON i.ZoneId = z.ZoneId 13 | WHERE [UtcStart] <= @utc AND [UtcEnd] > @utc 14 | 15 | RETURN TODATETIMEOFFSET(DATEADD(MINUTE, @OffsetMinutes, @utc), @OffsetMinutes) 16 | END 17 | -------------------------------------------------------------------------------- /Database/Procedures/AddLink.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [Tzdb].[AddLink] 2 | @LinkZoneId int, 3 | @CanonicalZoneId int 4 | AS 5 | DECLARE @cid int 6 | SELECT @cid = @CanonicalZoneId FROM [Tzdb].[Links] WHERE [LinkZoneId] = @LinkZoneId 7 | IF @cid is null 8 | INSERT INTO [Tzdb].[Links] ([LinkZoneId], [CanonicalZoneId]) VALUES (@LinkZoneId, @CanonicalZoneId) 9 | ELSE IF @cid <> @CanonicalZoneId 10 | UPDATE [Tzdb].[Links] SET [CanonicalZoneId] = @CanonicalZoneId WHERE [LinkZoneId] = @LinkZoneId 11 | -------------------------------------------------------------------------------- /Database/Procedures/AddZone.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [Tzdb].[AddZone] 2 | @Name varchar(50) 3 | AS 4 | DECLARE @id int 5 | SELECT @id = [Id] FROM [Tzdb].[Zones] WHERE [Name] = @Name 6 | IF @id is null 7 | BEGIN 8 | INSERT INTO [Tzdb].[Zones] ([Name]) VALUES (@Name) 9 | SET @id = SCOPE_IDENTITY() 10 | END 11 | SELECT @id as [Id] -------------------------------------------------------------------------------- /Database/Procedures/SetIntervals.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [Tzdb].[SetIntervals] 2 | @ZoneId int, 3 | @Intervals [Tzdb].[IntervalTable] READONLY 4 | AS 5 | DELETE FROM [Tzdb].[Intervals] WHERE [ZoneId] = @ZoneId 6 | INSERT INTO [Tzdb].[Intervals] ([ZoneId], [UtcStart], [UtcEnd], [LocalStart], [LocalEnd], [OffsetMinutes], [Abbreviation]) 7 | SELECT @ZoneId as [ZoneId], [UtcStart], [UtcEnd], [LocalStart], [LocalEnd], [OffsetMinutes], [Abbreviation] 8 | FROM @Intervals 9 | -------------------------------------------------------------------------------- /Database/Procedures/SetVersion.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [Tzdb].[SetVersion] 2 | @Version char(5) 3 | AS 4 | DELETE FROM [Tzdb].[VersionInfo] 5 | INSERT INTO [Tzdb].[VersionInfo] ([Version],[Loaded]) VALUES (@Version, GETUTCDATE()) 6 | -------------------------------------------------------------------------------- /Database/Schema.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [Tzdb] 2 | -------------------------------------------------------------------------------- /Database/Tables/Intervals.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [Tzdb].[Intervals] 2 | ( 3 | [Id] INT NOT NULL IDENTITY(1,1), 4 | [ZoneId] INT NOT NULL, 5 | [UtcStart] DATETIME2(0) NOT NULL, 6 | [UtcEnd] DATETIME2(0) NOT NULL, 7 | [LocalStart] DATETIME2(0) NOT NULL, 8 | [LocalEnd] DATETIME2(0) NOT NULL, 9 | [OffsetMinutes] SMALLINT NOT NULL, 10 | [Abbreviation] VARCHAR(10) NOT NULL, 11 | CONSTRAINT [PK_Intervals] PRIMARY KEY ([Id]), 12 | CONSTRAINT [FK_Intervals_Zones] FOREIGN KEY ([ZoneId]) REFERENCES [Tzdb].[Zones]([Id]) 13 | ) 14 | 15 | GO 16 | 17 | CREATE NONCLUSTERED INDEX [IX_Intervals_Utc] ON [Tzdb].[Intervals] 18 | ( 19 | [ZoneId], [UtcStart], [UtcEnd] 20 | ) 21 | INCLUDE 22 | ( 23 | [OffsetMinutes], [Abbreviation] 24 | ) 25 | 26 | GO 27 | 28 | CREATE NONCLUSTERED INDEX [IX_Intervals_Local] ON [Tzdb].[Intervals] 29 | ( 30 | [ZoneId], [LocalStart], [LocalEnd], [UtcStart] 31 | ) 32 | INCLUDE 33 | ( 34 | [OffsetMinutes], [Abbreviation] 35 | ) 36 | -------------------------------------------------------------------------------- /Database/Tables/Links.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [Tzdb].[Links] 2 | ( 3 | [LinkZoneId] INT NOT NULL, 4 | [CanonicalZoneId] INT NOT NULL, 5 | CONSTRAINT [PK_Links] PRIMARY KEY ([LinkZoneId]), 6 | CONSTRAINT [FK_Links_Zones_1] FOREIGN KEY ([LinkZoneId]) REFERENCES [Tzdb].[Zones]([Id]), 7 | CONSTRAINT [FK_Links_Zones_2] FOREIGN KEY ([CanonicalZoneId]) REFERENCES [Tzdb].[Zones]([Id]) 8 | ) 9 | -------------------------------------------------------------------------------- /Database/Tables/VersionInfo.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [Tzdb].[VersionInfo] 2 | ( 3 | [Version] CHAR(5) NOT NULL, 4 | [Loaded] DATETIMEOFFSET(0) NOT NULL, 5 | CONSTRAINT [PK_VersionInfo] PRIMARY KEY ([Version]) 6 | ) 7 | -------------------------------------------------------------------------------- /Database/Tables/Zones.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [Tzdb].[Zones] 2 | ( 3 | [Id] INT NOT NULL IDENTITY(1,1), 4 | [Name] VARCHAR(50) NOT NULL, 5 | CONSTRAINT [PK_Zones] PRIMARY KEY([Id]) 6 | ) 7 | 8 | GO 9 | 10 | CREATE UNIQUE INDEX [IX_Zones_Name] ON [Tzdb].[Zones] ([Name]) 11 | -------------------------------------------------------------------------------- /Database/Types/IntervalTable.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE [Tzdb].[IntervalTable] AS TABLE 2 | ( 3 | [UtcStart] DATETIME2(0) NOT NULL, 4 | [UtcEnd] DATETIME2(0) NOT NULL, 5 | [LocalStart] DATETIME2(0) NOT NULL, 6 | [LocalEnd] DATETIME2(0) NOT NULL, 7 | [OffsetMinutes] SMALLINT NOT NULL, 8 | [Abbreviation] VARCHAR(10) NOT NULL 9 | ) -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2015 Matt Johnson 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | 23 | -------------------------------------------------------------------------------- /NodaTime.CurrentTzdbProvider/AsyncLazy.cs: -------------------------------------------------------------------------------- 1 | using System.Runtime.CompilerServices; 2 | 3 | namespace System.Threading.Tasks 4 | { 5 | internal class AsyncLazy : Lazy> 6 | { 7 | // http://blogs.msdn.com/b/pfxteam/archive/2011/01/15/10116210.aspx 8 | 9 | public AsyncLazy(Func valueFactory) : 10 | base(() => Task.Factory.StartNew(valueFactory)) { } 11 | 12 | public AsyncLazy(Func> taskFactory) : 13 | base(() => Task.Factory.StartNew(taskFactory).Unwrap()) { } 14 | 15 | public TaskAwaiter GetAwaiter() 16 | { 17 | return Value.GetAwaiter(); 18 | } 19 | } 20 | } 21 | -------------------------------------------------------------------------------- /NodaTime.CurrentTzdbProvider/CachedAsyncLazy.cs: -------------------------------------------------------------------------------- 1 | using System.Diagnostics; 2 | using System.Runtime.CompilerServices; 3 | 4 | namespace System.Threading.Tasks 5 | { 6 | internal class CachedAsyncLazy 7 | { 8 | private readonly TimeSpan _cacheTimeout; 9 | private readonly Func> _taskFactory; 10 | private readonly Func _valueFactory; 11 | private readonly Stopwatch _stopwatch = new Stopwatch(); 12 | 13 | private AsyncLazy _lazy; 14 | 15 | public CachedAsyncLazy(TimeSpan cacheTimeout, Func valueFactory) 16 | { 17 | if (cacheTimeout <= TimeSpan.Zero) 18 | throw new ArgumentOutOfRangeException("cacheTimeout"); 19 | 20 | _cacheTimeout = cacheTimeout; 21 | _valueFactory = valueFactory; 22 | _lazy = new AsyncLazy(valueFactory); 23 | } 24 | 25 | public CachedAsyncLazy(TimeSpan cacheTimeout, Func> taskFactory) 26 | { 27 | if (cacheTimeout <= TimeSpan.Zero) 28 | throw new ArgumentOutOfRangeException("cacheTimeout"); 29 | 30 | _cacheTimeout = cacheTimeout; 31 | _taskFactory = taskFactory; 32 | _lazy = new AsyncLazy(taskFactory); 33 | } 34 | 35 | public Task Value 36 | { 37 | get 38 | { 39 | if (IsValueCreated && _stopwatch.Elapsed >= _cacheTimeout) 40 | { 41 | if (_valueFactory != null) 42 | _lazy = new AsyncLazy(_valueFactory); 43 | else if (_taskFactory != null) 44 | _lazy = new AsyncLazy(_taskFactory); 45 | } 46 | 47 | var value = _lazy.Value; 48 | _stopwatch.Restart(); 49 | return value; 50 | } 51 | } 52 | 53 | public bool IsValueCreated 54 | { 55 | get { return _lazy.IsValueCreated; } 56 | } 57 | 58 | public TaskAwaiter GetAwaiter() 59 | { 60 | return _lazy.GetAwaiter(); 61 | } 62 | 63 | public TimeSpan CacheTime 64 | { 65 | get { return _stopwatch.Elapsed; } 66 | } 67 | } 68 | } -------------------------------------------------------------------------------- /NodaTime.CurrentTzdbProvider/CurrentTzdbProvider.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.ObjectModel; 3 | using System.IO; 4 | using System.Linq; 5 | using System.Net.Http; 6 | using System.Threading.Tasks; 7 | using NodaTime.TimeZones; 8 | 9 | namespace NodaTime 10 | { 11 | public sealed class CurrentTzdbProvider : IDateTimeZoneProvider 12 | { 13 | private static readonly CachedAsyncLazy Instance = 14 | new CachedAsyncLazy(TimeSpan.FromDays(1), () => DownloadAsync()); 15 | 16 | private readonly IDateTimeZoneProvider _provider; 17 | private readonly ILookup _aliases; 18 | 19 | private CurrentTzdbProvider(IDateTimeZoneProvider provider, ILookup aliases) 20 | { 21 | _provider = provider; 22 | _aliases = aliases; 23 | } 24 | 25 | public static async Task LoadAsync() 26 | { 27 | return await Instance; 28 | } 29 | 30 | private static async Task DownloadAsync() 31 | { 32 | using (var client = new HttpClient()) 33 | { 34 | var latest = new Uri((await client.GetStringAsync("http://nodatime.org/tzdb/latest.txt")).TrimEnd()); 35 | var fileName = latest.Segments.Last(); 36 | var path = Path.Combine(Path.GetTempPath(), fileName); 37 | 38 | if (!File.Exists(path)) 39 | { 40 | using (var httpStream = await client.GetStreamAsync(latest)) 41 | using (var fileStream = File.Create(path)) 42 | { 43 | await httpStream.CopyToAsync(fileStream); 44 | } 45 | } 46 | 47 | using (var fileStream = File.OpenRead(path)) 48 | { 49 | var source = TzdbDateTimeZoneSource.FromStream(fileStream); 50 | var provider = new DateTimeZoneCache(source); 51 | return new CurrentTzdbProvider(provider, source.Aliases); 52 | } 53 | } 54 | } 55 | 56 | public ILookup Aliases 57 | { 58 | get { return _aliases; } 59 | } 60 | 61 | public DateTimeZone GetSystemDefault() 62 | { 63 | return _provider.GetSystemDefault(); 64 | } 65 | 66 | public DateTimeZone GetZoneOrNull(string id) 67 | { 68 | return _provider.GetZoneOrNull(id); 69 | } 70 | 71 | public string VersionId 72 | { 73 | get { return _provider.VersionId; } 74 | } 75 | 76 | public ReadOnlyCollection Ids 77 | { 78 | get { return _provider.Ids; } 79 | } 80 | 81 | public DateTimeZone this[string id] 82 | { 83 | get { return _provider[id]; } 84 | } 85 | } 86 | } 87 | -------------------------------------------------------------------------------- /NodaTime.CurrentTzdbProvider/NodaTime.CurrentTzdbProvider.csproj: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | Debug 6 | AnyCPU 7 | {B8ABB022-9691-469B-B2AE-BCC12F725798} 8 | Library 9 | Properties 10 | NodaTime 11 | NodaTime.CurrentTzdbProvider 12 | v4.5 13 | 512 14 | 15 | 16 | true 17 | full 18 | false 19 | bin\Debug\ 20 | DEBUG;TRACE 21 | prompt 22 | 4 23 | 24 | 25 | pdbonly 26 | true 27 | bin\Release\ 28 | TRACE 29 | prompt 30 | 4 31 | 32 | 33 | 34 | ..\packages\NodaTime.1.3.1\lib\net35-Client\NodaTime.dll 35 | 36 | 37 | 38 | 39 | 40 | ..\packages\Microsoft.Net.Http.2.2.29\lib\net45\System.Net.Http.Extensions.dll 41 | 42 | 43 | ..\packages\Microsoft.Net.Http.2.2.29\lib\net45\System.Net.Http.Primitives.dll 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 70 | -------------------------------------------------------------------------------- /NodaTime.CurrentTzdbProvider/Properties/AssemblyInfo.cs: -------------------------------------------------------------------------------- 1 | using System.Reflection; 2 | using System.Runtime.CompilerServices; 3 | using System.Runtime.InteropServices; 4 | 5 | // General Information about an assembly is controlled through the following 6 | // set of attributes. Change these attribute values to modify the information 7 | // associated with an assembly. 8 | [assembly: AssemblyTitle("NodaTime.CurrentTzdbProvider")] 9 | [assembly: AssemblyDescription("")] 10 | [assembly: AssemblyConfiguration("")] 11 | [assembly: AssemblyCompany("")] 12 | [assembly: AssemblyProduct("NodaTime.CurrentTzdbProvider")] 13 | [assembly: AssemblyCopyright("Copyright © 2015")] 14 | [assembly: AssemblyTrademark("")] 15 | [assembly: AssemblyCulture("")] 16 | 17 | // Setting ComVisible to false makes the types in this assembly not visible 18 | // to COM components. If you need to access a type in this assembly from 19 | // COM, set the ComVisible attribute to true on that type. 20 | [assembly: ComVisible(false)] 21 | 22 | // The following GUID is for the ID of the typelib if this project is exposed to COM 23 | [assembly: Guid("dc7f17a8-0636-4d3d-817c-85455aadb89b")] 24 | 25 | // Version information for an assembly consists of the following four values: 26 | // 27 | // Major Version 28 | // Minor Version 29 | // Build Number 30 | // Revision 31 | // 32 | // You can specify all the values or you can default the Build and Revision Numbers 33 | // by using the '*' as shown below: 34 | // [assembly: AssemblyVersion("1.0.*")] 35 | [assembly: AssemblyVersion("1.0.0.0")] 36 | [assembly: AssemblyFileVersion("1.0.0.0")] 37 | -------------------------------------------------------------------------------- /NodaTime.CurrentTzdbProvider/packages.config: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | 6 | 7 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL Server Time Zone Support 2 | 3 | This project adds full support for time zones to Microsoft SQL Server. 4 | 5 | This implementation uses the industry standard [IANA time zone database][1]. If you are used to Microsoft Windows time zones, such as used with .NET `TimeZoneInfo`, consider using IANA time zones by using the [Noda Time][2] library. 6 | 7 | You can read more about the IANA time zone database on [Wikipedia][3], and on [StackOverflow][4]. 8 | 9 | [A list of supported time zones can be found here.][12] 10 | 11 | **Note:** This is an un-official, personal project. It is not developed or supported by Microsoft. 12 | 13 | #### News: 14 | 15 | SQL Server 2016 includes built-in support for Windows time zones using a new `AT TIME ZONE` syntax. If you only need support for Windows time zones (not IANA time zones), consider using this feature *instead of this project*. Read [the news here](http://blogs.technet.com/b/dataplatforminsider/archive/2015/11/30/sql-server-2016-community-technology-preview-3-1-is-available.aspx), and [documentation here](https://msdn.microsoft.com/en-us/library/mt612795.aspx). 16 | 17 | ### Installation 18 | 19 | 1. Download the latest `sqltz.zip` file from [the releases page][5]. 20 | 2. Extract the zip file to a directory. 21 | 3. Open the `tzdb.sql` file, and run it against your database. 22 | - It will create all objects in an independent schema called `[Tzdb]`. 23 | - Microsoft SQL Server 2008 R2 and higher are supported, including Azure SQL Database. 24 | 4. Run the `SqlTzLoader.exe` utility, passing the connection string with the `-c` parameter. 25 | For example: 26 | 27 | ```bat 28 | SqlTzLoader.exe -c"Server=YourServerName;Database=YourDatabaseName;Trusted_Connection=True" 29 | ``` 30 | 31 | or 32 | 33 | ```bat 34 | SqlTzLoader.exe -c"Server=YourServerName;Database=YourDatabaseName;User Id=foo;Password=bar" 35 | ``` 36 | It will download the latest time zone data and populate the tables in the database. 37 | 38 | ### Staying Current 39 | 40 | You can re-execute the `SqlTzLoader.exe` utility any time. If new time zone data is available, it will download it and update the tables. You can easily run this from SQL Agent, Windows Scheduler, or Azure Scheduler. Please do not run it more than once daily. 41 | 42 | Our data comes from the [Noda Time TZDB NZD files][6], which in turn is generated directly from IANA releases. Therefore, you may notice a short delay between publishing of IANA TZDB and the updated NZD file being made available. 43 | 44 | ### Usage 45 | 46 | There are several user-defined functions exposed for common time zone conversion operations. If you need additional functions, please create an issue in [the issue tracker][7]. 47 | 48 | #### UtcToLocal 49 | 50 | Converts a `datetime` or `datetime2` value from UTC to a specific time zone. The output is a `datetimeoffset` value that has the correct local time and offset for the time zone requested. 51 | 52 | ```sql 53 | -- SYNTAX 54 | Tzdb.UtcToLocal([utc_datetime], [dest_timezone]) 55 | 56 | -- EXAMPLE 57 | SELECT Tzdb.UtcToLocal('2015-07-01 00:00:00', 'America/Los_Angeles') 58 | -- output: '2015-06-30 17:00:00 -07:00' 59 | ``` 60 | 61 | #### LocalToUtc 62 | 63 | Converts a `datetime` or `datetime2` value from a specific time zone to UTC. The output is a `datetimeoffset` value that has the correct UTC time and an offset of `+00:00`. 64 | 65 | Be aware that local-to-utc conversion is potentially a lossy operation. For more details, consult [the dst tag wiki on StackOverflow][8]. 66 | 67 | ```sql 68 | -- SYNTAX 69 | Tzdb.LocalToUtc([source_datetime], [source_timezone], [SkipOnSpringForwardGap], [FirstOnFallBackOverlap]) 70 | 71 | -- EXAMPLE 72 | SELECT Tzdb.LocalToUtc('2015-07-01 00:00:00', 'America/Los_Angeles', 1, 1) 73 | -- output: '2015-07-01 07:00:00 +00:00' 74 | ``` 75 | 76 | - The `SkipOnSpringForwardGap` parameter has the following options: 77 | - `1` : If a local time is in a DST gap due to the "spring-forward" DST transition, it is assumed that the clock *should* have sprung forward but didn't. It therefore advances the time by the DST bias (usually 1 hour) so it can return a valid UTC time. This is the default option. 78 | - `0` : If a local time is in a DST gap due to the "spring-forward" DST transition, the function returns `NULL`. 79 | 80 | - The `FirstOnFallBackOverlap` parameter has the following options: 81 | - `1` : If a local time is ambiguous due to the "fall-back" DST transition, the *first* occurrence is assumed. This will always be the *daylight* time instance. This is the default option. 82 | - `0` : If a local time is ambiguous due to the "fall-back" DST transition, the *second* occurrence is assumed. This will always be the *standard* time instance. 83 | 84 | 85 | #### ConvertZone 86 | 87 | Converts a `datetime` or `datetime2` value from a specific time zone to another specific time zone. The output is a `datetimeoffset` value that has the correct local time and offset for the destination time zone requested. 88 | 89 | The DST option flags are the same as the `LocalToUtc` function, and apply to the *source* time zone only. 90 | 91 | ```sql 92 | -- SYNTAX 93 | Tzdb.ConvertZone([source_datetime], [source_timezone], [dest_timezone], [SkipOnSpringForwardGap], [FirstOnFallBackOverlap]) 94 | 95 | -- EXAMPLE 96 | SELECT Tzdb.ConvertZone('2015-07-01 00:00:00', 'America/Los_Angeles', 'Australia/Sydney', 1, 1) 97 | -- output: '2015-07-01 17:00:00 +10:00' 98 | ``` 99 | 100 | #### SwitchZone 101 | 102 | Converts a `datetimeoffset` value to a specific time zone. The output is a `datetimeoffset` value that has the correct local time and offset for the time zone requested. 103 | 104 | This function is similar to SQL Server's `SWITCHOFFSET` function, however it accepts a time zone instead of an offset - so it can take daylight saving time into account. 105 | 106 | ```sql 107 | -- SYNTAX 108 | Tzdb.SwitchZone([source_datetimeoffset], [dest_timezone]) 109 | 110 | -- EXAMPLE 111 | SELECT Tzdb.SwitchZone('2015-07-01 00:00:00 -04:00', 'Asia/Kolkata') 112 | -- output: '2015-07-01 09:30:00 +05:30' 113 | ``` 114 | 115 | #### GetZoneAbbreviation 116 | 117 | Determines the correct abbreviation to use for the `datetimeoffset` value and time zone provided. The output is a `varchar(10)` containing the abbreviation requested. 118 | 119 | If you don't have a `datetimeoffset`, you should first obtain one either by using the `LocalToUtc` or `UtcToLocal` conversion functions, or by crafting it manually with SQL Server's `TODATETIMEOFFSET` function. Do not pass a `datetime` or `datetime2` in, or the *server's* local time zone will get applied during the conversion. 120 | 121 | Note that the abbreviations for many time zones depend on the specific date and time that they apply to. 122 | 123 | ```sql 124 | -- SYNTAX 125 | Tzdb.GetZoneAbbreviation([datetimeoffset], [timezone]) 126 | 127 | -- EXAMPLE 128 | SELECT Tzdb.GetZoneAbbreviation('2015-07-01 00:00:00 -04:00', 'America/New_York') 129 | -- output: 'EDT' 130 | ``` 131 | 132 | ### Shameless Plug 133 | 134 | If you want to learn more about time zones, and all of the lovely bits of programming that go around them, please consider watching my Pluralsight course, [Date and Time Fundamentals][9]. 135 | 136 | I also have a blog at [CodeOfMatt.com][10], which covers several issues surrounding dates, times, and time zones. 137 | 138 | Thanks! 139 | 140 | ### License 141 | 142 | This project is made freely available under [the MIT license][11]. Attribution is requested. 143 | 144 | This project uses the following external resources: 145 | 146 | - [Noda Time][2] (Apache licensed) 147 | - [IANA Time Zone Database][1] (public domain) 148 | 149 | [1]: http://www.iana.org/time-zones 150 | [2]: http://nodatime.org 151 | [3]: http://en.wikipedia.org/wiki/Tz_database 152 | [4]: http://stackoverflow.com/tags/timezone/info 153 | [5]: https://github.com/mj1856/SqlServerTimeZoneSupport/releases 154 | [6]: http://nodatime.org/tzdb/ 155 | [7]: https://github.com/mj1856/SqlServerTimeZoneSupport/issues 156 | [8]: http://stackoverflow.com/tags/dst/info 157 | [9]: http://www.pluralsight.com/courses/date-time-fundamentals 158 | [10]: http://codeofmatt.com 159 | [11]: https://github.com/mj1856/SqlServerTimeZoneSupport/blob/master/LICENSE 160 | [12]: http://en.wikipedia.org/wiki/List_of_tz_database_time_zones 161 | -------------------------------------------------------------------------------- /SqlTimeZone.sln: -------------------------------------------------------------------------------- 1 |  2 | Microsoft Visual Studio Solution File, Format Version 12.00 3 | # Visual Studio 2013 4 | VisualStudioVersion = 12.0.31101.0 5 | MinimumVisualStudioVersion = 10.0.40219.1 6 | Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "SqlTzLoader", "SqlTzLoader\SqlTzLoader.csproj", "{1C6E56EA-6FE4-4360-A87E-3B2E7B8ADD5E}" 7 | EndProject 8 | Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "NodaTime.CurrentTzdbProvider", "NodaTime.CurrentTzdbProvider\NodaTime.CurrentTzdbProvider.csproj", "{B8ABB022-9691-469B-B2AE-BCC12F725798}" 9 | EndProject 10 | Project("{00D1A9C2-B5F0-4AF3-8072-F6C62B433612}") = "Database", "Database\Database.sqlproj", "{EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}" 11 | EndProject 12 | Global 13 | GlobalSection(SolutionConfigurationPlatforms) = preSolution 14 | Debug|Any CPU = Debug|Any CPU 15 | Release|Any CPU = Release|Any CPU 16 | EndGlobalSection 17 | GlobalSection(ProjectConfigurationPlatforms) = postSolution 18 | {1C6E56EA-6FE4-4360-A87E-3B2E7B8ADD5E}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 19 | {1C6E56EA-6FE4-4360-A87E-3B2E7B8ADD5E}.Debug|Any CPU.Build.0 = Debug|Any CPU 20 | {1C6E56EA-6FE4-4360-A87E-3B2E7B8ADD5E}.Release|Any CPU.ActiveCfg = Release|Any CPU 21 | {1C6E56EA-6FE4-4360-A87E-3B2E7B8ADD5E}.Release|Any CPU.Build.0 = Release|Any CPU 22 | {B8ABB022-9691-469B-B2AE-BCC12F725798}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 23 | {B8ABB022-9691-469B-B2AE-BCC12F725798}.Debug|Any CPU.Build.0 = Debug|Any CPU 24 | {B8ABB022-9691-469B-B2AE-BCC12F725798}.Release|Any CPU.ActiveCfg = Release|Any CPU 25 | {B8ABB022-9691-469B-B2AE-BCC12F725798}.Release|Any CPU.Build.0 = Release|Any CPU 26 | {EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 27 | {EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}.Debug|Any CPU.Build.0 = Debug|Any CPU 28 | {EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}.Debug|Any CPU.Deploy.0 = Debug|Any CPU 29 | {EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}.Release|Any CPU.ActiveCfg = Release|Any CPU 30 | {EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}.Release|Any CPU.Build.0 = Release|Any CPU 31 | {EA37F5F7-FD91-47EF-B7DC-EECB4CF286D9}.Release|Any CPU.Deploy.0 = Release|Any CPU 32 | EndGlobalSection 33 | GlobalSection(SolutionProperties) = preSolution 34 | HideSolutionNode = FALSE 35 | EndGlobalSection 36 | EndGlobal 37 | -------------------------------------------------------------------------------- /SqlTzLoader/AsyncPump.cs: -------------------------------------------------------------------------------- 1 |  2 | // http://blogs.msdn.com/b/pfxteam/archive/2012/01/20/10259049.aspx 3 | 4 | using System; 5 | using System.Collections.Concurrent; 6 | using System.Collections.Generic; 7 | using System.Threading; 8 | using System.Threading.Tasks; 9 | 10 | namespace Microsoft.Threading 11 | { 12 | /// Provides a pump that supports running asynchronous methods on the current thread. 13 | public static class AsyncPump 14 | { 15 | /// Runs the specified asynchronous function. 16 | /// The asynchronous function to execute. 17 | public static void Run(Func func) 18 | { 19 | if (func == null) throw new ArgumentNullException("func"); 20 | 21 | var prevCtx = SynchronizationContext.Current; 22 | try 23 | { 24 | // Establish the new context 25 | var syncCtx = new SingleThreadSynchronizationContext(); 26 | SynchronizationContext.SetSynchronizationContext(syncCtx); 27 | 28 | // Invoke the function and alert the context to when it completes 29 | var t = func(); 30 | if (t == null) throw new InvalidOperationException("No task provided."); 31 | t.ContinueWith(delegate { syncCtx.Complete(); }, TaskScheduler.Default); 32 | 33 | // Pump continuations and propagate any exceptions 34 | syncCtx.RunOnCurrentThread(); 35 | t.GetAwaiter().GetResult(); 36 | } 37 | finally { SynchronizationContext.SetSynchronizationContext(prevCtx); } 38 | } 39 | 40 | /// Provides a SynchronizationContext that's single-threaded. 41 | private sealed class SingleThreadSynchronizationContext : SynchronizationContext 42 | { 43 | /// The queue of work items. 44 | private readonly BlockingCollection> m_queue = 45 | new BlockingCollection>(); 46 | /// The processing thread. 47 | private readonly Thread m_thread = Thread.CurrentThread; 48 | 49 | /// Dispatches an asynchronous message to the synchronization context. 50 | /// The System.Threading.SendOrPostCallback delegate to call. 51 | /// The object passed to the delegate. 52 | public override void Post(SendOrPostCallback d, object state) 53 | { 54 | if (d == null) throw new ArgumentNullException("d"); 55 | m_queue.Add(new KeyValuePair(d, state)); 56 | } 57 | 58 | /// Not supported. 59 | public override void Send(SendOrPostCallback d, object state) 60 | { 61 | throw new NotSupportedException("Synchronously sending is not supported."); 62 | } 63 | 64 | /// Runs an loop to process all queued work items. 65 | public void RunOnCurrentThread() 66 | { 67 | foreach (var workItem in m_queue.GetConsumingEnumerable()) 68 | workItem.Key(workItem.Value); 69 | } 70 | 71 | /// Notifies the context that no more work will arrive. 72 | public void Complete() { m_queue.CompleteAdding(); } 73 | } 74 | } 75 | } -------------------------------------------------------------------------------- /SqlTzLoader/Options.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Text; 5 | using System.Threading.Tasks; 6 | using CommandLine; 7 | using CommandLine.Text; 8 | using System.Configuration; 9 | 10 | namespace SqlTzLoader 11 | { 12 | 13 | internal class Options 14 | { 15 | private readonly HeadingInfo headingInfo = new HeadingInfo(System.Reflection.Assembly.GetExecutingAssembly().GetName().Name, System.Reflection.Assembly.GetExecutingAssembly().GetName().Version.ToString()); 16 | 17 | [Option('c', "connectionString", Required = true, HelpText = "Connectionstring of database to update.")] 18 | public string ConnectionString { get; set; } 19 | 20 | [Option('v', "verbose", HelpText = "Prints all messages to standard output.")] 21 | public bool Verbose { get; set; } 22 | 23 | [ParserState] 24 | public IParserState LastParserState { get; set; } 25 | 26 | [HelpOption] 27 | public string GetUsage() 28 | { 29 | return HelpText.AutoBuild(this, (HelpText current) => HelpText.DefaultParsingErrorsHandler(this, current)); 30 | } 31 | 32 | } 33 | } 34 | -------------------------------------------------------------------------------- /SqlTzLoader/Program.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Configuration; 4 | using System.Data; 5 | using System.Data.SqlClient; 6 | using System.Linq; 7 | using System.Threading.Tasks; 8 | using Microsoft.Threading; 9 | using NodaTime; 10 | 11 | namespace SqlTzLoader 12 | { 13 | class Program 14 | { 15 | private static Options _options = new Options(); 16 | 17 | static void Main(string[] args) 18 | { 19 | if (CommandLine.Parser.Default.ParseArgumentsStrict(args, _options)) 20 | { 21 | if (_options.Verbose) Console.WriteLine("ConnectionString: {0}", _options.ConnectionString); 22 | 23 | AsyncPump.Run(() => MainAsync(args)); 24 | } 25 | } 26 | 27 | static async Task MainAsync(string[] args) 28 | { 29 | var tzdb = await CurrentTzdbProvider.LoadAsync(); 30 | 31 | var zones = await WriteZonesAsync(tzdb.Ids); 32 | 33 | await WriteLinksAsync(zones, tzdb.Aliases); 34 | 35 | await WriteIntervalsAsync(zones, tzdb); 36 | 37 | await WriteVersion(tzdb.VersionId.Split(' ')[1]); 38 | } 39 | 40 | private static async Task> WriteZonesAsync(IEnumerable zones) 41 | { 42 | var dictionary = new Dictionary(); 43 | 44 | var cs = _options.ConnectionString; 45 | using (var connection = new SqlConnection(cs)) 46 | { 47 | var command = new SqlCommand("[Tzdb].[AddZone]", connection) { CommandType = CommandType.StoredProcedure }; 48 | command.Parameters.Add("@Name", SqlDbType.VarChar, 50); 49 | 50 | await connection.OpenAsync(); 51 | 52 | foreach (var zone in zones) 53 | { 54 | command.Parameters[0].Value = zone; 55 | var id = (int)await command.ExecuteScalarAsync(); 56 | dictionary.Add(zone, id); 57 | } 58 | 59 | connection.Close(); 60 | } 61 | 62 | return dictionary; 63 | } 64 | 65 | private static async Task WriteLinksAsync(IDictionary zones, ILookup aliases) 66 | { 67 | var cs = _options.ConnectionString; 68 | using (var connection = new SqlConnection(cs)) 69 | { 70 | var command = new SqlCommand("[Tzdb].[AddLink]", connection) { CommandType = CommandType.StoredProcedure }; 71 | command.Parameters.Add("@LinkZoneId", SqlDbType.Int); 72 | command.Parameters.Add("@CanonicalZoneId", SqlDbType.Int); 73 | 74 | await connection.OpenAsync(); 75 | 76 | foreach (var alias in aliases) 77 | { 78 | var canonicalId = zones[alias.Key]; 79 | foreach (var link in alias) 80 | { 81 | command.Parameters[0].Value = zones[link]; 82 | command.Parameters[1].Value = canonicalId; 83 | await command.ExecuteNonQueryAsync(); 84 | } 85 | } 86 | 87 | connection.Close(); 88 | } 89 | } 90 | 91 | private static async Task WriteIntervalsAsync(IDictionary zones, CurrentTzdbProvider tzdb) 92 | { 93 | var currentUtcYear = SystemClock.Instance.Now.InUtc().Year; 94 | var maxYear = currentUtcYear + 5; 95 | var maxInstant = new LocalDate(maxYear + 1, 1, 1).AtMidnight().InUtc().ToInstant(); 96 | 97 | var links = tzdb.Aliases.SelectMany(x => x).OrderBy(x => x).ToList(); 98 | 99 | foreach (var id in tzdb.Ids) 100 | { 101 | // Skip noncanonical zones 102 | if (links.Contains(id)) 103 | continue; 104 | 105 | using (var dt = new DataTable()) 106 | { 107 | dt.Columns.Add("UtcStart", typeof(DateTime)); 108 | dt.Columns.Add("UtcEnd", typeof(DateTime)); 109 | dt.Columns.Add("LocalStart", typeof(DateTime)); 110 | dt.Columns.Add("LocalEnd", typeof(DateTime)); 111 | dt.Columns.Add("OffsetMinutes", typeof(short)); 112 | dt.Columns.Add("Abbreviation", typeof(string)); 113 | 114 | var intervals = tzdb[id].GetZoneIntervals(Instant.MinValue, maxInstant); 115 | foreach (var interval in intervals) 116 | { 117 | 118 | var utcStart = interval.Start == Instant.MinValue 119 | ? DateTime.MinValue 120 | : interval.Start.ToDateTimeUtc(); 121 | 122 | var utcEnd = interval.End == Instant.MaxValue 123 | ? DateTime.MaxValue 124 | : interval.End.ToDateTimeUtc(); 125 | 126 | var localStart = utcStart == DateTime.MinValue 127 | ? DateTime.MinValue 128 | : interval.IsoLocalStart.ToDateTimeUnspecified(); 129 | 130 | var localEnd = utcEnd == DateTime.MaxValue 131 | ? DateTime.MaxValue 132 | : interval.IsoLocalEnd.ToDateTimeUnspecified(); 133 | 134 | 135 | var offsetMinutes = (short)interval.WallOffset.ToTimeSpan().TotalMinutes; 136 | 137 | var abbreviation = interval.Name; 138 | 139 | if (abbreviation.StartsWith("Etc/")) 140 | { 141 | abbreviation = abbreviation.Substring(4); 142 | if (abbreviation.StartsWith("GMT+")) 143 | abbreviation = "GMT-" + abbreviation.Substring(4); 144 | else if (abbreviation.StartsWith("GMT-")) 145 | abbreviation = "GMT+" + abbreviation.Substring(4); 146 | } 147 | 148 | dt.Rows.Add(utcStart, utcEnd, localStart, localEnd, offsetMinutes, abbreviation); 149 | } 150 | 151 | var cs = _options.ConnectionString; 152 | using (var connection = new SqlConnection(cs)) 153 | { 154 | var command = new SqlCommand("[Tzdb].[SetIntervals]", connection) 155 | { 156 | CommandType = CommandType.StoredProcedure 157 | }; 158 | command.Parameters.AddWithValue("@ZoneId", zones[id]); 159 | var tvp = command.Parameters.AddWithValue("@Intervals", dt); 160 | tvp.SqlDbType = SqlDbType.Structured; 161 | tvp.TypeName = "[Tzdb].[IntervalTable]"; 162 | 163 | await connection.OpenAsync(); 164 | await command.ExecuteNonQueryAsync(); 165 | connection.Close(); 166 | } 167 | } 168 | } 169 | } 170 | 171 | private static async Task WriteVersion(string version) 172 | { 173 | var cs = _options.ConnectionString; 174 | using (var connection = new SqlConnection(cs)) 175 | { 176 | var command = new SqlCommand("[Tzdb].[SetVersion]", connection) { CommandType = CommandType.StoredProcedure }; 177 | command.Parameters.AddWithValue("@Version", version); 178 | 179 | await connection.OpenAsync(); 180 | await command.ExecuteNonQueryAsync(); 181 | connection.Close(); 182 | } 183 | } 184 | } 185 | } 186 | -------------------------------------------------------------------------------- /SqlTzLoader/Properties/AssemblyInfo.cs: -------------------------------------------------------------------------------- 1 | using System.Reflection; 2 | using System.Runtime.CompilerServices; 3 | using System.Runtime.InteropServices; 4 | 5 | // General Information about an assembly is controlled through the following 6 | // set of attributes. Change these attribute values to modify the information 7 | // associated with an assembly. 8 | [assembly: AssemblyTitle("SqlTzLoader")] 9 | [assembly: AssemblyDescription("")] 10 | [assembly: AssemblyConfiguration("")] 11 | [assembly: AssemblyCompany("")] 12 | [assembly: AssemblyProduct("SqlTzLoader")] 13 | [assembly: AssemblyCopyright("Copyright © 2015")] 14 | [assembly: AssemblyTrademark("")] 15 | [assembly: AssemblyCulture("")] 16 | 17 | // Setting ComVisible to false makes the types in this assembly not visible 18 | // to COM components. If you need to access a type in this assembly from 19 | // COM, set the ComVisible attribute to true on that type. 20 | [assembly: ComVisible(false)] 21 | 22 | // The following GUID is for the ID of the typelib if this project is exposed to COM 23 | [assembly: Guid("800d6013-2f2d-46f3-b312-cea0550103a1")] 24 | 25 | // Version information for an assembly consists of the following four values: 26 | // 27 | // Major Version 28 | // Minor Version 29 | // Build Number 30 | // Revision 31 | // 32 | // You can specify all the values or you can default the Build and Revision Numbers 33 | // by using the '*' as shown below: 34 | // [assembly: AssemblyVersion("1.0.*")] 35 | [assembly: AssemblyVersion("1.0.0.0")] 36 | [assembly: AssemblyFileVersion("1.0.0.0")] 37 | -------------------------------------------------------------------------------- /SqlTzLoader/SqlTzLoader.csproj: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | Debug 6 | AnyCPU 7 | {1C6E56EA-6FE4-4360-A87E-3B2E7B8ADD5E} 8 | Exe 9 | Properties 10 | SqlTzLoader 11 | SqlTzLoader 12 | v4.5 13 | 512 14 | 15 | 16 | AnyCPU 17 | true 18 | full 19 | false 20 | bin\Debug\ 21 | DEBUG;TRACE 22 | prompt 23 | 4 24 | 25 | 26 | AnyCPU 27 | pdbonly 28 | true 29 | bin\Release\ 30 | TRACE 31 | prompt 32 | 4 33 | 34 | 35 | 36 | ..\packages\CommandLineParser.1.9.71\lib\net45\CommandLine.dll 37 | True 38 | 39 | 40 | ..\packages\NodaTime.1.3.1\lib\net35-Client\NodaTime.dll 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | {b8abb022-9691-469b-b2ae-bcc12f725798} 60 | NodaTime.CurrentTzdbProvider 61 | 62 | 63 | 64 | 71 | -------------------------------------------------------------------------------- /SqlTzLoader/packages.config: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | --------------------------------------------------------------------------------