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


Creating multiple Rows from one row by substringing a column


Creating multiple Rows from one row by substringing a column

Author
Message
lsinoff
lsinoff
SSC Rookie
SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)

Group: General Forum Members
Points: 46 Visits: 6
I need to create from 1 to n rows from a single row where the one column in the read table contains a string from 8 to 16 characters long. The rows written contain a single column 8 bytes long containing all each row being a different combination of 8 consecutive characters from the column of the read table.
INPUT: IN_NUM contains '3456738947'
Output Row 1: NUM_7 contains '34567389'
Output Row 2: NUM_7 contains '45673894'
Output Row 3: NUM_7 contains '56738947'
My ultimate input table will have over 1,000,000 rows and many more columns
My ultimate output table will have about 4,000,000 rows and a subset of columns from the input table
gbritton1
gbritton1
SSCertifiable
SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)

Group: General Forum Members
Points: 5931 Visits: 1063
lsinoff - Tuesday, January 2, 2018 9:33 PM
I need to create from 1 to n rows from a single row where the one column in the read table contains a string from 8 to 16 characters long. The rows written contain a single column 8 bytes long containing all each row being a different combination of 8 consecutive characters from the column of the read table.
INPUT: IN_NUM contains '3456738947'
Output Row 1: NUM_7 contains '34567389'
Output Row 2: NUM_7 contains '45673894'
Output Row 3: NUM_7 contains '56738947'
My ultimate input table will have over 1,000,000 rows and many more columns
My ultimate output table will have about 4,000,000 rows and a subset of columns from the input table

This is pretty easy to do with SUBSTRING and some randomization combined with CROSS APPLY. I don't understand the 4 million output rows, though. Are there not 8! combinations of the 8 bytes? That's a pretty big number. Also, what's the business motivation for this? There's may a better way.

lsinoff
lsinoff
SSC Rookie
SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)

Group: General Forum Members
Points: 46 Visits: 6
I do not know enough TSQL to code the loop needed to generate to create the three rows from 1 row as shown in my example.
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (165K reputation)SSC Guru (165K reputation)SSC Guru (165K reputation)SSC Guru (165K reputation)SSC Guru (165K reputation)SSC Guru (165K reputation)SSC Guru (165K reputation)SSC Guru (165K reputation)

Group: General Forum Members
Points: 165953 Visits: 22826
Here's a sample code to show you how to do it. It uses a cte that creates a tally table on the fly. You can convert the cte into a view, function or store it in a table. I suggest that you read more about tally tables to understand how do they replace loops.

CREATE TABLE #SampleData ( IN_NUM varchar(16));
INSERT INTO #SampleData VALUES('3456738947'), ('41724246874135');

WITH
E(n) AS(
SELECT n FROM (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0))E(n)
),
E2(n) AS(
SELECT a.n FROM E a, E b
),
E4(n) AS(
SELECT a.n FROM E2 a, E2 b
),
cteTally(n) AS(
SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) n
FROM E4
)
SELECT IN_NUM, SUBSTRING( IN_NUM, n, 8)
FROM #SampleData s
JOIN cteTally t ON LEN(s.IN_NUM) - 7 >= t.n
--ORDER BY IN_NUM, n
;

GO
DROP TABLE #SampleData



Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (895K reputation)SSC Guru (895K reputation)SSC Guru (895K reputation)SSC Guru (895K reputation)SSC Guru (895K reputation)SSC Guru (895K reputation)SSC Guru (895K reputation)SSC Guru (895K reputation)

Group: General Forum Members
Points: 895681 Visits: 48220
lsinoff - Tuesday, January 2, 2018 9:33 PM
I need to create from 1 to n rows from a single row where the one column in the read table contains a string from 8 to 16 characters long. The rows written contain a single column 8 bytes long containing all each row being a different combination of 8 consecutive characters from the column of the read table.
INPUT: IN_NUM contains '3456738947'
Output Row 1: NUM_7 contains '34567389'
Output Row 2: NUM_7 contains '45673894'
Output Row 3: NUM_7 contains '56738947'
My ultimate input table will have over 1,000,000 rows and many more columns
My ultimate output table will have about 4,000,000 rows and a subset of columns from the input table

I'm a bit confused. Ignoring the typo in Row2 of the output, what are you actually looking for the given value of '3456738947'. Is it just 3 rows as you have listed or do you really want 8 rows using the full rotation of the "ring counter" that you've described?

How about the example of '41724246874135' that Luis used? Do you want just the first 3 rows from the "ring" or do you want the full "ring" of 14 rows?


--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

When you put the right degree of spin on it, the number 318 is also a glyph that describes the nature of a DBAs job. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
lsinoff
lsinoff
SSC Rookie
SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)

Group: General Forum Members
Points: 46 Visits: 6
Just the three rows. Some accounts are sent in by our clients with prefixes and/or suffixes and some of the accounts in our Data Base also have prefixes and/or suffixes. A match on any 7 consecutive characters, same last name and same date of birth will be considered an good match. I need to extract all the 7 character consecutive strings from our DB.
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