SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Manipulate a field that contains a specific format


Manipulate a field that contains a specific format

Author
Message
EML
EML
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 136
Hi,
Please can anyone assist with my SQL problem?

Here's an example of the contents of a single field:
abcdef 01/01/2018 08:15:13 This is a note , this is a note , this is a note , this is a note , this is a note , this is a note , this is a note, ghijkl 02/02/2018 12:15:45, this is a note , this is a note , this is a note , this is a note mnopqr 03/02/2018 10:34:23 this is a note this is a note this is a note this is a note this is a note this is a note

So... the abcdef and ghijkl and mnopqr are usernames - ALWAYS 6 characters followed by a date and time - ALWAYS that same format.
From the front end, a user can go in and add a note. It gets appended to the existing note and is stored as the <Username> plus <Date and Time> plus <The Note>

I want to put CR+LF's in front of every username so that it will look like this:

abcdef 01/01/2018 08:15:13 This is a note , this is a note , this is a note , this is a note , this is a note , this is a note , this is a note,
ghijkl 02/02/2018 12:15:45, this is a note , this is a note , this is a note , this is a note
mnopqr 03/02/2018 10:34:23 this is a note this is a note this is a note this is a note this is a note this is a note

The output is to an SSRS report so i'm looking for ways to either do it in SQL or in SSRS
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)

Group: General Forum Members
Points: 122544 Visits: 18761
Is it possible that "this is a note" will contain six letters followed by a date and time?

John
EML
EML
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 136
Highly unlikely John. I am going to make the assumption not
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)

Group: General Forum Members
Points: 122544 Visits: 18761
DECLARE @Contents varchar(4000)
SET @Contents =
'abcdef 01/01/2018 08:15:13 This is a note , this is a note , this is a note , this is a note , this is a note , this is a note , this is a note, ghijkl 02/02/2018 12:15:45, this is a note , this is a note , this is a note , this is a note mnopqr 03/02/2018 10:34:23 this is a note this is a note this is a note this is a note this is a note this is a note';

WITH Ten AS (
SELECT n FROM (VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (0)) v(n)
)
, Hundred AS (
SELECT t1.n
FROM Ten t1
CROSS JOIN Ten t2
)
, Thousand(n) AS (
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM Hundred h
CROSS JOIN Ten t
)
, StartPoints AS (
SELECT n AS StartChar
FROM Thousand
WHERE SUBSTRING(@Contents,n,7) LIKE '[a-z][a-z][a-z][a-z][a-z][a-z] '
AND ISDATE(SUBSTRING(@Contents,n+7,19)) = 1
AND n<= LEN(@Contents) - 26
)
, StartPointssandNext AS (
SELECT
StartChar
, LEAD(StartChar,1,LEN(@Contents)+1) OVER (ORDER BY StartChar) AS NextStartChar
FROM StartPoints
)
SELECT
SUBSTRING(@Contents,StartChar,NextStartChar-StartChar)
FROM StartPointssandNext


John

EML
EML
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 136
Thankyou so much John....But....you're going to kill me!!
I posted in the wrong section. Its 2008 (not 2012).
Is there a substitute for LEAD?...Sorry!
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)

Group: General Forum Members
Points: 122544 Visits: 18761
Number the rows in the StartPoint CTE using ROW_NUMBER(). Then, instead of using LEAD in the StartPointsandNext CTE, join StartPoint to itself on RowNo = RowNo + 1.

John
EML
EML
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 136
Perfect. Thankyou very much
EML
EML
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 136
John Mitchell-245523 - Monday, March 5, 2018 7:39 AM
Number the rows in the StartPoint CTE using ROW_NUMBER(). Then, instead of using LEAD in the StartPointsandNext CTE, join StartPoint to itself on RowNo = RowNo + 1.

John

Hi John,
I wonder if you can help me any further? I've joined on RowNo + 1 but now it misses off the 3rd Username. (It only brings back 2 records instead of 3)
Here's the amended code....have you any ideas

DECLARE @Contents varchar(4000)
SET @Contents =
'abcdef 01/01/2018 08:15:13 This is a note , this is a note , this is a note , this is a note , this is a note , this is a note , this is a note, ghijkl 02/02/2018 12:15:45, this is a note , this is a note , this is a note , this is a note mnopqr 03/02/2018 10:34:23 this is a note this is a note this is a note this is a note this is a note this is a note';


WITH Ten AS (
SELECT n FROM (VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (0)) v(n)
)
, Hundred AS (
SELECT t1.n
FROM Ten t1
CROSS JOIN Ten t2
)
, Thousand(n) AS (
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM Hundred h
CROSS JOIN Ten t
)
, StartPoints AS (
SELECT n AS StartChar, ROW_NUMBER() OVER(ORDER BY n) AS Row#
FROM Thousand
WHERE SUBSTRING(@Contents,n,7) LIKE '[a-z][a-z][a-z][a-z][a-z][a-z] '
AND ISDATE(SUBSTRING(@Contents,n+7,19)) = 1
AND n<= LEN(@Contents) - 26
)
, StartPointssandNext AS (
SELECT
StartPoints.StartChar AS NextStartChar,
sp2.StartChar AS StartChar
FROM StartPoints
JOIN StartPoints sp2 ON StartPoints.Row# = sp2.Row# + 1
)
SELECT
SUBSTRING(@Contents,StartChar,NextStartChar-StartChar)
FROM StartPointssandNext

John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)SSC Guru (122K reputation)

Group: General Forum Members
Points: 122544 Visits: 18761
You need to do a left join so that you get all of the rows from StartPoints. You'll get a NULL on the right hand side, but you can handle that with and ISNULL or COALESCE.

John
EML
EML
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 136
Thanks John. Sorted :-


DECLARE @Contents varchar(4000)
SET @Contents =
'abcdef 01/01/2018 08:15:13 This is a note , this is a note , this is a note , this is a note , this is a note , this is a note , this is a note, ghijkl 02/02/2018 12:15:45, this is a note , this is a note , this is a note , this is a note mnopqr 03/02/2018 10:34:23 this is a note this is a note this is a note this is a note this is a note this is a note';

WITH Ten AS (
SELECT n FROM (VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (0)) v(n)
)
, Hundred AS (
SELECT t1.n
FROM Ten t1
CROSS JOIN Ten t2
)
, Thousand(n) AS (
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM Hundred h
CROSS JOIN Ten t
)
, StartPoints AS (
SELECT n AS StartChar, ROW_NUMBER() OVER(ORDER BY n) AS Row#
FROM Thousand
WHERE SUBSTRING(@Contents,n,7) LIKE '[a-z][a-z][a-z][a-z][a-z][a-z] '
AND ISDATE(SUBSTRING(@Contents,n+7,19)) = 1
AND n<= LEN(@Contents) - 26
)
, StartPointssandNext AS (
SELECT
StartPoints.StartChar AS StartChar,
COALESCE (sp2.StartChar, LEN(@Contents) + 1) AS NextStartChar
FROM StartPoints
LEFT JOIN StartPoints sp2 ON StartPoints.Row# + 1 = sp2.Row#
)
SELECT
SUBSTRING(@Contents,StartChar,NextStartChar-StartChar)

FROM StartPointssandNext
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