May 20, 2010 at 12:12 am
Hi all,
I want to split a string into table structure.
my string looks like '1:1,3,5,7,4:56,43,58,5:34,67r,234'
expected output is:
value1 value2
1 1
1 3
1 5
1 7
4 56
4 43
4 48
5 34
5 67r
5 234
where ever i find a ':' the previous digit should be value1 and value2 should be the rest of the comma separated values till it find next ':'. Remember to leave the last one for value1
i'm trying to modify the default function to split string
CREATE FUNCTION [dbo].[fn_CSVToTable] ( @StringInput VARCHAR(8000) ,@Seprator Varchar(1))
RETURNS @OutputTable TABLE ( [String] VARCHAR(10) )
AS
BEGIN
DECLARE @String VARCHAR(10)
WHILE LEN(@StringInput) > 0
BEGIN
SET @String = LEFT(@StringInput,
ISNULL(NULLIF(CHARINDEX(@Seprator, @StringInput) - 1, -1),
LEN(@StringInput)))
SET @StringInput = SUBSTRING(@StringInput,
ISNULL(NULLIF(CHARINDEX(@Seprator, @StringInput), 0),
LEN(@StringInput)) + 1, LEN(@StringInput))
INSERT INTO @OutputTable ( [String] )
VALUES ( @String )
END
RETURN
END
any guidelines / help are highly appreciated.
Thanks,
Regards,
Ami
May 20, 2010 at 5:02 am
I hope this will help;
Declare @StringInput varchar(100)
Declare @v-2 varchar(100)
Declare @v1 varchar(100)
Set @StringInput = '199:141,3,5,7,4:56,43,58,5:34,67r,234'
Declare @OutputTable TABLE ( [String1] VARCHAR(10),[String2] VARCHAR(10))
Declare C1 Cursor for Select [value] from dbo.fnSplit(@StringInput,',')
Open C1
Fetch Next from C1 into @v-2
While @@Fetch_Status = 0
begin
if CharIndex(':',@v) > 0
begin
Insert into @OutputTable
Select Left(@v,CharIndex(':',@v)-1),Right(@v,Len(@v) - CharIndex(':',@v))
Set @v1 = Left(@v,CharIndex(':',@v)-1)
end
else
begin
Insert into @OutputTable
Select @v1,@v
end
Fetch Next from C1 into @v-2
end
Deallocate C1
Select * from @OutputTable
May 20, 2010 at 5:02 am
If you dont have fnSplit function, here is the code;
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE function [dbo].[fnSplit]
(@pString nvarchar(max),@pSplitChar char(1))
returns @tblTemp table (tid int,value varchar(1000))
as
begin
declare @vStartPositionint
declare @vSplitPositionint
declare @vSplitValuevarchar(1000)
declare @vCounterint
set @vCounter=1
select @vStartPosition = 1,@vSplitPosition=0
set @vSplitPosition = charindex( @pSplitChar , @pString , @vStartPosition )
if (@vSplitPosition=0 and len(@pString) != 0)
begin
INSERT INTO @tblTemp
(
tid,
value
)
VALUES
(
1,
@pString
)
return--------------------------------------------------------------->>
end
set @pString=@pString+@pSplitChar
while (@vSplitPosition > 0 )
begin
set @vSplitValue = substring( @pString , @vStartPosition , @vSplitPosition - @vStartPosition )
set @vSplitValue = ltrim(rtrim(@vSplitValue))
INSERT INTO @tblTemp
(
tid,
value
)
VALUES
(
@vCounter,
@vSplitValue
)
set @vCounter=@vCounter+1
set @vStartPosition = @vSplitPosition + 1
set @vSplitPosition = charindex( @pSplitChar , @pString , @vStartPosition )
end
return
end
May 20, 2010 at 6:16 am
This one (without use of cursor or loops opr UDF) will perform and scale much better...
declare @pInput varchar(max)
declare @n int
set @pInput = '1:1,3,5,7,4:56,43,58,5:34,67r,234'
set @pInput = ',' + @pInput + ','
select @n =LEN(@pInput)
set rowcount @n
select IDENTITY( int,1,1) as id into #tally
from sys.columns
set rowcount 0
declare @val1 varchar(500)
declare @res table (id int, vals varchar(1000), val1 varchar(500), val2 varchar(500))
insert into @res (id, vals)
select id
,SUBSTRING(@pInput,id+1,CHARINDEX(',',@pInput,id+1)-id-1) vals
from #tally
where SUBSTRING(@pInput,id,1) = ',' and id < LEN(@pInput)
update @res
set val1 = case when CHARINDEX(':', vals) > 0 then SUBSTRING(vals,0,CHARINDEX(':', vals)) else @val1 end
,val2 = case when CHARINDEX(':', vals) > 0 then SUBSTRING(vals,CHARINDEX(':', vals)+1,1000) else vals end
,@val1 = case when CHARINDEX(':', vals) > 0 then SUBSTRING(vals,0,CHARINDEX(':', vals)) else @val1 end
select val1, val2 from @res
drop table #tally
If your string to split expected to be very large, you can add clustered unique index on id column of #tally table and use # table instead of table variable for the result table. Otherwise, I think this code is fine as it is...
May 21, 2010 at 4:40 am
Hi,
Thanks for the inputs. both are working fine
thanks,
regards,
Ami
May 21, 2010 at 6:12 am
Anamika (5/21/2010)
Hi,Thanks for the inputs. both are working fine
thanks,
regards,
Ami
If the comma separated list is as long as 1000s of list items, it would be better to with tally table solution. But if it is limited to 10s or 20s. then its up to you both are feasible.
May 21, 2010 at 3:31 pm
If you're really getting into the thousands of splits in a string, you're probably well into CLR territory.
WHAT?!?! SOMEBODY was gonna say it.
May 22, 2010 at 11:43 am
Atif Sheikh (5/21/2010)
Anamika (5/21/2010)
Hi,Thanks for the inputs. both are working fine
thanks,
regards,
Ami
If the comma separated list is as long as 1000s of list items, it would be better to with tally table solution. But if it is limited to 10s or 20s. then its up to you both are feasible.
I have to disagree... limited row counts are never justification for writing something that isn't scalable.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 23, 2013 at 7:21 pm
Ok, I know this thread is old but if PatternSplitCM[/url] was available when this was posted you could do this:
DECLARE @string varchar(100)='1:1,3,5,7,4:56,43,58,5:34,67r,234';
WITH prep1 AS
(
SELECT x.ItemNumber,
ROW_NUMBER() OVER (PARTITION BY x.ItemNumber
ORDER BY xx.ItemNumber) AS rnk,
x.Item,
xx.Item AS Item_sub
FROM (SELECT * FROM dbo.PatternSplitCM(@string,'[^:]')
WHERE Item<>',') x
CROSS APPLY dbo.PatternSplitCM(x.Item,',') xx
WHERE x.Matched=1 AND xx.Matched=0
),
prep2 AS
(
SELECTItemNumber+
CASE
WHEN rnk=MAX(rnk) OVER (PARTITION BY ItemNumber) AND
prep1.ItemNumber<>MAX(ItemNumber) OVER()
THEN 2 ELSE 0
END AS ItemNumber,
Item_sub,
CASE
WHEN rnk=MAX(rnk) OVER (PARTITION BY ItemNumber) AND
prep1.ItemNumber<>MAX(ItemNumber) OVER()
THEN 1 ELSE 0
END AS isParent
FROM prep1
)
SELECT p1.Item_sub, p2.Item_sub xx
FROM prep2 p1
JOIN prep2 p2 ON p1.ItemNumber=p2.ItemNumber
WHERE p1.isParent=1
AND p2.isParent=0
ORDER BY p1.Item_sub
-- Itzik Ben-Gan 2001
October 25, 2013 at 4:14 am
A bit of a different take on this, just for fun.
WITH SampleData (ID, MyString) AS
(
SELECT 1, '1:1,3,5,7,4:56,43,58,5:34,67r,234'
)
SELECT ID
,ItemNumber
,value1=CASE CHARINDEX(':', Item) WHEN 0 THEN NULL ELSE LEFT(Item, CHARINDEX(':', Item) - 1) END
,value2=CASE CHARINDEX(':', Item) WHEN 0 THEN Item ELSE SUBSTRING(Item, CHARINDEX(':', Item) + 1, 999) END
INTO #MyTable
FROM SampleData a
CROSS APPLY dbo.DelimitedSplit8K(MyString, ',') b
ALTER TABLE #MyTable ALTER COLUMN ID INT NOT NULL;
ALTER TABLE #MyTable ALTER COLUMN ItemNumber INT NOT NULL;
ALTER TABLE #MyTable ADD PRIMARY KEY(ID, ItemNumber);
ALTER TABLE #MyTable ADD value3 INT NULL;
DECLARE @val INT = 0, @ID INT;
UPDATE #MyTable WITH(TABLOCKX)
SET @val = CASE WHEN @ID = ID AND value1 IS NULL THEN @val ELSE value1 END
,value3 = @val
,@ID = ID
OPTION (MAXDOP 1);
SELECT ID, value1=value3, value2
FROM #MyTable;
GO
DROP TABLE #MyTable;
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
October 25, 2013 at 7:19 am
Or another (just for fun 😉 )
WITH SampleData (ID, MyString) AS
(
SELECT 1, '1:1,3,5,7,4:56,43,58,5:34,67r,234'
),
split AS
(
SELECT b.ItemNumber,b.Item
FROM SampleData a
CROSS APPLY dbo.DelimitedSplit8K(MyString, ',') b
)
SELECTLEFT(s2.Item,CHARINDEX(':',s2.Item)-1),
CASE CHARINDEX(':', s1.Item) WHEN 0 THEN s1.Item ELSE SUBSTRING(s1.Item,CHARINDEX(':', s1.Item)+1,255) END
FROMsplit s1
CROSS APPLY (SELECT TOP 1 * FROM split WHERE ItemNumber < s1.ItemNumber AND Item LIKE '%:%' ORDER BY ItemNumber DESC) s2
Really horrible looking execution plan though 😀
Far away is close at hand in the images of elsewhere.
Anon.
October 25, 2013 at 6:27 pm
David Burrows (10/25/2013)
Clearly we are having way too much fun here! 😛
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply