• Sean Lange (4/2/2013)


    The biggest take away from this is that you should ALWAYS use the datetime datatype for datetime values. Using a varchar for dates just doesn't make sense. You don't store numbers in a varchar, I don't know why so many people store dates in a varchar.

    That's true when STORING a date after it's been validated. But there have been many times when I had "dates" as input from a spreadsheet import or a form post that are strings. When using a "date" in a parameter, unless the source is a datetime datatyped column I set the parameter datatype to varchar or nvarchar. I really don't trust my inputs so I run the alleged "date" through a validator function that will reject non-dates and convert those that pass to whatever datetime datatype I need. This keeps non-date "dates" from causing run time errors.

    Here's a date validation procedure I use. I wish I could turn it into a TVF, but the procedure depends on TRY...CATCH and that won't work. This is the surest way I've found to validate dates: by trying to convert them to a date datatype and rejecting those "dates" that won't convert. Depending on the desired date format (DMY vs YMD for example) a particular date might pass or fail this test while ISDATE might return true and give a false positive. In this procedure I'm using SMALLDATETIME as my conversion type and that can be changed to whatever datatype is required.

    CREATE PROCEDURE [dbo].[IsValidDate]

    @sDate VARCHAR(50)

    ,@sDateFormat CHAR(3) = 'DMY' -- MDY, DMY, YMD, YDM, MYD, DYM

    AS

    BEGIN

    SET NOCOUNT ON

    SET DATEFORMAT @sDateFormat

    DECLARE

    @dStdDate SMALLDATETIME

    ,@dUMCDate DATETIMEOFFSET

    ,@bIsValidUMCDate BIT

    ,@bIsValidDate BIT

    SET @dStdDate = NULL

    SET @dUMCDate = NULL

    /* Check to see if this is a valid UMC date */

    IF OBJECT_ID('tempdb..#CheckUMCDate') IS NOT NULL

    DROP TABLE #CheckUMCDate

    CREATE TABLE #CheckUMCDate (

    [ID] INT IDENTITY(1,1) NOT NULL,

    [InputDate] VARCHAR(50) NULL,

    [ConvertedDate] VARCHAR(50) NULL,

    [IsValidUMCDate] BIT NULL

    PRIMARY KEY (ID))

    BEGIN TRY

    INSERT INTO #CheckUMCDate

    EXEC dbo.IsValidUMCDate @sDate

    END TRY

    BEGIN CATCH

    INSERT INTO #CheckUMCDate

    SELECT

    @sDate AS InputDate

    ,NULL ConvertedDate

    ,0 AS IsValidUMCDate

    END CATCH

    SELECT

    @dUMCDate = ConvertedDate

    ,@bIsValidUMCDate = IsValidUMCDate

    FROM

    #CheckUMCDate

    /* Check using regular SMALLDATETIME datatype */

    BEGIN TRY

    SET @dStdDate = CONVERT(SMALLDATETIME,@sDate)

    SET @bIsValidDate = 1

    END TRY

    BEGIN CATCH

    SET @bIsValidDate = 0

    SET @dStdDate = NULL

    END CATCH

    SELECT

    @sDate AS InputDate

    ,@dStdDate AS StdDate

    ,@bIsValidDate AS IsValidDate

    ,@dUMCDate AS UMCDate

    ,@bIsValidUMCDate AS IsValidUMCDate

    /*

    EXAMPLES:

    EXEC dbo.IsValidDate '01-07-2001' -- Valid date

    EXEC dbo.IsValidDate '1/7/2001' -- Valid date

    EXEC dbo.IsValidDate '07-01-2001' -- Valid date

    EXEC dbo.IsValidDate '7/1/2001' -- Valid date

    EXEC dbo.IsValidDate '29-12-2013','DMY' -- Valid date in DMY format

    EXEC dbo.IsValidDate '29-12-2013','MDY' -- Invalid date in MDY format

    EXEC dbo.IsValidDate '32-12-2013' -- ERROR: Date out of range

    EXEC dbo.IsValidDate '29-02-2013' -- ERROR: Not a leap year

    EXEC dbo.IsValidDate 'xyz' -- ERROR: Invalid date

    EXEC dbo.IsValidDate '1234' -- Invalid std date/valid umc date

    EXEC dbo.IsValidDate '2013-01-08 15:44:12' -- Valid date

    EXEC dbo.IsValidDate '2013-01-08 15:44:12.000' -- Valid date

    EXEC dbo.IsValidDate '2013-01-08 15:44:12.208' -- Valid date

    EXEC dbo.IsValidDate '2013-01-08 15:44:12.2081606' -- Invalid std date/valid umc date

    EXEC dbo.IsValidDate '2013-01-08 15:44:12.2081606 +05:30' -- Invalid std date/valid umc date

    */

    END