December 10, 2015 at 6:02 am
Hi,
how extract values from expressions
declare @testdata table(expression varchar(500))
insert into @testdata values('[w1+w2+w3/5]'),('[(w1+w2+w3)/5]'),('[(w4-w5*w6)/5]')
select * from @testdata
Result like
w1
w2
w3
w1
w2
w3
w4
w5
w6
--chalam
December 10, 2015 at 6:47 am
Search on the forum for:
DelimitedSplit8K
Recipe:
Replace all chars/strings which are not a value with an 'X', or another character which is not used.
Use the DelimitedSplit8K function to split the string into the seperate parts.
Do any further filtering.
I use a self build Replace2 function instead of a number of replaces.
Here the number 5 is not filtered out, because I do not know what is to be considered a value and what is not. So this is not complete but can be used as a start.
Tell us if this does help.
Ben
Edit.
Add the new characters and the replacement for this to the set of chars to replace.
('[(w4-w5*w6)/5]') so ad a replace for the '*' as wel.
update @testdata set expression = master.dbo.Replace2(expression,'[|+|/|*|-|]|(|)|XXXX|XX|XX|','X|X|X|X|X|X|X|X|X|X|X|X')
declare @testdata table(expression varchar(500))
insert into @testdata values('[w1+w2+w3/5]'),('[(w1+w2+w3)/5]')
update @testdata set expression = master.dbo.Replace2(expression,'[|+|/|]|(|)|XXXX|XX|XX|','X|X|X|X|X|X|X|X|X|X')
-- Or use the replace function to do this for each character/string independend.
select * from @testdata
SELECT item,* FROM @testdata
CROSS APPLY DelimitedSplit8K(expression, 'x') a
WHERE Item <> ''
-- OR
SELECT distinct item FROM @testdata
CROSS APPLY DelimitedSplit8K(expression, 'x') a
WHERE Item <> ''
December 10, 2015 at 8:27 am
The DelimitedSplit8K is a great tool, but you might find useful to use another tool to reduce the code.
This tool is the Pattern Splitter created by Chris Morris and posted by Dwain Camps in here: http://www.sqlservercentral.com/articles/String+Manipulation/94365/
Then, the code might look like this:
declare @testdata table(expression varchar(500))
insert into @testdata values('[w1+w2+w3/5]'),('[(w1+w2+w3)/5]'),('[(w4-w5*w6)/5]')
SELECT expression, Item
FROM @testdata
--Uses REPLACE because the splitter doesn't seem to be escaping the right square bracket correctly
CROSS APPLY dbo.PatternSplitCM(REPLACE( expression, ']', '['), '%[-()[+=*/]%')
WHERE Matched = 0 --Discard operators
AND Item LIKE '%[^0-9]%' --Discard literals
December 10, 2015 at 10:57 am
Another way, using delimitedsplit8K and patreplace8k (both referenced in my signature) would be like so:
declare @testdata table(expression varchar(500))
insert into @testdata
SELECT expression FROM
(values('[w1+w2+w3/5]'),('[(w1+w2+w3)/5]'),('[(w4-w5*w6)/5]')) x(expression)
select expression, Item
from @testdata
CROSS APPLY dbo.Patreplace8K(expression,'[^w0-9]','|')
CROSS APPLY dbo.delimitedsplit8k(newstring,'|')
WHERE Item LIKE 'w[0-9]%';
-- Itzik Ben-Gan 2001
December 10, 2015 at 7:50 pm
If it's always a "w" followed by a digit or digits, perhaps just this?!:
declare @testdata table(expression varchar(500))
insert into @testdata values('[w1+w2+w3/5]'),('[(w1+w2+w3)/5]'),('[(w4-w5*w6)/5]')
insert into @testdata values('w1')
insert into @testdata values('2w3')
insert into @testdata values('4+w5')
select 'w' + LEFT(ds.item, patindex('%[^0-9]%', ds.Item + '.') - 1)
from @testdata td
cross apply dbo.DelimitedSplit8K(td.expression, 'w') ds
where ds.ItemNumber > 1 AND ds.Item like '[0-9]%'
Edit: Corrected code and added more test data.
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply