Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Unable to compare text datatype fields to extract salient data


Unable to compare text datatype fields to extract salient data

Author
Message
High Plains Grifter
High Plains Grifter
SSC Rookie
SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)

Group: General Forum Members
Points: 35 Visits: 121
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
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9027 Visits: 19036
-- 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
Exploring Recursive CTEs by Example Dwain Camps
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14385 Visits: 9729
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
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16671 Visits: 17030
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16671 Visits: 17030
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
High Plains Grifter
High Plains Grifter
SSC Rookie
SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)

Group: General Forum Members
Points: 35 Visits: 121
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.
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9027 Visits: 19036
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
Exploring Recursive CTEs by Example Dwain Camps
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9027 Visits: 19036
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
Exploring Recursive CTEs by Example Dwain Camps
High Plains Grifter
High Plains Grifter
SSC Rookie
SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)

Group: General Forum Members
Points: 35 Visits: 121
Ok... Magic? I guess that one needs a google; I cannot explain that by looking!
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9027 Visits: 19036
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
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search