February 28, 2011 at 11:39 pm
hi
can any one help me in splitting like this in ssis
bas-06-12586
to
bas
06
12586
in different columns
March 1, 2011 at 12:09 am
Hi gupta.sreekanth,
I'm not that expert in scripting, but for the starting u may use following i guess:
Select SUBSTRING(dbo.Table.Column, 0, CHARINDEX('-', dbo.Table.Column, 1,)) as Column1
March 1, 2011 at 12:04 pm
gupta.sreekanth (2/28/2011)
hican any one help me in splitting like this in ssis
bas-06-12586
to
bas
06
12586
in different columns
In SSIS you can use the Derived Column Data Flow Transformation in your Data Flow Task. This will allow you to run an expression against the incoming column containing the dash-delimited strings to create three output columns.
Within the Derived Column Data Flow Transformation SSIS provides a decent expression-builder with functions like FINDSTRING, LEN and SUBSTRING that will support this effort.
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
March 1, 2011 at 11:18 pm
Hi,
You can use the below query in the ssis.
I have taken your string in to one variable and splitted the string in to 3 columns.
There are two methods to derive this
1)Using substring , patindex
-----------------------------
declare @ssn varchar(50)
set @ssn = 'bas-06-12586'
select @ssn,
substring(@ssn,0,patindex('%-[0-9]%',@ssn)) as first,
substring(substring(@ssn,patindex('%-[0-9]%',@ssn)+1,len(@ssn) - patindex('%-[0-9]%',@ssn)),
0,
patindex('%-[0-9]%',substring(@ssn,patindex('%-[0-9]%',@ssn)+1,len(@ssn) - patindex('%-[0-9]%',@ssn)))) as second,
substring(substring(@ssn,patindex('%-[0-9]%',@ssn)+1,len(@ssn) - patindex('%-[0-9]%',@ssn)),
4,
len(substring(@ssn,patindex('%-[0-9]%',@ssn)+1,len(@ssn) - patindex('%-[0-9]%',@ssn)))) as third
2)Using Substring, patindex, reverse
--------------------------------------
declare @ssn varchar(50)
set @ssn = 'bas-06-12586'
select @ssn,
reverse(substring(substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn))),
patindex('%-[a-z]%',substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn))))+1,
len(substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn)))))) as first,
reverse(substring(substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn))),
patindex('%[0-9][0-9]-%',substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn)))),
patindex('%-[a-z]%',substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn))))
- patindex('%[0-9][0-9]-%',substring(reverse(@ssn),patindex('%-[0-9]%',reverse(@ssn))+1,len(reverse(@ssn))-patindex('%-[0-9]%',reverse(@ssn))))
)) as second,
reverse(substring(reverse(@ssn),0,patindex('%-[0-9]%',reverse(@ssn)))) as third
You can use any of the method and can try in SSIS.
Hope this might solve your problem.
Thanks,
Madhuri
March 2, 2011 at 6:59 am
If the expected format of the source data is always the same, this is a simple way to do it...
DECLARE @SplitString VARCHAR(100)
SELECT @SplitString = 'bas-06-12586'
SELECT Col1 = PARSENAME(REPLACE(@SplitString,'-','.'),3),
Col2 = PARSENAME(REPLACE(@SplitString,'-','.'),2),
Col3 = PARSENAME(REPLACE(@SplitString,'-','.'),1)
You can use a column name in place of @SplitString just as easily...
SELECT Col1 = PARSENAME(REPLACE(YourColumn,'-','.'),3),
Col2 = PARSENAME(REPLACE(YourColumn,'-','.'),2),
Col3 = PARSENAME(REPLACE(YourColumn,'-','.'),1)
FROM dbo.YourTable
--Jeff Moden
Change is inevitable... Change for the better is not.
March 2, 2011 at 7:04 am
Jeff Moden (3/2/2011)
If the expected format of the source data is always the same, this is a simple way to do it...
DECLARE @SplitString VARCHAR(100)
SELECT @SplitString = 'bas-06-12586'
SELECT Col1 = PARSENAME(REPLACE(@SplitString,'-','.'),3),
Col2 = PARSENAME(REPLACE(@SplitString,'-','.'),2),
Col3 = PARSENAME(REPLACE(@SplitString,'-','.'),1)
You can use a column name in place of @SplitString just as easily...
SELECT Col1 = PARSENAME(REPLACE(YourColumn,'-','.'),3),
Col2 = PARSENAME(REPLACE(YourColumn,'-','.'),2),
Col3 = PARSENAME(REPLACE(YourColumn,'-','.'),1)
FROM dbo.YourTable
That is a very interesting method. (I had never heard of the PARSENAME function before).
Another one for my knowledge base 🙂
Need an answer? No, you need a question
My blog at https://sqlkover.com.
MCSE Business Intelligence - Microsoft Data Platform MVP
March 2, 2011 at 7:41 am
Koen Verbeeck (3/2/2011)
Jeff Moden (3/2/2011)
If the expected format of the source data is always the same, this is a simple way to do it...
DECLARE @SplitString VARCHAR(100)
SELECT @SplitString = 'bas-06-12586'
SELECT Col1 = PARSENAME(REPLACE(@SplitString,'-','.'),3),
Col2 = PARSENAME(REPLACE(@SplitString,'-','.'),2),
Col3 = PARSENAME(REPLACE(@SplitString,'-','.'),1)
You can use a column name in place of @SplitString just as easily...
SELECT Col1 = PARSENAME(REPLACE(YourColumn,'-','.'),3),
Col2 = PARSENAME(REPLACE(YourColumn,'-','.'),2),
Col3 = PARSENAME(REPLACE(YourColumn,'-','.'),1)
FROM dbo.YourTable
That is a very interesting method. (I had never heard of the PARSENAME function before).
Another one for my knowledge base 🙂
Me too 😀
Just having a play with the statement now.... nice and simple :hehe:
Jeff strikes again :hehe:
March 2, 2011 at 8:02 am
thanks a ton......................
March 2, 2011 at 8:02 am
thanks a ton......................
March 2, 2011 at 8:03 am
thanks a ton......................
March 2, 2011 at 8:04 am
thanks a ton......................
March 2, 2011 at 8:04 am
thanks a ton......................
March 2, 2011 at 8:04 am
Very smart method, I dig it!
March 2, 2011 at 10:31 am
Koen Verbeeck (3/2/2011)
That is a very interesting method. (I had never heard of the PARSENAME function before).Another one for my knowledge base 🙂
grahamc (3/2/2011)
Me too 😀Just having a play with the statement now.... nice and simple :hehe:
Jeff strikes again :hehe:
Ryan Fitzgerald (3/2/2011)
Very smart method, I dig it!
Thanks for the feedback, folks. Simple 2, 3, or 4 part splits seem to come up a lot. What'cha figure? "SQL Spackle" article worthy?
--Jeff Moden
Change is inevitable... Change for the better is not.
March 2, 2011 at 10:33 am
gupta.sreekanth (3/2/2011)
thanks a ton......................
You bet... thank you for the feedback.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 15 posts - 1 through 15 (of 16 total)
You must be logged in to reply to this topic. Login to reply