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


Can't zero pad a variable


Can't zero pad a variable

Author
Message
ScottPletcher
ScottPletcher
SSC-Dedicated
SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)

Group: General Forum Members
Points: 35097 Visits: 7741
I'd be inclined to just do this:

 
SELECT @RunDay = CONVERT(CHAR(2), SomeDate, 1)
FROM #TestTable;



SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)

Group: General Forum Members
Points: 383922 Visits: 43063
Phil Parkin - Thursday, October 12, 2017 9:04 AM
Jeff Moden - Thursday, October 12, 2017 8:54 AM

Except I goofed. Blush I posted before testing. My method turns out to be the slowest between yours, Luis', and mine.


--DROP TABLE #TestTable
GO
DECLARE @StartDate DATE = '2000' --Inclusive
,@LimitDate DATE = '2017' --Exclusive
;
DECLARE @Days INT = DATEDIFF(dd,@StartDate,@LimitDate)
;
SELECT TOP 1000000
SomeDate = DATEADD(dd,ABS(CHECKSUM(NEWID())%@Days),@StartDate)
INTO #TestTable
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
;
GO
--===== PRECAST METHOD
PRINT '========== PRECAST Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = RIGHT('0' + CAST(DAY(SomeDate) AS VARCHAR(2)), 2)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;
--===== DATENAME METHOD
PRINT '========== DATENAME Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = RIGHT('0'+DATENAME(dd,SomeDate),2)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;
--===== DATENAME METHOD
PRINT '========== MATH OVERRUN Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = RIGHT(100+DAY(SomeDate),2)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;


That's not what I am seeing. On my system (2016 SP1), each method performs almost exactly the same.


Here's the update code to include JustMarie's CASE method and Scott's CONVERT/CHAR(2) method.


DROP TABLE #TestTable
GO
DECLARE @StartDate DATE = '2000' --Inclusive
,@LimitDate DATE = '2017' --Exclusive
;
DECLARE @Days INT = DATEDIFF(dd,@StartDate,@LimitDate)
;
SELECT TOP 1000000
SomeDate = DATEADD(dd,ABS(CHECKSUM(NEWID())%@Days),@StartDate)
INTO #TestTable
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
;
--===== PRECAST METHOD
PRINT '========== PRECAST Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = RIGHT('0' + CAST(DAY(SomeDate) AS VARCHAR(2)), 2)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;
--===== DATENAME METHOD
PRINT '========== DATENAME Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = RIGHT('0'+DATENAME(dd,SomeDate),2)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;
--===== DATENAME METHOD
PRINT '========== MATH OVERRUN Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = RIGHT(100+DAY(SomeDate),2)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;
--===== CASE METHOD
PRINT '========== CASE Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = CASE
WHEN day(SomeDate) < 10
THEN '0' + CAST(DAY(SomeDate) AS VARCHAR(2))
ELSE cast(day(SomeDate) AS VARCHAR(2))
END
FROM #TestTable;
;

GO 3
SET STATISTICS TIME OFF;
--===== CONVERT CHAR(2) METHOD
PRINT '========== CONVERT CHAR(2) Method ==============================================================='
SET STATISTICS TIME ON;
GO
DECLARE @RunDay CHAR(2);
SELECT @RunDay = CONVERT(CHAR(2), SomeDate, 1)
FROM #TestTable;
GO 3
SET STATISTICS TIME OFF;



And, yes, I agree.... they all run in almost the same time. I know we're making million row runs here so a 10 ms difference doesn't matter much but I am seeing the MATH OVERRUN method the Luis posted consistently coming in at about 10ms faster than the rest (about 70ms faster than the CASE method) Are you seeing roughly the same thing?


========== PRECAST Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 333 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 327 ms, elapsed time = 331 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 328 ms, elapsed time = 329 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== DATENAME Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 336 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 328 ms, elapsed time = 333 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 334 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== MATH OVERRUN Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 312 ms, elapsed time = 321 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 328 ms, elapsed time = 320 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 327 ms, elapsed time = 321 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== CASE Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 390 ms, elapsed time = 389 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 375 ms, elapsed time = 388 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 390 ms, elapsed time = 390 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== CONVERT CHAR(2) Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 344 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 344 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 374 ms, elapsed time = 374 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.



--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Phil Parkin
Phil Parkin
SSC Guru
SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)

Group: General Forum Members
Points: 97892 Visits: 22006
Jeff Moden - Thursday, October 12, 2017 11:41 PM
Are you seeing roughly the same thing?

The results I see follow a slightly different pattern. The CASE version is the slowest (and most variable), but the MATH OVERRUN method performs little differently from the remainder.


========== PRECAST Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 1 ms.

SQL Server Execution Times:
CPU time = 360 ms, elapsed time = 357 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 359 ms, elapsed time = 361 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 359 ms, elapsed time = 360 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== DATENAME Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 360 ms, elapsed time = 356 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 359 ms, elapsed time = 358 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 359 ms, elapsed time = 357 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== MATH OVERRUN Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 1 ms.

SQL Server Execution Times:
CPU time = 360 ms, elapsed time = 359 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 359 ms, elapsed time = 372 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 360 ms, elapsed time = 363 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== CASE Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 1 ms.

SQL Server Execution Times:
CPU time = 468 ms, elapsed time = 482 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 438 ms, elapsed time = 442 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 453 ms, elapsed time = 448 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.
========== CONVERT CHAR(2) Method ===============================================================
Beginning execution loop
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 349 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 360 ms, elapsed time = 363 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 343 ms, elapsed time = 352 ms.
Batch execution completed 3 times.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.



Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)SSC Guru (383K reputation)

Group: General Forum Members
Points: 383922 Visits: 43063
Thanks, Phil. Good to see mostly consistency between disparate machines on these.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Avi1
Avi1
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1190 Visits: 463
I tested the scripts in one of dev box in SQL2016. the results are below. Each scripts ran 100 times (at 2 different times)
Included the method suggested by Scott Pletcher
CONVERT(CHAR(2), SomeDate, 1)

Run#1
Method AvgTime(ms)
PRECAST Method 553.07
DATENAME Method 518.48
MATH OVERRUN Method 526.75
ScottPletcher Method 483.83

Ru#2
PRECAST Method 565.5
DATENAME Method 515.25
MATH OVERRUN Method 526.97
ScottPletcher Method 501.11
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (73K reputation)SSC Guru (73K reputation)SSC Guru (73K reputation)SSC Guru (73K reputation)SSC Guru (73K reputation)SSC Guru (73K reputation)SSC Guru (73K reputation)SSC Guru (73K reputation)

Group: General Forum Members
Points: 73602 Visits: 20514
Avi1 - Friday, October 13, 2017 12:40 PM
I tested the scripts in one of dev box in SQL2016. the results are below. Each scripts ran 100 times (at 2 different times)
Included the method suggested by Scott Pletcher
CONVERT(CHAR(2), SomeDate, 1)

Run#1
Method AvgTime(ms)
PRECAST Method 553.07
DATENAME Method 518.48
MATH OVERRUN Method 526.75
ScottPletcher Method 483.83

Ru#2
PRECAST Method 565.5
DATENAME Method 515.25
MATH OVERRUN Method 526.97
ScottPletcher Method 501.11


Sure, it can be faster. Are you sure that it's correct?


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
Avi1
Avi1
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1190 Visits: 463
Luis Cazares - Friday, October 13, 2017 1:53 PM
Avi1 - Friday, October 13, 2017 12:40 PM
I tested the scripts in one of dev box in SQL2016. the results are below. Each scripts ran 100 times (at 2 different times)
Included the method suggested by Scott Pletcher
CONVERT(CHAR(2), SomeDate, 1)

Run#1
Method AvgTime(ms)
PRECAST Method 553.07
DATENAME Method 518.48
MATH OVERRUN Method 526.75
ScottPletcher Method 483.83

Ru#2
PRECAST Method 565.5
DATENAME Method 515.25
MATH OVERRUN Method 526.97
ScottPletcher Method 501.11


Sure, it can be faster. Are you sure that it's correct?

Yes, ran against the sample data, and the result was correct

ScottPletcher
ScottPletcher
SSC-Dedicated
SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)

Group: General Forum Members
Points: 35097 Visits: 7741
Luis Cazares - Friday, October 13, 2017 1:53 PM
Avi1 - Friday, October 13, 2017 12:40 PM
I tested the scripts in one of dev box in SQL2016. the results are below. Each scripts ran 100 times (at 2 different times)
Included the method suggested by Scott Pletcher
CONVERT(CHAR(2), SomeDate, 1)

Run#1
Method AvgTime(ms)
PRECAST Method 553.07
DATENAME Method 518.48
MATH OVERRUN Method 526.75
ScottPletcher Method 483.83

Ru#2
PRECAST Method 565.5
DATENAME Method 515.25
MATH OVERRUN Method 526.97
ScottPletcher Method 501.11


Sure, it can be faster. Are you sure that it's correct?

Yeah, should be Day instead of Month, but that's extremely easy to fix: just use code 3 instead of 1:

CONVERT(CHAR(2), SomeDate, 3)

I'd avoid the other method here just because it's so obscure and uncommon. It's very common to convert a date to char, but extraordinarily uncommon to add 100 to the days of a month(!). It'd have to perform significantly better for me to even consider such a trick. [Sure Celko uses 00 as a day,but even he doesn't add 100 to it Laugh.]


SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
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