• It can be done in SSIS, but you have to use a Script Component to do it. Within the Script Component you would use the Split function which creates an array then you can add the columns to the Script Components output by looping through the array.

    You can also do it in T-SQL like this:

    DECLARE @table TABLE (ID INT, value VARCHAR(100))

    INSERT INTO @table (

    ID,

    value

    )

    SELECT

    1, '23:45:355:68'

    Union All

    Select

    1, '4545:908:24'

    Union All

    Select

    2, '343:32'

    Union All

    Select

    3, '812:321:23434:34:45:68'

    /*

    this builds a tally or numbers cte to help do the split

    see this article http://www.sqlservercentral.com/articles/TSQL/62867/

    for an explanation of the tally table and the split function that follows

    */

    ;WITH cteTally AS

    (

    SELECT TOP 100

    ROW_NUMBER() OVER(ORDER BY NAME) as n

    FROM

    sys.all_columns AS AC

    ),

    cteData As

    (

    SELECT

    /*

    I need this to uniquely identitfy each row since your

    test data includes 2 rows with id 1. If the id column

    is unique then you can skip this step and replace value_id

    with id in later steps

    */

    ROW_NUMBER() OVER (ORDER BY T.id) AS value_id,

    T.ID,

    T.value

    FROM

    @table T

    ),

    /*

    this splits the values into multiple rows identifying each row

    for each value_id for use to PIVOT the data

    */

    cteValues AS

    (

    SELECT

    ROW_NUMBER() OVER (PARTITION BY T.value_id ORDER BY T.id) AS row_id,

    T.value_id,

    T.ID,

    SUBSTRING(':'+T.value+':',N+1,CHARINDEX(':',':'+T.value+':',N+1)-N-1) AS split_value,

    T.value

    FROM

    cteData AS T CROSS JOIN

    cteTally AS TL

    WHERE

    N < LEN(':'+T.value+':') AND

    SUBSTRING(':'+T.value+':',N,1) = ':'

    )

    /*

    Here is where we return the final data in the format you want,

    I used the MIN function but you could use MAX as each row will only

    have one value for each column. See this article for details on the

    pivoting http://www.sqlservercentral.com/articles/T-SQL/63681/

    The first example uses the PIVOT function the second (Commented out) does not.

    */

    SELECT

    id,

    value,

    [1] AS Col1,

    [2] AS Col2,

    [3] AS Col3,

    [4] AS Col4,

    [5] AS Col5,

    [6] AS Col6

    FROM

    (SELECT value_id, row_id, id, value, split_value FROM cteValues) AS Src

    PIVOT (MIN(split_value) FOR row_id IN ([1],[2],[3], [4], [5], [6]))AS pvt

    ORDER BY

    id,

    value

    /*

    SELECT

    id,

    value,

    Min(CASE

    WHEN row_id = 1 THEN split_value

    ELSE NULL

    END) AS col1,

    Min(CASE

    WHEN row_id = 2 THEN split_value

    ELSE NULL

    END) AS col2,

    Min(CASE

    WHEN row_id = 3 THEN split_value

    ELSE NULL

    END) AS col3,

    Min(CASE

    WHEN row_id = 4 THEN split_value

    ELSE NULL

    END) AS col4,

    Min(CASE

    WHEN row_id = 5 THEN split_value

    ELSE NULL

    END) AS col5,

    Min(CASE

    WHEN row_id = 6 THEN split_value

    ELSE NULL

    END) AS col6

    FROM

    cteValues

    GROUP BY

    value_id,

    id,

    value

    */

    Which you use (SSIS or T-SQL) depends on what you need to do next.