Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How this works? Expand / Collapse
Author
Message
Posted Thursday, July 24, 2014 8:11 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, October 13, 2014 4:33 AM
Points: 141, Visits: 403
Hi there ,

I got this code from web, I cant understand how it works

can anybody suggest me with links or explanations about the below used techniques.

DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

;WITH Numbers(N) AS (
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
)
SELECT
id,
data_reversed
FROM @t T1
CROSS APPLY(
SELECT
SUBSTRING(data,N,1)
FROM @t T2 JOIN Numbers ON N<=LEN(data)
WHERE T1.id=T2.id
ORDER BY N DESC
FOR XML PATH('')
)x(data_reversed)
ORDER BY id DESC

Post #1595903
Posted Thursday, July 24, 2014 8:29 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:03 AM
Points: 6,805, Visits: 14,022
-- make a table with two rows, two columns
DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'
SELECT * FROM @t
GO
----------------------------------------------------------------------------------------------------

DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

-- a CTE which provides n rows containing values 1 through n,
-- where n is the longest word in column [data]
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
GO
----------------------------------------------------------------------------------------------------

DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

-- pick the letters from [data] one by one, putting each one on a separate row of the output
;WITH Numbers(N) AS (
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
)
SELECT T2.id, N,
SUBSTRING(data,N,1)
FROM @t T2 JOIN Numbers ON N<=LEN(data)
--WHERE T1.id=T2.id
ORDER BY T2.id, N DESC -- added T2.id for clarity
--FOR XML PATH('')
GO
----------------------------------------------------------------------------------------------------

-- finally, FOR XML PATH concatenates the values from each row (for each id)
-- ORDER BY N DESC ensures that the letters are concatenated in the reverse order from collection.
DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

;WITH Numbers(N) AS (
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
)
SELECT
id,
data_reversed
FROM @t T1
CROSS APPLY(
SELECT
SUBSTRING(data,N,1)
FROM @t T2 JOIN Numbers ON N<=LEN(data)
WHERE T1.id=T2.id
ORDER BY N DESC
FOR XML PATH('')
)x(data_reversed)
ORDER BY id DESC

----------------------------------------------------------------------------------------------------



“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
Post #1595909
Posted Thursday, July 24, 2014 8:30 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:03 AM
Points: 6,805, Visits: 14,022
vignesh.ms (7/24/2014)
Hi there ,

I got this code from web, I cant understand how it works

can anybody suggest me with links or explanations about the below used techniques.

.
.
.


An excellent article here.


“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
Post #1595911
Posted Thursday, July 24, 2014 8:37 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 9:43 PM
Points: 3,783, Visits: 8,482
I hope that you're using that code for learning purposes only and not instead of REVERSE() function.


Luis C.
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?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1595914
Posted Friday, July 25, 2014 4:11 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, October 13, 2014 4:33 AM
Points: 141, Visits: 403
Luis Cazares (7/24/2014)
I hope that you're using that code for learning purposes only and not instead of REVERSE() function.


yes of course
Post #1596147
Posted Friday, July 25, 2014 4:34 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, October 13, 2014 4:33 AM
Points: 141, Visits: 403
ChrisM@Work (7/24/2014)
-- make a table with two rows, two columns
DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'
SELECT * FROM @t
GO
----------------------------------------------------------------------------------------------------

DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

-- a CTE which provides n rows containing values 1 through n,
-- where n is the longest word in column [data]
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
GO
----------------------------------------------------------------------------------------------------

DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

-- pick the letters from [data] one by one, putting each one on a separate row of the output
;WITH Numbers(N) AS (
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
)
SELECT T2.id, N,
SUBSTRING(data,N,1)
FROM @t T2 JOIN Numbers ON N<=LEN(data)
--WHERE T1.id=T2.id
ORDER BY T2.id, N DESC -- added T2.id for clarity
--FOR XML PATH('')
GO
----------------------------------------------------------------------------------------------------

-- finally, FOR XML PATH concatenates the values from each row (for each id)
-- ORDER BY N DESC ensures that the letters are concatenated in the reverse order from collection.
DECLARE @t TABLE( ID INT IDENTITY, data VARCHAR(20))
INSERT INTO @t(data) SELECT 'Jacob'
INSERT INTO @t(data) SELECT 'Sebastian'

;WITH Numbers(N) AS (
SELECT DISTINCT Number
FROM master..spt_values
WHERE Number BETWEEN 1 AND (SELECT MAX(LEN(data))FROM @t)
)
SELECT
id,
data_reversed
FROM @t T1
CROSS APPLY(
SELECT
SUBSTRING(data,N,1)
FROM @t T2 JOIN Numbers ON N<=LEN(data)
WHERE T1.id=T2.id
ORDER BY N DESC
FOR XML PATH('')
)x(data_reversed)
ORDER BY id DESC

----------------------------------------------------------------------------------------------------



Good explanation...

Splitting query into chunks make me understand easily. Really its very useful to me. Thanks for your time & effort..
Post #1596150
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse