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 ««123»»

SQL /Procedure - for Transpose and Calculation Expand / Collapse
Author
Message
Posted Tuesday, April 9, 2013 4:31 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: 2 days ago @ 6:04 AM
Points: 1,127, Visits: 1,599
ChrisM@Work (4/9/2013)
sudhirnune (4/9/2013)
Yes they has SAL.


Thanks.

DROP TABLE #Sampledata
CREATE TABLE #Sampledata (NAME VARCHAR(25), PAYMENT_TYPE VARCHAR(10), PAYMENT DECIMAL(5,2))
INSERT INTO #Sampledata (NAME, PAYMENT_TYPE, PAYMENT)
SELECT 'SUDHIR', 'SAL', 30.3 UNION ALL
SELECT 'SUDHIR', 'ADV', 10.3 UNION ALL
SELECT 'SUDHIR', 'ALL_1', 10 UNION ALL
SELECT 'SUDHIR', 'ALL_2', 10 UNION ALL
SELECT 'SUDHIR', 'ALL_3', 10 UNION ALL
SELECT 'MADHAV', 'SAL', 34 UNION ALL
SELECT 'MADHAV', 'ALL_1', 24 UNION ALL
SELECT 'MADHAV', 'BONUS', 10

SELECT
s.NAME,
[SAL] = s.Payment-x.ADV,
[BONUS1] = (s.Payment-x.ADV) * 1.1, -- BONUS from formula
[BONUS2] = x.BONUS, -- BONUS from Target Table
[COMM] = x.[COMM+] - x.[COMM-]
FROM #Sampledata s
OUTER APPLY (
SELECT
[ADV] = SUM(CASE WHEN PAYMENT_TYPE = 'ADV' THEN PAYMENT ELSE 0 END),
[COMM+] = SUM(CASE WHEN PAYMENT_TYPE IN ('ALL_1','ALL_2') THEN PAYMENT ELSE 0 END),
[COMM-] = SUM(CASE WHEN PAYMENT_TYPE = 'ALL_3' THEN PAYMENT ELSE 0 END),
[BONUS] = SUM(CASE WHEN PAYMENT_TYPE = 'BONUS' THEN PAYMENT ELSE 0 END)
FROM #Sampledata si
WHERE si.NAME = s.NAME
AND si.PAYMENT_TYPE <> 'SAL'
) x
WHERE s.PAYMENT_TYPE = 'SAL'
ORDER BY s.NAME DESC



Nicely Done Chris.


Vinu Vijayan

For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden
Post #1440252
Posted Tuesday, April 9, 2013 4:46 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, March 6, 2014 11:47 PM
Points: 86, Visits: 214
CODE 1:

DECLARE @cols AS NVARCHAR(MAX),
@query AS NVARCHAR(MAX),
@cols2 AS NVARCHAR(MAX);

SET @cols = STUFF((SELECT distinct ',' + QUOTENAME(c.PAYMENT_TYPE)
FROM TEST_DATA_SRC c
FOR XML PATH(''), TYPE
).value('.', 'NVARCHAR(MAX)')
,1,1,'')
SET @Cols2 = SUBSTRING((SELECT DISTINCT ',ISNULL(['+PAYMENT_TYPE+'],0) AS ['+PAYMENT_TYPE+']' FROM TEST_DATA_SRC GROUP BY PAYMENT_TYPE FOR XML PATH('')),2,8000)


set @query = 'SELECT name, ' + @cols2 + ' from
(
select name
, payment
, payment_type
from TEST_DATA_SRC
) x
pivot
(
max(payment)
for payment_type in (' + @cols + ')
) p '


execute(@query)

Which helps me to pivot the Data and provide the needed outpout.

Below is teh Part of Stored proc whcih will Update the Data based on the Formula from the
TEST_FORMULA:

Procedure:
----------
DECLARE CUR_TEST_FORMULA CURSOR

--Get the Update Query created for executing the same on the Fact Data
FOR
SELECT 'Update TEST_TGT set '+ COA_CODE + ' = ' + COA_FORMULA +';'
FROM TEST_FORMULA

OPEN CUR_TEST_FORMULA
DECLARE @Q_SQL NVARCHAR(MAX)

FETCH NEXT FROM CUR_TEST_FORMULA INTO @Q_SQL
While @@FETCH_STATUS = 0
BEGIN

EXECUTE (@Q_SQL);

FETCH NEXT FROM CUR_TEST_FORMULA INTO @Q_SQL
END
CLOSE CUR_TEST_FORMULA
DEALLOCATE CUR_TEST_FORMULA

Need help to Update the procedure which will Update the Data in the Cursor and insert the detaisl to the TEST_TGT
Post #1440260
Posted Tuesday, April 9, 2013 5:22 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 6,826, Visits: 14,058
How many rows does the table TEST_FORMULA contain?
Can you post a few rows please?


“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 #1440270
Posted Tuesday, April 9, 2013 5:24 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 6,826, Visits: 14,058
vinu512 (4/9/2013)
...
Nicely Done Chris.


Thank you, Vinu. Insufficient information yet to determine whether or not it will be useful...


“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 #1440271
Posted Tuesday, April 9, 2013 5:27 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, March 6, 2014 11:47 PM
Points: 86, Visits: 214
Data in the Test Formula is

TGT_PAYMENT_TYPE PAYMENT_FORMULA
SAL SAL-ADV
COMM ALL_1+ALL_2-ALL_3
BONUS SAL * 1.1
Post #1440273
Posted Tuesday, April 9, 2013 5:42 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 6,826, Visits: 14,058
sudhirnune (4/9/2013)
Data in the Test Formula is

TGT_PAYMENT_TYPE PAYMENT_FORMULA
SAL SAL-ADV
COMM ALL_1+ALL_2-ALL_3
BONUS SAL * 1.1


There's only one formula in the table? Are you expecting more? If so, can you show how they might look?


“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 #1440277
Posted Tuesday, April 9, 2013 6:34 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, March 6, 2014 11:47 PM
Points: 86, Visits: 214
there are 3 formula....!

SAL = SAL-ADV
COMM = ALL_1+ALL_2-ALL_3
BONUS = SAL * 1.1
Post #1440289
Posted Tuesday, April 9, 2013 6:36 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 6,826, Visits: 14,058
sudhirnune (4/9/2013)
there are 3 formula....!

SAL = SAL-ADV
COMM = ALL_1+ALL_2-ALL_3
BONUS = SAL * 1.1


Did you test the query I posted above somewhere?


“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 #1440290
Posted Tuesday, April 9, 2013 6:41 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, March 6, 2014 11:47 PM
Points: 86, Visits: 214
Chris. I agree with your Query. My problem is that i need to make it Dynamic.

I can not use the Static way of implimenting this.

Can you please help me with the Stored proc which can update the data in the Cursor baed on my Formula.

I am looking forward for options to update my Procedure whcih i pasted in one of the posts.
Post #1440291
Posted Tuesday, April 9, 2013 6:44 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 6,826, Visits: 14,058
sudhirnune (4/9/2013)
Chris. I agree with your Query. My problem is that i need to make it Dynamic.

I can not use the Static way of implimenting this.

Can you please help me with the Stored proc which can update the data in the Cursor baed on my Formula.

I am looking forward for options to update my Procedure whcih i pasted in one of the posts.


That's straightforward enough. But first, can you explain a little why the query must be dynamic?


“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 #1440292
« Prev Topic | Next Topic »

Add to briefcase ««123»»

Permissions Expand / Collapse