Author |
Topic |
paulmoss
Starting Member
14 Posts |
Posted - 2013-06-13 : 04:45:09
|
We have a field in sage that contains values from a Multi-Select field in our CRM package. The data is stored as below;,prod1,prod2,prod3,I am trying to create a view that will replace those values. The result I am trying to achieve is;Product1, Product2, Product3I have considered using a CASE statement, but was wondering if there was a simpler methodMany thanksPaul |
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2013-06-13 : 04:57:41
|
is it always same word pattern ie prod? or are there a set of patterns which you need to replace with their expanded forms?------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/https://www.facebook.com/VmBlogs |
|
|
paulmoss
Starting Member
14 Posts |
Posted - 2013-06-13 : 05:05:33
|
There are a set of patterns. I don't know if this will help, but there is a table that contains both the short form and the expanded form.Many thanksPaul |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2013-06-13 : 05:09:44
|
yep...that would certainly helpthen you can use likeUPDATE mtSET mt.Field = REPLACE(mt.Field,',' + pt.shortform + ',',',' + pt.expandedform + ',')FROM MainTable mtINNER JOIN PatternTable ptON mt.Field LIKE '%,' + pt.shortform + ',%' ------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/https://www.facebook.com/VmBlogs |
|
|
paulmoss
Starting Member
14 Posts |
Posted - 2013-06-13 : 06:01:07
|
Thanks for the code that helps if I wanted to update a field permanently. Unfortunately I need to keep both the short and extended versions of the text. What I am really looking for is a script that can be used in a view that displays the extended versions in place of the short text, with out replacing the underlying data.Many thanksPaul |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2013-06-13 : 06:09:12
|
ok here you goSELECT mt.Field,pt.ExpandedFROM MainTable mtCROSS APPLY (SELECT ',' + expandedform AS text() FROM PatternTable WHERE mt.Field LIKE '%,' + shortform + ',%' FOR XML PATH('') )pt(Expanded) ------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/https://www.facebook.com/VmBlogs |
|
|
paulmoss
Starting Member
14 Posts |
Posted - 2013-06-13 : 08:54:53
|
Thanks for the help that your providing visakh16, but I am having issues with the code you provided. I keep getting an incorrect syntax near '('. Any idea what I might be doing wrongMany thanksPaul |
|
|
bandi
Master Smack Fu Yak Hacker
2242 Posts |
Posted - 2013-06-13 : 09:44:37
|
[code]-- try thisSELECT mt.Field,pt.ExpandedFROM MainTable mtCROSS APPLY (SELECT ',' + expandedform AS text() -- strike off red marked part FROM PatternTable WHERE mt.Field LIKE '%,' + shortform + ',%' FOR XML PATH('') )pt(Expanded)[/code]--Chandu |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2013-06-14 : 00:52:57
|
quote: Originally posted by paulmoss Thanks for the help that your providing visakh16, but I am having issues with the code you provided. I keep getting an incorrect syntax near '('. Any idea what I might be doing wrongMany thanksPaul
it should beSELECT mt.Field,pt.ExpandedFROM MainTable mtCROSS APPLY (SELECT ',' + expandedform AS [text()] FROM PatternTable WHERE mt.Field LIKE '%,' + shortform + ',%' FOR XML PATH('') )pt(Expanded) ------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/https://www.facebook.com/VmBlogs |
|
|
|