June 27, 2013 at 12:57 pm
Brothers,
I need to parse the first numeric value from a string that usually contains several numerics.
This function works OK when the first number has no decimals ( 1 - returns '500000').
In #2 (naturally!) the result is 0
Can you spare some help?
alter FUNCTION dbo.fnExtractDigits (@inString VARCHAR(8000))
RETURNS VARCHAR(8000) AS
BEGIN
DECLARE @X VARCHAR(100)
Select @X=@inString
Select @X= SubString(@X,PATINDEX('%[0-9]%',@X),Len(@X))
Select @X= SubString(@X,0,PATINDEX('%[^0-9]%',@X))
RETURN @X
END
-- 1. select dbo.fnExtractDigits ('NYSTATIN SUSP 500000 UNIT = 5 ML (1 5 ML CUP)')
-- 2. select dbo.fnExtractDigits ('NYSTATIN SUSP 0.75 UNIT = 5 ML (1 5 ML CUP)')
June 27, 2013 at 1:10 pm
I would recommend NOT doing this as a scalar function. Scalar functions are not good for performance. You can easily leverage the DelimitedSplit8K function for this.
select top 1 *
from dbo.DelimitedSplit8K('NYSTATIN SUSP 500000 UNIT = 5 ML (1 5 ML CUP)', ' ')
where Item not like '%[^0-9.]%'
select top 1 *
from dbo.DelimitedSplit8K('NYSTATIN SUSP 0.75 UNIT = 5 ML (1 5 ML CUP)', ' ')
where Item not like '%[^0-9.]%'
You can find the code the that function by following the link in my signature about splitting strings.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 β Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
June 27, 2013 at 1:11 pm
Sis,
Provided you don't have '.' anywhere except as a decimal separator:
alter FUNCTION dbo.fnExtractDigits (@inString VARCHAR(8000))
RETURNS VARCHAR(8000) AS
BEGIN
DECLARE @X VARCHAR(100)
Select @X=@inString
Select @X= SubString(@X,PATINDEX('%[0-9]%',@X),Len(@X))
Select @X= SubString(@X,0,PATINDEX('%[^.0-9]%',@X))
RETURN @X
END
June 27, 2013 at 1:32 pm
Thanks Sean. Will read (love charts!)
June 27, 2013 at 1:34 pm
Let's take the excellent example from David and turn it into a iTVF instead of a scalar function.
create FUNCTION dbo.fnExtractDigits (@inString VARCHAR(8000))
RETURNS table
return
select SubString(
SubString(@inString, PATINDEX('%[0-9]%', @inString), Len(@inString)), 0,
PATINDEX('%[^.0-9]%', SubString(@inString,PATINDEX('%[0-9]%',@inString),Len(@inString)))) as MyValue
Now we can really leverage some power and performance.
--need to setup our test data
;with myCte(SomeKey, SomeValue) as
(
select 1, 'NYSTATIN SUSP 500000 UNIT = 5 ML (1 5 ML CUP)' union all
select 2, 'NYSTATIN SUSP 0.75 UNIT = 5 ML (1 5 ML CUP)'
)
--now we can retrieve it
select *
from myCte
cross apply dbo.fnExtractDigits(SomeValue) s
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 β Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
June 27, 2013 at 1:37 pm
Dave - thanks, it works -need to play to make sure it's ok in other strings
Thanks
(I can only be your brother, not sister - need to ask dad π
June 27, 2013 at 1:44 pm
Sean has the best idea. His implementation will be far better behaved than the code I posted.
June 27, 2013 at 1:47 pm
Ha! Sean, you elegantly rewrote my function (stollen from somwhere anyway).
I do not think that to use cte in my case is a good idea - I use this function within a select statement from a big table - not sure that cte can be used here
SELECT
Real_Date_Time ChartedAt
,DRUG_INFO_1
,LEFT(drug_info_1,CHARINDEX(CHAR(32),drug_info_1)) Drug
,dbo.fnExtractDigits(DRUG_INFO_1) as DoseOrFirstNumeric
, Coalesce(case charindex('MG', DRUG_INFO_1)
when 0 then null
else 'MG'
end --Mg
,case charindex('GM', DRUG_INFO_1)
when 0 then null
else 'GM'
end --GM
,case charindex('UNIT', DRUG_INFO_1)
when 0 then null
else 'UNITS'
end ----UNITS
)
,ROUTE
,NO_OF_INGREDIENTS
,PMP
,pat_num
,ADMIN_STATUS
FROM MAK_Data.dbo.CHRT_Tran
Where
LEFT(drug_info_1,CHARINDEX(CHAR(32),drug_info_1))
IN
(
'abacavir', 'acyclovir', 'amikacin', 'amoxicillin', 'amoxicillin-clavulanic', 'amphotericin', 'ampicillin',
'ampicillin-sulbactam', 'atazanavir', 'atovaquone', 'azithromycin', 'aztreonam',
'cefazolin', 'cefdinir', 'cefepime', 'cefixime', 'cefotaxime', 'cefotetan',
'cefoxitin', 'cefpodoxime proxetil', 'ceftazidime', 'ceftriaxone', 'cefuroxime',
'cefuroxime axetil', 'cephalexin', 'ciprofloxacin', 'clarithromycin', 'clindamycin',
'colistimethate', 'dapsone', 'daptomycin', 'demeclocycline', 'dicloxacillin', 'doxycycline',
'efavirenz', 'ertapenem', 'erythromycin', 'erythromycin', 'ethambutol', 'fluconazole', 'gentamicin',
'hydroxychloroquine', 'imipenem', 'isoniazid', 'itraconazole', 'ketoconazole', 'lamivudine', 'levofloxacin',
'linezolid', 'meropenem', 'methenamine', 'metronidazole', 'minocycline', 'nafcillin',
'neomycin', 'nevirapine', 'nitrofurantoin', 'nystatin', 'oseltamivir', '
penicillin', 'pentamidine', 'piperacillin-tazobactam (single)', 'pyrazinamide', 'ribavirin',
'rifabutin', 'rifampin', 'ritonavir', 'sulfamethoxazole/trimethoprim', 'sulfasalazine',
'tenofovir', 'terbinafine', 'tetracycline', 'tigecycline', 'tobramycin', 'trimethoprim',
'valacyclovir', 'vancomycin', 'voriconazole'
)
and ROUTE IN ('iv','PO')
AND Real_Date_Time >'6/1/2013'
and ADMIN_STATUS ='admin'
June 27, 2013 at 2:01 pm
valeryk2000 (6/27/2013)
Ha! Sean, you elegantly rewrote my function (stollen from somwhere anyway).I do not think that to use cte in my case is a good idea - I use this function within a select statement from a big table - not sure that cte can be used here
The only reason there is a cte there is for testing. I don't have a table with the values you posted so I just stuck them in a cte. It is merely an example of usage. That could a table, a cte, whatever.
They way you wrote the function and are using it is a scalar function. They are horrible for performance. Look at how I used the iTVF with cross apply instead of calling the function as a column. The performance benefits are HUGE!!!!
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 β Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
June 28, 2013 at 9:18 am
Ok. I'll try it (never tried before)
July 1, 2013 at 8:16 am
Sean, I hate to look stupid - but this is a quality not easy to hide ...
I was not able to use iTVF in my query ... alas ...
July 1, 2013 at 8:21 am
Please post your query and the problem you had so we can help you. π
July 1, 2013 at 8:24 am
valeryk2000 (7/1/2013)
Sean, I hate to look stupid - but this is a quality not easy to hide ...I was not able to use iTVF in my query ... alas ...
I'm sure we can change that...
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
July 1, 2013 at 8:32 am
iTVF - 1:08
Scalar- 2:07
Long live iTVF and Sean!
July 1, 2013 at 8:35 am
valeryk2000 (7/1/2013)
iTVF - 1:08Scalar- 2:07
Long live iTVF and Sean!
ROFL. Glad you got it working. π
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 β Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
Viewing 15 posts - 1 through 15 (of 33 total)
You must be logged in to reply to this topic. Login to reply