Table : test
|---------------------------------------------------------|
| descriptiona |
|---------------------------------------------------------|
|#*Summary: data1 #*Steps: data2 #*Result: data3 |
|---------------------------------------------------------|
|#*Steps: data5 #*Summary: data6 #*Result: data4 |
|---------------------------------------------------------|
I want the data to be displayed as:
summary steps result
data1 data2 data3
data6 data5 data4
Tried using:
SELECT substring(descriptiona, 1, charindex('*Steps', descriptiona)-2) AS Summary,
substring(descriptiona, charindex('*Steps', descriptiona), (charindex('*Result', descriptiona) - charindex('*Steps', descriptiona)) -2 ) AS Steps,
substring(descriptiona, charindex('*Result', descriptiona),len(descriptiona)) AS ActualResult
from test;
But this only works for the first row.
You could split the string and perform a conditional aggregation within a CROSS APPLY
Example
Declare @YourTable Table ([descriptiona] varchar(50)) Insert Into @YourTable Values
('#*Summary: data1 #*Steps: data2 #*Result: data3')
,('#*Steps: data5 #*Summary: data6 #*Result: data4')
Select B.*
From @YourTable
Cross Apply ( Select Summary= stuff(max(case when charindex('Summary:',value)>0 then Value end),1,10,'')
,Steps = stuff(max(case when charindex('Steps:',value)>0 then Value end) ,1,8,'')
,Result = stuff(max(case when charindex('Result:',value)>0 then Value end) ,1,9,'')
From string_split([descriptiona],'#')
) B
Returns
Summary Steps Result
data1 data2 data3
data6 data5 data4
EDIT - 2012 Non Function Alternative
Declare @YourTable Table ([descriptiona] varchar(50)) Insert Into @YourTable Values
('#*Summary: data1 #*Steps: data2 #*Result: data3')
,('#*Steps: data5 #*Summary: data6 #*Result: data4')
Select B.*
From @YourTable
Cross Apply ( Select Summary= stuff(max(case when charindex('Summary:',value)>0 then Value end),1,10,'')
,Steps = stuff(max(case when charindex('Steps:',value)>0 then Value end) ,1,8,'')
,Result = stuff(max(case when charindex('Result:',value)>0 then Value end) ,1,9,'')
From (
Select seq = row_number() over (order by 1/0)
,value = ltrim(rtrim(B.i.value('(./text())[1]', 'varchar(max)')))
From (Select x = Cast('<x>' + replace((Select replace([descriptiona],'#','§§Split§§') as [*] For XML Path('')),'§§Split§§','</x><x>')+'</x>' as xml).query('.')) as A
Cross Apply x.nodes('x') AS B(i)
) B1
) B