August 14, 2012 at 12:56 am
Format number thousands separator with point
Hi there, I need your help.
I have this number in my database output result of query:
1013473
I need this output: 1.013.473
Can you help me?
Thanks in advance.
August 14, 2012 at 1:33 am
cms9651 (8/14/2012)
Format number thousands separator with pointHi there, I need your help.
I have this number in my database output result of query:
1013473
I need this output: 1.013.473
Can you help me?
Thanks in advance.
You should probably be doing this in the presentation layer, rather than the database. But, here's one way you could do it: -
SELECT PARSENAME(CONVERT(VARCHAR(19), CONVERT(MONEY,randomBigInt), 1), 2)
FROM #testEnvironment;
How about performance?
BEGIN TRAN
SET NOCOUNT ON;
--== SOME SAMPLE DATA ==--
IF object_id('tempdb..#testEnvironment') IS NOT NULL
BEGIN
DROP TABLE #testEnvironment;
END;
--1,000,000 Random rows of data
SELECT TOP 1000000 IDENTITY(INT,1,1) AS ID,
ABS(CHECKSUM(NEWID())) AS randomBigInt
INTO #testEnvironment
FROM master.dbo.syscolumns sc1, master.dbo.syscolumns sc2, master.dbo.syscolumns sc3;
--Holder variable to take display time out of the equation
DECLARE @HOLDER VARCHAR(19);
PRINT REPLICATE('=',80);
PRINT 'PARSENAME / CONVERT MONEY';
PRINT REPLICATE('=',80);
SET STATISTICS IO, TIME ON;
SELECT @HOLDER = PARSENAME(CONVERT(VARCHAR(19), CONVERT(MONEY,randomBigInt), 1), 2)
FROM #testEnvironment;
SET STATISTICS IO, TIME OFF;
ROLLBACK
================================================================================
PARSENAME / CONVERT MONEY
================================================================================
Table '#testEnvironment'. Scan count 1, logical reads 2102, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 609 ms, elapsed time = 610 ms.
Sorry, I've just noticed that you asked for dot separators not commas.
Instead, use this: -
SELECT REPLACE(PARSENAME(CONVERT(VARCHAR(19), CONVERT(MONEY,randomBigInt), 1), 2) COLLATE Latin1_General_BIN2, ',', '.')
FROM #testEnvironment;
Performance goes down over the commas because of the additional replace: -
BEGIN TRAN
SET NOCOUNT ON;
--== SOME SAMPLE DATA ==--
IF object_id('tempdb..#testEnvironment') IS NOT NULL
BEGIN
DROP TABLE #testEnvironment;
END;
--1,000,000 Random rows of data
SELECT TOP 1000000 IDENTITY(INT,1,1) AS ID,
ABS(CHECKSUM(NEWID())) AS randomBigInt
INTO #testEnvironment
FROM master.dbo.syscolumns sc1, master.dbo.syscolumns sc2, master.dbo.syscolumns sc3;
--Holder variable to take display time out of the equation
DECLARE @HOLDER VARCHAR(19);
PRINT REPLICATE('=',80);
PRINT 'REPLACE / PARSENAME / CONVERT MONEY';
PRINT REPLICATE('=',80);
SET STATISTICS IO, TIME ON;
SELECT @HOLDER = REPLACE(PARSENAME(CONVERT(VARCHAR(19), CONVERT(MONEY,randomBigInt), 1), 2) COLLATE Latin1_General_BIN2, ',', '.')
FROM #testEnvironment;
SET STATISTICS IO, TIME OFF;
ROLLBACK
================================================================================
REPLACE / PARSENAME / CONVERT MONEY
================================================================================
Table '#testEnvironment'. Scan count 1, logical reads 2102, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 985 ms, elapsed time = 987 ms.
August 14, 2012 at 11:33 am
excellent, thank you
August 14, 2012 at 12:05 pm
Sorry, I've just noticed that you asked for dot separators not commas
Wouldn't this be defined by the regional settings? If the settings affect the format for money, this can result problematic.
August 14, 2012 at 7:28 pm
Cadavre +1 for a very clever solution.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 15, 2012 at 5:00 am
Luis Cazares (8/14/2012)
Wouldn't this be defined by the regional settings? If the settings affect the format for money, this can result problematic.
I don't believe so. Normally I'd just test it, but I'm having a bit of a busy day.
dwain.c (8/14/2012)
Cadavre +1 for a very clever solution.
Thank you. I was hoping someone would have a method that would blow it away (the performance isn't great) 🙂
August 15, 2012 at 5:33 am
Cadavre (8/15/2012)
dwain.c (8/14/2012)
Cadavre +1 for a very clever solution.Thank you. I was hoping someone would have a method that would blow it away (the performance isn't great) 🙂
Don't think for one minute I didn't try! 🙂
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 16, 2012 at 5:55 pm
Hi,
This is not as nice as cadavre, but is different.
DECLARE @Number AS BIGINT; SET @Number = 65432121235
SELECT ISNULL( CONVERT(VARCHAR,NULLIF(@Number/1000000000 % 1000,0))+'.','') +
ISNULL( CONVERT(VARCHAR,NULLIF(@Number/1000000 % 1000,0))+'.','') +
ISNULL( CONVERT(VARCHAR,NULLIF(@Number/1000 % 1000,0))+'.','') +
CONVERT(VARCHAR,NULLIF(@Number%1000,0))
August 16, 2012 at 6:19 pm
Hm, neat. I see what you did there. The Parsename had me all sorts of scragged up until I broke it down and figured out what you were avoiding with it. Neat trick. Not much else you can do with that for speed, though, you're dealing with significant string manipulation at that point, not numerics.
For regional settings, afaik and what I can find in BoL, region will affect your default collations and default datetime components, but not directly selected money styles.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
August 16, 2012 at 6:24 pm
As a great Jedi once said: "Do, or do not, there is no try..."
SET NOCOUNT ON;
--== SOME SAMPLE DATA ==--
IF object_id('tempdb..#testEnvironment') IS NOT NULL
BEGIN
DROP TABLE #testEnvironment;
END;
--1,000,000 Random rows of data
SELECT TOP 1000000 IDENTITY(INT,1,1) AS ID,
ABS(CHECKSUM(NEWID())) AS randomBigInt
INTO #testEnvironment
FROM master.dbo.syscolumns sc1, master.dbo.syscolumns sc2, master.dbo.syscolumns sc3;
--Holder variable to take display time out of the equation
DECLARE @HOLDER VARCHAR(19);
PRINT REPLICATE('=',80);
PRINT 'REPLACE / PARSENAME / CONVERT MONEY';
PRINT REPLICATE('=',80);
SET STATISTICS IO, TIME ON;
SELECT @HOLDER = REPLACE(PARSENAME(CONVERT(VARCHAR(19), CONVERT(MONEY,randomBigInt), 1), 2) COLLATE Latin1_General_BIN2, ',', '.')
FROM #testEnvironment;
SET STATISTICS IO, TIME OFF;
PRINT REPLICATE('=',80);
PRINT 'Dwain.C';
PRINT REPLICATE('=',80);
SET STATISTICS IO, TIME ON;
SELECT @HOLDER = CASE WHEN randomBigInt > 999999999 THEN RIGHT(randomBigInt/1000000000, 3) + '.' ELSE '' END +
CASE WHEN randomBigInt > 999999 THEN RIGHT(randomBigInt/1000000, 3) + '.' ELSE '' END +
CASE WHEN randomBigInt > 999 THEN RIGHT(randomBigInt/1000, 3) + '.' ELSE '' END +
RIGHT(randomBigInt, 3)
FROM #testEnvironment;
SET STATISTICS IO, TIME OFF;
PRINT REPLICATE('=',80);
PRINT 'Adrian.Facio';
PRINT REPLICATE('=',80);
SET STATISTICS IO, TIME ON;
SELECT @HOLDER = ISNULL( CONVERT(VARCHAR,NULLIF(randomBigInt/1000000000 % 1000,0))+'.','') +
ISNULL( CONVERT(VARCHAR,NULLIF(randomBigInt/1000000 % 1000,0))+'.','') +
ISNULL( CONVERT(VARCHAR,NULLIF(randomBigInt/1000 % 1000,0))+'.','') +
CONVERT(VARCHAR,NULLIF(randomBigInt%1000,0))
FROM #testEnvironment;
SET STATISTICS IO, TIME OFF;
DROP TABLE #testEnvironment
Ugly as mine is, I think it edges out Cadavre's solution slightly in the performance race.
================================================================================
REPLACE / PARSENAME / CONVERT MONEY
================================================================================
Table '#testEnvironment____________________________________________________________________________________________________0000000000A4'. Scan count 1, logical reads 2102, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 1404 ms, elapsed time = 1411 ms.
================================================================================
Dwain.C
================================================================================
Table '#testEnvironment____________________________________________________________________________________________________0000000000A4'. Scan count 1, logical reads 2102, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 1279 ms, elapsed time = 1310 ms.
================================================================================
Adrian.Facio
================================================================================
Table '#testEnvironment____________________________________________________________________________________________________0000000000A4'. Scan count 1, logical reads 2102, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 1794 ms, elapsed time = 1818 ms.
Still ain't real fast though. I'm thinking it should perform in under 1000ms.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply