SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Function to format a datetime variable by a mask


Function to format a datetime variable by a mask

Author
Message
Colin Frame
Colin Frame
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1109 Visits: 343
Comments posted to this topic are about the item Function to format a datetime variable by a mask

Forum Etiquette: How to post data/code on a forum to get the best help
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
SQLVoila
SQLVoila
SSC-Addicted
SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)SSC-Addicted (461 reputation)

Group: General Forum Members
Points: 461 Visits: 187
Neat but I also use old style CONVERT(). seems simpler and probably more efficient. Just supply the proper [style] code.

/*
http://msdn.microsoft.com/en-us/library/ms187928%28v=sql.105%29.aspx
100 mon dd yyyy hh:miAM (or PM)
101 mm/dd/yyyy
102 yy.mm.dd
103 dd/mm/yyyy
104 dd.mm.yy
105 dd-mm-yy
106 dd mon yy
107 Mon dd, yy
108 hh:mi:ss
109 mon dd yyyy hh:mi:ss:mmmAM (or PM)
110 mm-dd-yy
111 yy/mm/dd
112 yymmdd
113 dd mon yyyy hh:mi:ss:mmm(24h)
114 hh:mi:ss:mmm(24h)
120 yyyy-mm-dd hh:mi:ss(24h)
121 yyyy-mm-dd hh:mi:ss.mmm(24h)
126 yyyy-mm-ddThh:mi:ss.mmm (no spaces)
127 yyyy-mm-ddThh:mi:ss.mmmZ
130 dd mon yyyy hh:mi:ss:mmmAM
131 dd/mm/yy hh:mi:ss:mmmAM
*/
-- CONVERT ( data_type [ ( length ) ] , expression [ , style ] )
SELECT CONVERT(VARCHAR(24),GETDATE(),121)
Colin Frame
Colin Frame
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1109 Visits: 343
Agreed, if you can use one of the standard styles.

The initial triggers for me writing this were a couple of requests that didn't seem to fit in with one of those. Using a mask enables you to define an alternative format e.g. use mask 'YYYYMMDD-hhmi' to get 20131018-1645.

Forum Etiquette: How to post data/code on a forum to get the best help
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
Norbert L. Muth, M.A.
Norbert L. Muth, M.A.
SSC Rookie
SSC Rookie (38 reputation)SSC Rookie (38 reputation)SSC Rookie (38 reputation)SSC Rookie (38 reputation)SSC Rookie (38 reputation)SSC Rookie (38 reputation)SSC Rookie (38 reputation)SSC Rookie (38 reputation)

Group: General Forum Members
Points: 38 Visits: 13
Hallo,

very good function often needed.

German SQLservers need adaptation.
Since Wednesday in German "Mittwoch" gets corrupted by the MI=minute mask, some workarounds are necessary. I added month and day without leading zero.


/*
YYYY - Year, 4 digit
YY - Year, 2 digit
MMMM - Monats-Name
MMM - Monats-Name, erste 3 Buchstaben
MM - Monat 2-stellig, führende 0
XM - Monat ohne führende 0
DDDD - Wochentag
WOTAG- Wochentag
DDD - Wochentag, erste 3 Buchstaben
DD - Tag 2 stellig führende 0
XD - Tag ohne führende 0
hh - Stunde (24 Stunden, 2 stellig, führende 0
mi - Minuten, 2 stellig, führende 0
ss - Sekunden, 2 stellig, führende 0
*/
alter FUNCTION [dbo].[DateFormattedByMask]
(
@InputDate DATETIME,
@Mask NVARCHAR(40)
)
RETURNS VARCHAR(40)
AS
BEGIN

SELECT @Mask = REPLACE(@Mask,'YYYY',DATENAME(YEAR,@InputDate))
SELECT @Mask = REPLACE(@Mask,'YY',RIGHT(DATENAME(YEAR,@InputDate),2))
SELECT @Mask = REPLACE(@Mask,'MMMM', DATENAME(MONTH,@InputDate))
SELECT @Mask = REPLACE(@Mask,'MMM', LEFT(DATENAME(MONTH,@InputDate),3))
SELECT @Mask = REPLACE(@Mask,'MM', RIGHT('0'+CAST(MONTH(@InputDate) AS NVARCHAR(2)),2))
SELECT @Mask = REPLACE(@Mask,'XM', CAST(MONTH(@InputDate) AS NVARCHAR(2)))
SELECT @Mask = REPLACE(@Mask,'DDDD', 'WOTAG')
SELECT @Mask = REPLACE(@Mask,'DDD', LEFT(DATENAME(dw,@InputDate),3))
SELECT @Mask = REPLACE(@Mask,'DD', RIGHT('0'+DATENAME(DAY,@InputDate),2))
SELECT @Mask = REPLACE(@Mask,'XD', DATENAME(DAY,@InputDate))
SELECT @Mask = REPLACE(@Mask,'hh', RIGHT('0'+DATENAME(hh,@InputDate),2))
SELECT @Mask = REPLACE(@Mask,'mi', RIGHT('0'+DATENAME(mi,@InputDate),2))
SELECT @Mask = REPLACE(@Mask,'ss', RIGHT('0'+DATENAME(ss,@InputDate),2))
SELECT @Mask = REPLACE(@Mask,'WOTAG', DATENAME(dw,@InputDate))

RETURN @Mask

END
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)

Group: General Forum Members
Points: 145948 Visits: 22058
Maybe something like this could perform better, based on the following article:
http://www.sqlservercentral.com/articles/T-SQL/91724/
CREATE FUNCTION [dbo].[DateFormattedByMask] 
(
@InputDate DATETIME,
@Mask NVARCHAR(80)
)
RETURNS TABLE
AS
RETURN
(
SELECT Mask = REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(
REPLACE(@Mask,'hh', RIGHT('0'+DATENAME(hh,@InputDate),2))
,'mi', RIGHT('0'+DATENAME(mi,@InputDate),2))
,'ss', RIGHT('0'+DATENAME(ss,@InputDate),2))
,'YYYY',DATENAME(YEAR,@InputDate))
,'YY',RIGHT(DATENAME(YEAR,@InputDate),2))
,'MMMM', DATENAME(MONTH,@InputDate))
,'MMM', LEFT(DATENAME(MONTH,@InputDate),3))
,'MM', RIGHT('0'+CAST(MONTH(@InputDate) AS NVARCHAR(2)),2))
,'DDDD', DATENAME(dw,@InputDate))
,'DDD', LEFT(DATENAME(dw,@InputDate),3))
,'DD', RIGHT('0'+DATENAME(DAY,@InputDate),2))

)
GO


EDIT: format and minute code issues.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Iwas Bornready
Iwas Bornready
SSC Guru
SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)

Group: General Forum Members
Points: 57796 Visits: 886
Thanks for the script. There have been a few of these lately and I had to go back and look yours up.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search