Manipulate a field that contains a specific format

  • 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

  • Is it possible that "this is a note" will contain six letters followed by a date and time?

    John

  • Highly unlikely John. I am going to make the assumption not

  • 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

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

  • 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

  • Perfect. Thankyou very much

  • 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

  • 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

  • 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

  • I recall that the original post wanted to add a CR/LF for each note.   This would make the report easier to deal with than having to adjust to not repeat existing columns for the additional rows the final posted query would produce..   Try this and see if it works for you:SET NOCOUNT ON;
    DECLARE @Contents AS varchar(4000) =
        '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)) AS v(n)
    ),
        Hundred AS (

            SELECT t1.n
            FROM Ten AS t1
                CROSS JOIN Ten AS t2
    ),
        Thousand(n) AS (

            SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
            FROM Hundred AS h
                CROSS JOIN Ten AS t   
    ),
        StartPoints AS (

            SELECT n AS StartChar, ROW_NUMBER() OVER(ORDER BY n) AS RN
            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 S1.StartChar,
                ISNULL(S2.StartChar, LEN(@Contents) + 1) AS NextStartChar
            FROM StartPoints AS S1
                LEFT OUTER JOIN StartPoints AS S2
                    ON S1.RN + 1 = S2.RN
    )
    SELECT STUFF(
        (
        SELECT CHAR(13) + CHAR(10) +
            SUBSTRING(@Contents, StartChar, NextStartChar - StartChar)
        FROM StartPointssandNext
        FOR XML PATH(''), TYPE
        ).value('.','varchar(4000)'), 1, 2, '') AS THE_COLUMN;

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • That works great Steve...Thankyou.
    I had done the last part this way:
    Yours works just as well 🙂

    SELECT @combinedString = COALESCE(@combinedString + CHAR(13) + CHAR(10), '') + SUBSTRING(@Contents,StartChar,NextStartChar-StartChar)

  • I have a problem with this now...If the date in the note is in UK format, it returns NULL. (It works as expected when it is in US format).
    The example i gave wouldn't have highlighted the problem because the dates are 01/01/2018, 02/02/2018 and 03/02/2018.
    If we change one of these dates to say 30/01/2018 you would get a NULL. If you change it to 01/30/2018 - it works.
    Any idea why?

    Another annoying problem is that i've now established that the application sometimes stores the date as dd/mm/yy - How annoying!
    So some notes are dd/mm/yyyy and some are dd/mm/yy - Which obviously scuppers the super function that John created - Again, any ideas on how to deal with that?

  • Sussed it!

    The first part (US date format) i've done a SET DATEFORMAT dmy
    The second part, I've made it cater for both dd/mm/yy AND dd/mm/yyyy:

    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)
            OR
            (ISDATE(SUBSTRING(@Contents,n+7,17)) = 1 AND n<= LEN(@Contents) - 24)
            )
      )

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

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