• GSquared (9/24/2012)


    Another possible:

    IF OBJECT_ID(N'tempdb..#T') IS NOT NULL

    DROP TABLE #T;

    CREATE TABLE #T

    (EntryID INT NOT NULL,

    EntryTime DATETIME NOT NULL,

    FieldValue VARCHAR(MAX));

    INSERT INTO #T

    (EntryID, EntryTime, FieldValue)

    VALUES (1, '20120924 00:00:00', 'We cannot do anything until 1 O''Clock - the penguin needs defrosting'),

    (1, '20120924 13:00:00',

    'We cannot do anything until 1 O''Clock - the penguin needs defrosting I have defrosted it'),

    (1, '20120924 13:05:00',

    'We cannot do anything until 1 O''Clock - the penguin needs defrosting I have defrosted it It''s Alive!'),

    (1, '20120924 13:10:00',

    'We cannot do anything until 1 O''Clock - the penguin needs defrosting I have defrosted it It''s Alive! I let it go.');

    SELECT T1.EntryTime,

    LTRIM(STUFF(T1.FieldValue, 1, ISNULL(LEN(Previous.FieldValue), 0), ''))

    FROM #T AS T1

    OUTER APPLY (SELECT TOP (1)

    *

    FROM #T AS T2

    WHERE T1.EntryID = T2.EntryID

    AND T1.EntryTime > T2.EntryTime

    ORDER BY EntryTime DESC) AS Previous

    ORDER BY T1.EntryTime;

    Outer Apply grabs the immediately prior row, if any, gets the Len() of the value, and uses Stuff() to get rid of that much of the beginning of the string.

    Using Replace() (as per Chris idea), might not work if a string can repeat itself inside the data. If, for example, the first entry were "Hello!", and the second were then "Hello! Hello! to you too", you'd end up with the "Hello!" substring stripped out where it's not supposed to be. If that's not a possible scenario (repeating string), then it won't matter and either will work.

    Good point, Gus. First mental pass used STUFF but it flew away during coding.

    -- sample data

    DROP TABLE #Sample

    CREATE TABLE #Sample (UserName VARCHAR(15), [Time] CHAR(8), FieldValue TEXT)

    INSERT INTO #Sample (UserName, [Time], FieldValue)

    SELECT 'Bob Hope', '12:00:00', 'We cannot do anything until 1 O''Clock - the penguin needs defrosting'

    UNION ALL SELECT 'Rolf Harris', '13:00:00', 'We cannot do anything until 1 O''Clock - the penguin needs defrosting I have defrosted it'

    UNION ALL SELECT 'Jeff Bridges', '13:13:00', 'We cannot do anything until 1 O''Clock - the penguin needs defrosting I have defrosted it It''s Alive!'

    UNION ALL SELECT 'Jenny Bond', '13:46:25', 'We cannot do anything until 1 O''Clock - the penguin needs defrosting I have defrosted it It''s Alive! I let it go.'

    -- solution

    ;WITH SequencedData AS (

    SELECT

    UserName,

    [Time],

    FieldValue = CAST(FieldValue AS VARCHAR(MAX)),

    rn = ROW_NUMBER() OVER (ORDER BY [Time])

    FROM #Sample

    ),

    rCTE AS (

    SELECT UserName, [Time], rn,

    UserString = FieldValue,

    FieldValue = FieldValue

    FROM SequencedData

    WHERE rn = 1

    UNION ALL

    SELECT tr.UserName, tr.[Time], tr.rn,

    UserString = LTRIM(STUFF(tr.FieldValue,1,DATALENGTH(lr.FieldValue),'')),

    FieldValue = tr.FieldValue

    FROM SequencedData tr

    INNER JOIN rCTE lr ON lr.rn+1 = tr.rn

    )

    SELECT UserName, [Time], UserString

    FROM rCTE

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden