Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
Author |
Topic |
tech2
Yak Posting Veteran
51 Posts |
Posted - 2014-07-14 : 16:05:45
|
Need to extract only numbers from the three strings. Below is the code I've tryed but it is extracting alpha characters to the letters 'ID'. SQL Server 2012ABC -- Item Order for Custom ID 1234567; Doe, JohnItem Order for Custom ID 7654321; Doe, JaneItem Order for Custom ID 123456; Doe, JackSELECT substring(Field, 1, PATINDEX('%[0-9]%', Field) -1) AS CustomIDWHERE PATINDEX('%[0-9]%', Field) > 0 |
|
James K
Master Smack Fu Yak Hacker
3873 Posts |
Posted - 2014-07-14 : 16:56:11
|
quote: Originally posted by tech2 Need to extract only numbers from the three strings. Below is the code I've tryed but it is extracting alpha characters to the letters 'ID'. SQL Server 2012ABC -- Item Order for Custom ID 1234567; Doe, JohnItem Order for Custom ID 7654321; Doe, JaneItem Order for Custom ID 123456; Doe, JackSELECT substring(Field, 1, PATINDEX('%[0-9]%', Field) -1) AS CustomIDWHERE PATINDEX('%[0-9]%', A.PLNotes) > 0
Is Field and A.PLNotes related? Can you show some examples of the two columns Field and A.PLNotes?If you are trying to extract the numeric portion from the example strings you have shown, something like shown below should work. But, it will work only if there is only one instance of consecutive numeric charactersDECLARE @s VARCHAR(256) = 'Item Order for Custom ID 123456; Doe, Jack';SELECT LEFT(STUFF(@s,1,PATINDEX('%[0-9]%',@s)-1,''),PATINDEX('%[^0-9]%',STUFF(@s,1,PATINDEX('%[0-9]%',@s)-1,''))-1) |
|
|
khtan
In (Som, Ni, Yak)
17689 Posts |
|
tech2
Yak Posting Veteran
51 Posts |
Posted - 2014-07-15 : 08:46:10
|
Sorry James and thanks for the reply. I didn't change 'A.PLNotes' to 'field' when I was modifying my example. I've updated my original post. What I'm trying to accomplish is; to extract only the numeric values from the strings below, it will not be a specific persons name.quote: Originally posted by James K
quote: Originally posted by tech2 Need to extract only numbers from the three strings. Below is the code I've tryed but it is extracting alpha characters to the letters 'ID'. SQL Server 2012ABC -- Item Order for Custom ID 1234567; Doe, JohnItem Order for Custom ID 7654321; Doe, JaneItem Order for Custom ID 123456; Doe, JackSELECT substring(Field, 1, PATINDEX('%[0-9]%', Field) -1) AS CustomIDWHERE PATINDEX('%[0-9]%', Field) > 0
Is Field and A.PLNotes related? Can you show some examples of the two columns Field and A.PLNotes?If you are trying to extract the numeric portion from the example strings you have shown, something like shown below should work. But, it will work only if there is only one instance of consecutive numeric charactersDECLARE @s VARCHAR(256) = 'Item Order for Custom ID 123456; Doe, Jack';SELECT LEFT(STUFF(@s,1,PATINDEX('%[0-9]%',@s)-1,''),PATINDEX('%[^0-9]%',STUFF(@s,1,PATINDEX('%[0-9]%',@s)-1,''))-1)
|
|
|
James K
Master Smack Fu Yak Hacker
3873 Posts |
Posted - 2014-07-15 : 10:49:44
|
You should be able to use the query I posted regardless of the characters/person's name that precede and succeed the numeric portion. |
|
|
madhivanan
Premature Yak Congratulator
22864 Posts |
Posted - 2014-07-16 : 06:57:19
|
All you need to do is just modify your code as James showed youSELECT LEFT(STUFF(Field,1,PATINDEX('%[0-9]%',Field)-1,''),PATINDEX('%[^0-9]%',STUFF(Field,1,PATINDEX('%[0-9]%',Field)-1,''))-1) AS CustomID from your_tableWHERE PATINDEX('%[0-9]%', Field) > 0MadhivananFailing to plan is Planning to fail |
|
|
|
|
|
|
|