Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««1234»»»

concatenate with leading zeros Expand / Collapse
Author
Message
Posted Monday, September 9, 2013 10:38 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
Jeff Moden (9/9/2013)
dwain.c (9/9/2013)
At the risk of being called a contrarian, this can be done without using RIGHT:

WITH SampleData (C1, C2) AS (
SELECT 1234, 1
UNION ALL SELECT 12345, 11
UNION ALL SELECT 123456, 111)
SELECT C1, C2
,STUFF(C1, 1, 0, REPLICATE('0',6-LEN(C1)))+STUFF(C2, 1, 0, REPLICATE('0',3-LEN(C2)))
FROM SampleData;




Perhaps RIGHT is the right way to go though it does take a lot of rows to make a difference.

--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate the test table on-the-fly.
SELECT TOP 1000000
C1 = ABS(CHECKSUM(NEWID()))%1000000
,C2 = ABS(CHECKSUM(NEWID()))%1000
INTO #TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
--===== Create a target variable that will take the display time out of the picture.
DECLARE @BitBucket CHAR(9);

PRINT '========== Traditional RIGHT+RIGHT Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000'+CAST(C1 AS VARCHAR(6)),6) + RIGHT('000'+CAST(C1 AS VARCHAR(3)),3)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Double STUFF Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = STUFF(C1, 1, 0, REPLICATE('0',6-LEN(C1)))+STUFF(C2, 1, 0, REPLICATE('0',3-LEN(C2)))
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Integer Math RIGHT(RIGHT) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000000'+RIGHT(C1*1000+C2,9),9)
FROM #TestTable;
SET STATISTICS TIME OFF;


Results:

(1000000 row(s) affected)
========== Traditional RIGHT+RIGHT Method ==========

SQL Server Execution Times:
CPU time = 499 ms, elapsed time = 496 ms.
========== Double STUFF Method ==========

SQL Server Execution Times:
CPU time = 702 ms, elapsed time = 697 ms.
========== Integer Math RIGHT(RIGHT) Method ==========

SQL Server Execution Times:
CPU time = 452 ms, elapsed time = 458 ms.



Indeed, perhaps your right but two RIGHTs don't make a wrong!

  PRINT '========== Another Integer Math Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(1000000000 + C1*1000 + C2, 9)
FROM #TestTable;
SET STATISTICS TIME OFF;


Latest results:

========== Traditional RIGHT+RIGHT Method ==========

SQL Server Execution Times:
CPU time = 593 ms, elapsed time = 593 ms.
========== Double STUFF Method ==========

SQL Server Execution Times:
CPU time = 936 ms, elapsed time = 938 ms.
========== Integer Math RIGHT(RIGHT) Method ==========

SQL Server Execution Times:
CPU time = 437 ms, elapsed time = 438 ms.
========== Another Integer Math Method ==========

SQL Server Execution Times:
CPU time = 390 ms, elapsed time = 390 ms.





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1492980
Posted Monday, September 9, 2013 10:51 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 8:33 AM
Points: 36,958, Visits: 31,465
In the interest of science...
--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate the test table on-the-fly.
SELECT TOP 1000000
C1 = ABS(CHECKSUM(NEWID()))%1000000
,C2 = ABS(CHECKSUM(NEWID()))%1000
INTO #TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
--===== Create a target variable that will take the display time out of the picture.
DECLARE @BitBucket CHAR(9);

