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


Numerical conversion


Numerical conversion

Author
Message
Bollivier
Bollivier
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 7
I need to take numerical data from a CSV file and format it as follows:

Value in File - Converted Value
3 0030
25.75 0258
12 0120
125.8 1258

The converted value must contain 4 numbers, rounded to the nearest 10th, numbers only, no decimal points. I am using SQL Tools on SQL Server 2012 to import the data into a table in the SQL Server, then using t-sql in a stored procedure to convert the data and export the file as a CSV for use in another system.

I am having a very difficult time getting the leading or ending zeros as needed, along with rounding to the nearest 10th.

Thank you in advance for any help you can provide.
HappyGeek
HappyGeek
SSCertifiable
SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)SSCertifiable (6.9K reputation)

Group: General Forum Members
Points: 6915 Visits: 4503
Not sure you are going to achieve that without changing the data type to a character string, having said that something along the lines of the following may help:


DECLARE @Num decimal (6,2) = 3.55

SELECT LEFT('0000', 4 - LEN(CAST((@NUM * 10) as INT))) + CAST ((CAST(ROUND((@NUM * 10), 0) as INT)) as varchar(4)) ConvVal




...
Thom A
Thom A
SSC-Forever
SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)

Group: General Forum Members
Points: 46143 Visits: 15669
Slightly different approach. This also won't fall over if a number is greater than 999:

WITH VTE AS (
SELECT *
FROM (VALUES(3),(25.75),(12),(125.8),(1000),(1857.5)) V(I))
SELECT I,
RIGHT('0000' + CONVERT(varchar(8),CONVERT(int,ROUND(I*10,0))),4) AS LeadingZeros
FROM VTE;





Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)

Group: General Forum Members
Points: 96260 Visits: 21206
A shorter version:
WITH VTE AS (
SELECT *
FROM (VALUES(3),(25.75),(12),(125.8),(1000),(1857.5)) V(I))
SELECT I,
RIGHT( 10000 + CAST(ROUND(I*10, 0) AS int), 4) AS LeadingZeros
FROM VTE;



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
Jack Corbett
  Jack Corbett
SSC Guru
SSC Guru (104K reputation)SSC Guru (104K reputation)SSC Guru (104K reputation)SSC Guru (104K reputation)SSC Guru (104K reputation)SSC Guru (104K reputation)SSC Guru (104K reputation)SSC Guru (104K reputation)

Group: General Forum Members
Points: 104429 Visits: 15047
This is an even simpler option:

WITH VTE AS
(
SELECT
*
FROM
(
VALUES (3),
(25.75),
(12),
(125.8),
(1000),
(1857.5)
) V (I)
)
SELECT VTE.I, FORMAT(I*10, '0000') AS LeadingZeros FROM VTE;




Jack Corbett
Consultant Straight Path Solutions
Dont let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a QuestionHow to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)SSC Guru (96K reputation)

Group: General Forum Members
Points: 96260 Visits: 21206
Jack Corbett - Friday, December 29, 2017 8:47 AM
This is an even simpler option:

WITH VTE AS
(
SELECT
*
FROM
(
VALUES (3),
(25.75),
(12),
(125.8),
(1000),
(1857.5)
) V (I)
)
SELECT VTE.I, FORMAT(I*10, '0000') AS LeadingZeros FROM VTE;


I usually avoid FORMAT due to its fame of being slow.


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
Bollivier
Bollivier
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 7
HappyGeek - Friday, December 29, 2017 1:18 AM
Not sure you are going to achieve that without changing the data type to a character string, having said that something along the lines of the following may help:


DECLARE @Num decimal (6,2) = 3.55

SELECT LEFT('0000', 4 - LEN(CAST((@NUM * 10) as INT))) + CAST ((CAST(ROUND((@NUM * 10), 0) as INT)) as varchar(4)) ConvVal



Thank you, HappyGeek! this worked perfectly. Have a Happy New Year.

Sue_H
Sue_H
SSC-Dedicated
SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)

Group: General Forum Members
Points: 33546 Visits: 9539
Luis Cazares - Friday, December 29, 2017 8:56 AM
Jack Corbett - Friday, December 29, 2017 8:47 AM
This is an even simpler option:

WITH VTE AS
(
SELECT
*
FROM
(
VALUES (3),
(25.75),
(12),
(125.8),
(1000),
(1857.5)
) V (I)
)
SELECT VTE.I, FORMAT(I*10, '0000') AS LeadingZeros FROM VTE;


I usually avoid FORMAT due to its fame of being slow.


I was just comparing the two for that very reason....format version is much slower on execution times as I thought it would be. Quite noticeable with a cold cache even with a small set of data. Keep thinking maybe there is some scenario where it is more useful, isn't so slow but haven't found one yet.

Sue



Thom A
Thom A
SSC-Forever
SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)

Group: General Forum Members
Points: 46143 Visits: 15669
Sue_H - Friday, December 29, 2017 4:30 PM
Luis Cazares - Friday, December 29, 2017 8:56 AM
Jack Corbett - Friday, December 29, 2017 8:47 AM
This is an even simpler option:

WITH VTE AS
(
SELECT
*
FROM
(
VALUES (3),
(25.75),
(12),
(125.8),
(1000),
(1857.5)
) V (I)
)
SELECT VTE.I, FORMAT(I*10, '0000') AS LeadingZeros FROM VTE;


I usually avoid FORMAT due to its fame of being slow.


I was just comparing the two for that very reason....format version is much slower on execution times as I thought it would be. Quite noticeable with a cold cache even with a small set of data. Keep thinking maybe there is some scenario where it is more useful, isn't so slow but haven't found one yet.

Sue


Agreed, I remember about 4 years ago when I got access to FORMAT on 2012, and I was really excited. Started using it, and noticed a significant performance decrease. Couldn't see at all as to why; then someone (here) posted about FORMAT and it's awful performance; i changed the FORMAT back to CONVERT and they query runs beautifully again.

A real shame, as FORMAT is so much easier on the eyes; something that starts with REPLACE(LEFT(CONVERT(varchar(15), and ends with something like ,121),7),'-','') just isn't as easily understood by some.


Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
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