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


SQL /Procedure - for Transpose and Calculation


SQL /Procedure - for Transpose and Calculation

Author
Message
sudhirnune
sudhirnune
SSC-Enthusiastic
SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)

Group: General Forum Members
Points: 198 Visits: 252
Hi Team,

I have a Complex requirement.

Source:
--------
NAME PAYMENT_TYPE PAYMENT
SUDHIR SAL 30.3
SUDHIR ADV 10.3
SUDHIR ALL_1 10
SUDHIR ALL_2 10
SUDHIR ALL_3 10
MADHAV SAL 34
MADHAV ALL_1 24
MADHAV BONUS 10

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

Target Table:
------------
NAME SAL BONUS COMM
SUDHIR 20 0 10
MADHAV 34 10 24


Please need help to code SQL Query / Package which will take the Formula on from the table Formula and apply on Source before pushing it to target.

Thanks & Regards,
Sudhir Nune.
Mansfield
Mansfield
SSC-Addicted
SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)

Group: General Forum Members
Points: 424 Visits: 394
Use UNPIVOT to turn each PAYMENT_TYPE into its own column. See the following link.

Then your calculation should be easy Smile
sudhirnune
sudhirnune
SSC-Enthusiastic
SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)

Group: General Forum Members
Points: 198 Visits: 252
Thanks for the Reply, If you observe my Example, the Payment Type is not Static for all the user and payment Type has nearly 5000 types Sad

Writing Pivot is a Challenge with out clear understanding.

Also by Writing Pivot I am restricting the Payment types.

When Ever a new payment come's in I need to Append it to the query.

Please check if any such scenarios occured for any of you ???
Mansfield
Mansfield
SSC-Addicted
SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)SSC-Addicted (424 reputation)

Group: General Forum Members
Points: 424 Visits: 394
There is no need to hard-code each payment type in a pivot query. Dynamic SQL can take care of that.
sudhirnune
sudhirnune
SSC-Enthusiastic
SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)

Group: General Forum Members
Points: 198 Visits: 252
Thanks for the above input.

Now I am stuck to write a Dynamic SQL which will inter update the Data in the cursor, as per teh data format needed.

1. Formula is fetched into a Cursor form the Formula table.

2. Decla one more cursore which will fetch the data from the SQL Prepared to fetch the pivot data.

2. For loop is used to use the Formula data.

3. Need to write a SLQ Query whcih will update the target Columns SAL, BON, COM based on the formula.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16468 Visits: 19557
Is there one payment type which is common to all employees? For instance, 'SAL'? This could be very easy ...

“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
sudhirnune
sudhirnune
SSC-Enthusiastic
SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)

Group: General Forum Members
Points: 198 Visits: 252
the broblem is that I have multiple of such in my Scenarion
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16468 Visits: 19557
I understand that you have multiple payment types, and an employee may have several rows with different payment types.
Do ALL employees have at least one row with payment type of 'SAL'?

“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
sudhirnune
sudhirnune
SSC-Enthusiastic
SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)SSC-Enthusiastic (198 reputation)

Group: General Forum Members
Points: 198 Visits: 252
Yes they has SAL.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16468 Visits: 19557
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



“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
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