string manipulation - Need help !

  • Hi All,

    Can anyone help me with below sql server 2005 and up:

    input string:

    BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]

    output string:

    BUILTIN\ADMINISTRATORS: [System Admin]YES;[Disk Admin]YES;

    I am playing with Stuff and Replace functions but without any luck.

    ______________________________________________________________________________________________________________________________________________________________________________________
    HTH !
    Kin
    MCTS : 2005, 2008
    Active SQL Server Community Contributor 🙂

  • Can you explain more your requirements?

    Because I'm sure that this won't work for you.

    SELECT inputString, SUBSTRING( inputString, 1,42) + SUBSTRING( inputString, 105,16)

    FROM (SELECT 'BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]' AS inputString) Input

    However, it gives the correct output.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Using one of Jeff Moden's splitter functions

    DECLARE @pString VARCHAR(MAX) = 'BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator];'

    DECLARE @pDELIMITER CHAR(1) = ';'

    ;WITH SPLITS AS (

    SELECT ItemNumber = ROW_NUMBER() OVER (ORDER BY t.N),

    Item = SUBSTRING(@pString, t.N, CHARINDEX(@pDelimiter, @pString + @pDelimiter, t.N) - t.N)

    FROM dbo.Tally as t

    WHERE t.N <= DATALENGTH(@pString)+1 --DATATLENGTH allows for trailing space delimiters

    AND SUBSTRING(@pDelimiter + @pString, t.N, 1) = @pDelimiter

    )

    SELECT Item

    FROM SPLITS

    WHERE ITEM Like '%YES'

    ORDER BY ItemNumber

    Then you just concatenate the resulting items with a delimiter, using STUFF, as you were originally experimenting with?

  • -- deleted double comments --

    ______________________________________________________________________________________________________________________________________________________________________________________
    HTH !
    Kin
    MCTS : 2005, 2008
    Active SQL Server Community Contributor 🙂

  • Luis Cazares (9/4/2012)


    Can you explain more your requirements?

    Because I'm sure that this won't work for you.

    SELECT inputString, SUBSTRING( inputString, 1,42) + SUBSTRING( inputString, 105,16)

    FROM (SELECT 'BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]' AS inputString) Input

    However, it gives the correct output.

    I am just writing a report that will show the login information with their privileges

    NT AUTHORITY\SYSTEM: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]

    NT SERVICE\MSSQL$instance1: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]

    NT SERVICE\SQLAGENT$instance1: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]YES

    I want the result as below:

    NT AUTHORITY\SYSTEM: [System Admin]YES;

    NT SERVICE\MSSQL$instance1: [System Admin]YES;

    NT SERVICE\SQLAGENT$instance1: [System Admin]YES;[Database Creator]YES;

    Thanks for you code .. but you code truncates the

    SELECT inputString, SUBSTRING( inputString, 1,42) + SUBSTRING( inputString, 105,16)

    FROM (SELECT 'NT SERVICE\SQLAGENT$instance1: [System Admin]YES;[Security Admin];[Server Admin]YES;[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]YES' AS inputString) Input

    NT SERVICE\SQLAGENT$instance1: [System Adess Admin];[Disk

    ______________________________________________________________________________________________________________________________________________________________________________________
    HTH !
    Kin
    MCTS : 2005, 2008
    Active SQL Server Community Contributor 🙂

  • I agree that a string splitter combined with putting it all back together using FOR XML TYPE is the way to go:

    DECLARE @pString VARCHAR(MAX) = 'BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator];'

    SELECT Result=

    (SELECT item + CASE itemnumber WHEN 1 THEN ': ' ELSE ';' END

    FROM dbo.DelimitedSplit8K(REPLACE(@pString, ': ', ';'), ';')

    WHERE RIGHT(item, 3) = 'YES' OR itemnumber = 1

    FOR XML PATH(''), TYPE).value('.', 'VARCHAR(MAX)')


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • pls try below code.

    declare @t varchar(2000)='BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]'

    select 'BUILTIN\ADMINISTRATORS: [System Admin]YES'+SUBSTRING(@t,PATINDEX('%Disk Admin]YES%',@t)-2,16)

  • You can use a lot of methods to do this. It all depends on what part of the String you want to remove, the type of requirement(one time or a lot of times) and a lot more conditions. Apart from the abovew mentioned ways you can use Stuff and Replace as well as follows:

    Declare @String Varchar(Max) = 'BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]'

    Select STUFF(STUFF(@String, 42, 62, ''), 59, 18, '')

    Select Replace(REPLACE(@String, '[Security Admin];[Server Admin];[setup Admin];[Process Admin];', ''), '[Database Creator]', '')

    Now, you have a lot of options and you can choose the best depending on the conditions that define your requirement.

    Edit: The Stuff Function should give better performance. And I am sure when Dwain sees the Replace functions he would definitely come up with a couple of expert performance points. That would clear the situation a little more. 🙂

    Vinu Vijayan

    For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden[/url] 😉

  • vinu512 (9/5/2012)


    You can use a lot of methods to do this. It all depends on what part of the String you want to remove, the type of requirement(one time or a lot of times) and a lot more conditions. Apart from the abovew mentioned ways you can use Stuff and Replace as well as follows:

    Declare @String Varchar(Max) = 'BUILTIN\ADMINISTRATORS: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin]YES;[Database Creator]'

    Select STUFF(STUFF(@String, 42, 62, ''), 59, 18, '')

    Select Replace(REPLACE(@String, '[Security Admin];[Server Admin];[setup Admin];[Process Admin];', ''), '[Database Creator]', '')

    Now, you have a lot of options and you can choose the best depending on the conditions that define your requirement.

    Edit: The Stuff Function should give better performance. And I am sure when Dwain sees the Replace functions he would definitely come up with a couple of expert performance points. That would clear the situation a little more. 🙂

    I think what the OP wants to do is return any roles that have a YES next to them. My assumption was that any of the listed roles could be YES or ''. What if the string was:

    'BUILTIN\ADMINISTRATORS: [System Admin];[Security Admin];[Server Admin]YES;[setup Admin];[Process Admin]YES;[Disk Admin];[Database Creator]YES'

    What would your code return?

    I don't think he was looking for something that is as specific as yours (but of course I could be wrong).

    As to performance, applying a binary collation to @pString (my query) would be my only suggestion. Since he didn't provide a TABLE with a column of such strings to parse, I wasn't aiming for high performance.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • ohhh!!!! yes!!....i didn't look at the logic that way...that completely missed my eye. Sorry, My Bad. I was in a hurry, I just saw the OP's post and replied without reading any of the other posts. May be if I had read the other posts then I would have had a better idea of the OP's requirement.

    Vinu Vijayan

    For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden[/url] 😉

  • vinu512 (9/5/2012)


    ohhh!!!! yes!!....i didn't look at the logic that way...that completely missed my eye. Sorry, My Bad. I was in a hurry, I just saw the OP's post and replied without reading any of the other posts. May be if I had read the other posts then I would have had a better idea of the OP's requirement.

    I think you aren't the only one that's replied to this thread that did the same. No harm done. 🙂

    We'll need to hear back from the OP to find out for sure. Hopefully we will.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • It might not be the optimal way, but it's simple enough for everyone to understand. However, I haven't tested for performance against other methods.

    DECLARE @test-2Table(

    MyStringvarchar(MAX))

    INSERT @test-2 VALUES

    ('NT AUTHORITY\SYSTEM: [System Admin]YES;[Security Admin];[Server Admin]YES;[setup Admin];[Process Admin];[Disk Admin];[Database Creator]'),

    ('NT SERVICE\MSSQL$instance1: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]'),

    ('NT SERVICE\SQLAGENT$instance1: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]YES')

    SELECT LEFT( MyString, CHARINDEX( ':', MyString) + 1) +

    CASE WHEN CHARINDEX( 'System Admin]YES;', MyString) > 0

    THEN '[System Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Security Admin]YES;', MyString) > 0

    THEN '[Security Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Server Admin]YES;', MyString) > 0

    THEN '[Server Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'setup Admin]YES;', MyString) > 0

    THEN '[setup Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Process Admin]YES;', MyString) > 0

    THEN '[Process Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Disk Admin]YES;', MyString) > 0

    THEN '[Disk Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Database Creator]YES', MyString) > 0

    THEN '[Database Creator]YES;' ELSE '' END

    FROM @test-2

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Luis Cazares (9/5/2012)


    It might not be the optimal way, but it's simple enough for everyone to understand. However, I haven't tested for performance against other methods.

    DECLARE @test-2Table(

    MyStringvarchar(MAX))

    INSERT @test-2 VALUES

    ('NT AUTHORITY\SYSTEM: [System Admin]YES;[Security Admin];[Server Admin]YES;[setup Admin];[Process Admin];[Disk Admin];[Database Creator]'),

    ('NT SERVICE\MSSQL$instance1: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]'),

    ('NT SERVICE\SQLAGENT$instance1: [System Admin]YES;[Security Admin];[Server Admin];[setup Admin];[Process Admin];[Disk Admin];[Database Creator]YES')

    SELECT LEFT( MyString, CHARINDEX( ':', MyString) + 1) +

    CASE WHEN CHARINDEX( 'System Admin]YES;', MyString) > 0

    THEN '[System Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Security Admin]YES;', MyString) > 0

    THEN '[Security Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Server Admin]YES;', MyString) > 0

    THEN '[Server Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'setup Admin]YES;', MyString) > 0

    THEN '[setup Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Process Admin]YES;', MyString) > 0

    THEN '[Process Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Disk Admin]YES;', MyString) > 0

    THEN '[Disk Admin]YES;' ELSE '' END +

    CASE WHEN CHARINDEX( 'Database Creator]YES', MyString) > 0

    THEN '[Database Creator]YES;' ELSE '' END

    FROM @test-2

    Thanks for all your replies..

    This is what I did:

    get the results of the query in a temp table and then followed what @luis suggested.

    I learned a lot of different way to achieve the same results.

    I did not chose for the tally table or the splitter function as I did not want to create extra table or function to achieve what could be done using the results from temp table.

    I might be overlooking some obvious benefits which Jeff has an article on SSC, but currently it is not an option for me. I have used Tally and Number tables a lot and they have benefited me ..

    Thanks to all who provided different methods/solutions.

    Good learning ...

    ______________________________________________________________________________________________________________________________________________________________________________________
    HTH !
    Kin
    MCTS : 2005, 2008
    Active SQL Server Community Contributor 🙂

  • So in other words, the string always contains the same roles (or a subset of them) and the ordering of the output result is always fixed and not based on the order of the input roles.

    Right?


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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 14 posts - 1 through 13 (of 13 total)

You must be logged in to reply to this topic. Login to reply