February 27, 2009 at 1:04 pm
Hi,
Looking for help with function.
InputString= John[Sam]Will[Joseph]Smith[Joe]
Output table values:
Sam
Joseph
Joe
Trying the following however unsure of output as table values.
select SUBSTRING(InputString,CHARINDEX('[',InputString)+1,charindex(']',InputString,CHARINDEX('[',InputString))-2)
February 27, 2009 at 2:30 pm
I would recommend that your read this article by Jeff Moden
http://www.sqlservercentral.com/articles/T-SQL/63003/
contains enough sample code to do what you want to do
February 27, 2009 at 8:31 pm
I'd definitely suggest you read the article that Bit Bucket pointed you to, but not until you understand how a Tally table actually replaces a loop in situations like this. Read the following article, first...
http://www.sqlservercentral.com/articles/TSQL/62867/
Then, make a permanent Tally table...
--===== Create and populate the Tally table on the fly
SELECT TOP 11000 --equates to more than 30 years of dates
IDENTITY(INT,1,1) AS N
INTO dbo.Tally
FROM Master.dbo.SysColumns sc1,
Master.dbo.SysColumns sc2
--===== Add a Primary Key to maximize performance
ALTER TABLE dbo.Tally
ADD CONSTRAINT PK_Tally_N
PRIMARY KEY CLUSTERED (N) WITH FILLFACTOR = 100
--===== Allow the general public to use it
GRANT SELECT ON dbo.Tally TO PUBLIC
After that, your problem suddenly becomes child's play, just like the article that Bit Bucket pointed you to...
--===== Simulate a passed parameter
DECLARE @Parameter VARCHAR(8000)
SET @Parameter = 'John[Sam]Will[Joseph]Smith[Joe]'
--===== Suppress the auto-display of rowcounts to keep them from being
-- mistaken as part of the result set.
SET NOCOUNT ON
--===== Get the items in the brackets and number them
SELECT ROW_NUMBER() OVER (ORDER BY N) AS ElementNumber,
SUBSTRING(@Parameter,N+1,CHARINDEX(']',@Parameter,N+1)-N-1) AS ElementValue
FROM dbo.Tally
WHERE N < LEN(@Parameter)
AND SUBSTRING(@Parameter,N,1) = '['
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply