Unable to compare text datatype fields to extract salient data

  • Hi all,

    I am looking at a table which holds a record of things typed by different users into a field in our front end. It looks something a bit like this:

    UserName Time FieldValue

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

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

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

    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.

    The basic format is that text is never removed; each new entry is appended on to the end of the last entry in a new row on the table (presumably this enables the history function to work for users in the front end). My problem is that when I produce a report of all the messages in the field, I only want to list the addition that each person made:

    UserName Time FieldValue

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

    Rolf Harris 13:00:00 I have defrosted it

    Jeff Bridges 13:13:00 It's Alive!

    Jenny Bond 13:46:25 I let it go.

    Given that the Field value is stared as a text datatype and it is conceivable that the total message length may exceed 8000 characters, is there any way to achieve what I want? If I start using substrings etc, I will limit myself to 8000 characters, even when using a VARCHAR(MAX) (At least I think that is the case..?)

    Any help much appreciated, as I am beginning to pull my hair...

    Thanks

    Mark

  • -- 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(REPLACE(tr.FieldValue,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

  • 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.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • Hi and welcome to SSC. It is difficult to answer your question because there is not a lot of detail in the question. From your description I am pretty sure that you can accomplish this. You just need to find the text of the "previous" entry and replace that with ''.

    create table #SomeData

    (

    UserName varchar(20),

    EntryTime Time,

    FieldValue varchar(max)

    )

    insert #SomeData

    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.'

    ;with cte as

    (

    select *, ROW_NUMBER()over(order by EntryTime) as RowNum

    from #SomeData

    )

    , cte2 as

    (

    SELECT UserName, EntryTime, c1.FieldValue as FieldValue1, c1.RowNum, (select c2.FieldValue from cte c2 where c2.RowNum = c1.RowNum - 1) as FieldValue2 FROM cte c1

    )

    select UserName, EntryTime, ltrim(isnull(REPLACE(FieldValue1, FieldValue2, ''), FieldValue1)) as NewValue from cte2

    drop table #SomeData

    Notice how I posted sample data and structures. This is something you should consider on future posts. You can view the first link in my signature for best practices when posting questions.

    --EDIT--

    LOL it seems that two others posted while I was writing my response. :hehe:

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • I like the approach that G2 took using apply. Didn't think about repeating strings get removed.

    This exercise is a good example of why data should be stored differently. If your application stored only the current entry none of this would be happening at all. That of course is not always possible or feasible to retrofit but definitely something to consider for future applications.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks Chris and GSquared for replies and speed!

    I see how those work; my concern is that using things like REPLACE(),LEN(),LEFT() on a text field of more than 8000 characters will truncate the length down to 8000 characters, meaning that I could lose data off the end of my fieldvalue; the example below will return 8000:

    DECLARE @String VARCHAR(MAX) = REPLICATE('a',10000)

    SELECT LEN(@String)

    I am using SQL Server 2008 R2, so the VARCHAR(MAX) should be able to hold something like 2^31 characters

    Edit:

    Wow - you post faster than I do! I hear you about the need for sample data - taken on board. Unfortunately, we are using a database built by an external software company and have no real control over the format.

  • 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

  • High Plains Grifter (9/24/2012)


    Thanks Chris and GSquared for replies and speed!

    I see how those work; my concern is that using things like REPLACE(),LEN(),LEFT() on a text field of more than 8000 characters will truncate the length down to 8000 characters, meaning that I could lose data off the end of my fieldvalue; the example below will return 8000:

    DECLARE @String VARCHAR(MAX) = REPLICATE('a',10000)

    SELECT LEN(@String)

    I am using SQL Server 2008 R2, so the VARCHAR(MAX) should be able to hold something like 2^31 characters

    Edit:

    Wow - you post faster than I do! I hear you about the need for sample data - taken on board. Unfortunately, we are using a database built by an external software company and have no real control over the format.

    DECLARE @String VARCHAR(MAX) = REPLICATE(CAST('a' AS VARCHAR(MAX)),10000)

    SELECT LEN(@String)

    “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

  • Ok... Magic? I guess that one needs a google; I cannot explain that by looking!

  • High Plains Grifter (9/24/2012)


    Ok... Magic? I guess that one needs a google; I cannot explain that by looking!

    There's a good explanation in BOL - the output datatype of REPLICATE depends upon the input datatype. Casting outside of REPLICATE is too late.

    “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

  • Ok, well I don't quite get why SQL Server only truncates some strings, but I have a way that fails to work and your example using CAST() which does work to look at so I reckon I can solve that one myself.

    Thanks a lot for your excellent help - I can continue to write and to learn.

    Cheers and cheerio!

    Mark

  • High Plains Grifter (9/24/2012)


    Ok, well I don't quite get why SQL Server only truncates some strings, but I have a way that fails to work and your example using CAST() which does work to look at so I reckon I can solve that one myself.

    Thanks a lot for your excellent help - I can continue to write and to learn.

    Cheers and cheerio!

    Mark

    Thanks for the feedback Mark. I'd recommend you investigate Gus's solution as it will likely perform better than a 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

  • High Plains Grifter (9/24/2012)


    Ok, well I don't quite get why SQL Server only truncates some strings, but I have a way that fails to work and your example using CAST() which does work to look at so I reckon I can solve that one myself.

    Thanks a lot for your excellent help - I can continue to write and to learn.

    Cheers and cheerio!

    Mark

    The reason it truncates some and not others is the precedence on implicit conversions/definitions.

    SELECT 'a' AS StringColumn;

    That doesn't explicitly define the datatype of the column. To find out what it is, you can look at the defaults set on the server you're running it on, or you can change it to:

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

    DROP TABLE #T;

    SET NOCOUNT ON;

    SELECT 'a' AS StringColumn

    INTO #T;

    SELECT (SELECT TOP (1)

    name

    FROM sys.types

    WHERE types.system_type_id = columns.system_type_id),

    max_length,

    precision,

    scale

    FROM tempdb.sys.columns

    WHERE object_id = OBJECT_ID(N'tempdb..#T');

    What you'll probably end up with is varchar(1). Some connections will define the default length as 25 or even 50, but without checking you really can't be sure what it is.

    Now try replacing the Select Into with this:

    SELECT CAST('a' AS VARCHAR(MAX)) AS StringColumn

    INTO #T;

    You should get what looks like varchar(-1). Max-length of -1 = "max" in sys.columns.

    So, when you use the default "REPLICATE('a', 10000)", you're getting a regular version of varchar, not the large-object-version, because regular is the default. That can only go to 8k characters, so that's all you get.

    For more information on it, research implicit conversions. Start here: http://msdn.microsoft.com/en-us/library/aa224021(v=SQL.80).aspx

    The solution I gave you works just fine with long data. Try this:

    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.'),

    (2, '20120924 00:00:00', REPLICATE(CAST('a' AS VARCHAR(MAX)), 10000)),

    (2, '20120924 00:00:01', REPLICATE(CAST('a' AS VARCHAR(MAX)), 10000) + CAST('x' AS VARCHAR(MAX)));

    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;

    The only modification is that I added EntryID 2 data to the end of the insert and tested that. You can add a length-check to it:

    SELECT T1.EntryTime, LEN(T1.FieldValue),

    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. EntryID, T1.EntryTime;

    (The results also make more sense if you add EntryID to the Order By.)

    Does that help?

    (Edit to fix a formatting tag.)

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

Viewing 13 posts - 1 through 12 (of 12 total)

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