PRINT '========== Traditional RIGHT+RIGHT Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000'+CAST(C1 AS VARCHAR(6)),6) + RIGHT('000'+CAST(C1 AS VARCHAR(3)),3)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Less Traditional RIGHT+RIGHT Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(REPLICATE('0',6)+CAST(C1 AS VARCHAR(6)),6) + RIGHT(REPLICATE('0',3)+CAST(C1 AS VARCHAR(3)),3)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Double STUFF Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = STUFF(C1, 1, 0, REPLICATE('0',6-LEN(C1)))+STUFF(C2, 1, 0, REPLICATE('0',3-LEN(C2)))
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Integer Math RIGHT(RIGHT) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000000'+RIGHT(C1*1000+C2,9),9)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Integer Math RIGHT(RIGHT) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000000'+RIGHT(C1*1000+C2,9),9)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Integer Math RIGHT(CAST) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000000'+CAST(C1*1000+C2 AS VARCHAR(9)),9)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== REPLACE(STR) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = REPLACE(STR(C1*1000+C2,9),' ','0')
FROM #TestTable;
SET STATISTICS TIME OFF;


Results:
========== Traditional RIGHT+RIGHT Method ==========

SQL Server Execution Times:
CPU time = 515 ms, elapsed time = 505 ms.
========== Less Traditional RIGHT+RIGHT Method ==========

SQL Server Execution Times:
CPU time = 546 ms, elapsed time = 547 ms.
========== Double STUFF Method ==========

SQL Server Execution Times:
CPU time = 718 ms, elapsed time = 718 ms.
========== Integer Math RIGHT(RIGHT) Method ==========

SQL Server Execution Times:
CPU time = 452 ms, elapsed time = 456 ms.
========== Integer Math RIGHT(RIGHT) Method ==========

SQL Server Execution Times:
CPU time = 452 ms, elapsed time = 457 ms.
========== Integer Math RIGHT(CAST) Method ==========

SQL Server Execution Times:
CPU time = 390 ms, elapsed time = 389 ms.

========== REPLACE(STR) Method ==========

SQL Server Execution Times:
CPU time = 1482 ms, elapsed time = 1472 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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1492982
Posted Monday, September 9, 2013 11:01 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
Mine seems to have gotten lost in the shuffle there in your last test harness, but I can see what you've done. Results look pretty close.

For some reason, I'm always forgetting those integer math approaches, or at least they're not the first thing that snaps into my brain.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1492983
Posted Monday, September 9, 2013 11:08 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 8:33 AM
Points: 36,958, Visits: 31,465
The results are, indeed, pretty close especially considering the number of rows. However, just imagine if you could make all of your code run twice as fast. "Mind the pennies and the dollars take care of themselves."

--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1492984
Posted Monday, September 9, 2013 11:12 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
Jeff Moden (9/9/2013)
The results are, indeed, pretty close especially considering the number of rows. However, just imagine if you could make all of your code run twice as fast. "Mind the pennies and the dollars take care of themselves."


I'm always imagining that, but the imagineering is often easier than the engineering.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1492985
Posted Monday, September 9, 2013 11:29 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
As you said, in the interests of science, I removed the duplicate scenario in your test harness, added back my original at the end and included an extra one based on that good old binary collation within REPLACE.

Test harness:

--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate the test table on-the-fly.
SELECT TOP 1000000
C1 = ABS(CHECKSUM(NEWID()))%1000000
,C2 = ABS(CHECKSUM(NEWID()))%1000
INTO #TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
--===== Create a target variable that will take the display time out of the picture.
DECLARE @BitBucket CHAR(9);

PRINT '========== Traditional RIGHT+RIGHT Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000'+CAST(C1 AS VARCHAR(6)),6) + RIGHT('000'+CAST(C1 AS VARCHAR(3)),3)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Less Traditional RIGHT+RIGHT Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(REPLICATE('0',6)+CAST(C1 AS VARCHAR(6)),6) + RIGHT(REPLICATE('0',3)+CAST(C1 AS VARCHAR(3)),3)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Double STUFF Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = STUFF(C1, 1, 0, REPLICATE('0',6-LEN(C1)))+STUFF(C2, 1, 0, REPLICATE('0',3-LEN(C2)))
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Integer Math RIGHT(RIGHT) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000000'+RIGHT(C1*1000+C2,9),9)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== Integer Math RIGHT(CAST) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT('000000000'+CAST(C1*1000+C2 AS VARCHAR(9)),9)
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== REPLACE(STR) Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = REPLACE(STR(C1*1000+C2,9),' ','0')
FROM #TestTable;
SET STATISTICS TIME OFF;

PRINT '========== REPLACE(STR) Method with BIN collation =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = REPLACE(STR(C1*1000+C2,9) COLLATE Latin1_General_BIN,' ','0')
FROM #TestTable;
SET STATISTICS TIME OFF;
PRINT '========== Another Integer Math Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(1000000000 + C1*1000 + C2, 9)
FROM #TestTable;
SET STATISTICS TIME OFF;


Test results:

========== Traditional RIGHT+RIGHT Method ==========

SQL Server Execution Times:
CPU time = 577 ms, elapsed time = 614 ms.
========== Less Traditional RIGHT+RIGHT Method ==========

SQL Server Execution Times:
CPU time = 593 ms, elapsed time = 608 ms.
========== Double STUFF Method ==========

SQL Server Execution Times:
CPU time = 889 ms, elapsed time = 890 ms.
========== Integer Math RIGHT(RIGHT) Method ==========

SQL Server Execution Times:
CPU time = 437 ms, elapsed time = 432 ms.
========== Integer Math RIGHT(CAST) Method ==========

SQL Server Execution Times:
CPU time = 405 ms, elapsed time = 400 ms.
========== REPLACE(STR) Method ==========

SQL Server Execution Times:
CPU time = 2637 ms, elapsed time = 2660 ms.
========== REPLACE(STR) Method with BIN collation ==========

SQL Server Execution Times:
CPU time = 1451 ms, elapsed time = 1441 ms.
========== Another Integer Math Method ==========

SQL Server Execution Times:
CPU time = 390 ms, elapsed time = 387 ms.



Despite what some pundits may disclaim, competition is a really good thing to help improve people's code and coding style.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1492987
Posted Monday, September 9, 2013 11:40 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 8:33 AM
Points: 36,958, Visits: 31,465
dwain.c (9/9/2013)

  PRINT '========== Another Integer Math Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(1000000000 + C1*1000 + C2, 9)
FROM #TestTable;
SET STATISTICS TIME OFF;




Oh, now that's just bloody clever. You stayed away from anything character based until "display time". Well done!


--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1492992
Posted Monday, September 9, 2013 11:43 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
Jeff Moden (9/9/2013)
  PRINT '========== Another Integer Math Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(1000000000 + C1*1000 + C2, 9)
FROM #TestTable;
SET STATISTICS TIME OFF;


Oh, now that's just bloody clever. You stayed away from anything character based until "display time". Well done!


Couldn't have done it without you actually. Your first post gave me the inspiration.

[face-to-palm] Why didn't I think of it initially!



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1492993
Posted Tuesday, September 10, 2013 1:26 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:50 AM
Points: 7,191, Visits: 13,645
dwain.c (9/9/2013)
Jeff Moden (9/9/2013)
  PRINT '========== Another Integer Math Method =========='
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(1000000000 + C1*1000 + C2, 9)
FROM #TestTable;
SET STATISTICS TIME OFF;


Oh, now that's just bloody clever. You stayed away from anything character based until "display time". Well done!


Couldn't have done it without you actually. Your first post gave me the inspiration.

[face-to-palm] Why didn't I think of it initially!


Nice one, Dwain. Tight little examples like this make concepts easier to remember.


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1493019
Posted Tuesday, September 10, 2013 6:43 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, July 28, 2014 8:23 AM
Points: 10, Visits: 213
Here is another variation on the math method that my testing says is a little faster:

DECLARE @Billion INT;
SET @Billion = 1000000000;
SET STATISTICS TIME ON;
SELECT @BitBucket = RIGHT(@Billion+(C1*1000)+C2,9)
FROM #TestTable;
SET STATISTICS TIME OFF;
Post #1493142
« Prev Topic | Next Topic »

Add to briefcase ««1234»»»

Permissions Expand / Collapse