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


How to query results in debit and credit column


How to query results in debit and credit column

Author
Message
yingchai
yingchai
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 467
Hi SQL Gurus,

I would like to run a query to display the amount in a debit and credit column from a FACT table. The value appearing in the debit or credit column depends on the account sign in the ACCOUNT table.

FACT TABLE

ACCOUNT | ORGANIZATION | YEAR | PERIOD | AMOUNT
-----------------------------------------------------
1001 | aaa | 2012 | 01 | 100
1002 | aaa | 2012 | 01 | 50
1003 | aaa | 2012 | 01 | -100
1004 | aaa | 2012 | 01 | 90


ACCOUNT TABLE

ACCOUNT | DESC | SIGN
------------------------
1001 | 1001 | Dr
1002 | 1002 | Cr
1003 | 1003 | Dr
1004 | 1004 | Cr


How can I transform to this result?

ACCOUNT | ORGANIZATION | YEAR | PERIOD | Dr | Cr
-----------------------------------------------------
1001 | aaa | 2012 | 01 | 100 |
1002 | aaa | 2012 | 01 | | 50
1003 | aaa | 2012 | 01 | -100 |
1004 | aaa | 2012 | 01 | | 90


Below is the DDL and sample data for this:

DECLARE @ACCOUNT TABLE
(
ACCOUNT CHAR(4) NOT NULL,
DESC CHAR(4) NOT NULL,
SIGN CHAR(4) NOT NULL
)

DECLARE @FACT TABLE
(
ACCOUNT CHAR(4) NOT NULL,
ORGANIZATION CHAR(3) NOT NULL,
YEAR SMALLINT NOT NULL,
PERIOD CHAR(2) NOT NULL,
AMOUNT int NOT NULL
)

INSERT @ACCOUNT
VALUES ('1001', '1001', 'Dr'),
('1002', '1002', 'Cr'),
('1003', '1003', 'Dr'),
('1004', '1004', 'Cr')

INSERT @FACT
VALUES ('1001', 'aaa', 2012, '01', 100),
('1002', 'aaa', 2012, '01', 50),
('1003', 'aaa', 2012, '01', -100),
('1004', 'aaa', 2012, '01', 90)



Thanks.
Sony Francis @EY
Sony Francis @EY
SSC-Enthusiastic
SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)

Group: General Forum Members
Points: 107 Visits: 293
Try this,

SELECT Acc.Account,Fct.ORGANIZATION ,Fct .Year,Period,
CASE WHEN Acc .[SIGN]='Cr' THEN SUM(Fct.AMOUNT ) ELSE 0 END AS Cr,
CASE WHEN Acc.[SIGN]='Dr' THEN SUM(Fct.AMOUNT ) ELSE 0 END AS Dr
FROM #ACCOUNT Acc
INNER JOIN #FACT Fct ON Acc.ACCOUNT=Fct.ACCOUNT
GROUP BY Acc.Account,Fct.ORGANIZATION,Fct.Year,Period,Acc .[SIGN]
Lynn Pettis
Lynn Pettis
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39011 Visits: 38508
Not sure why you need the SUM or GROUP BY.



DECLARE @ACCOUNT TABLE
(
ACCOUNT CHAR(4) NOT NULL,
[DESC] CHAR(4) NOT NULL,
[SIGN] CHAR(4) NOT NULL
);

DECLARE @FACT TABLE
(
ACCOUNT CHAR(4) NOT NULL,
ORGANIZATION CHAR(3) NOT NULL,
[YEAR] SMALLINT NOT NULL,
PERIOD CHAR(2) NOT NULL,
AMOUNT int NOT NULL
);

INSERT @ACCOUNT
VALUES ('1001', '1001', 'Dr'),
('1002', '1002', 'Cr'),
('1003', '1003', 'Dr'),
('1004', '1004', 'Cr');

INSERT @FACT
VALUES ('1001', 'aaa', 2012, '01', 100),
('1002', 'aaa', 2012, '01', 50),
('1003', 'aaa', 2012, '01', -100),
('1004', 'aaa', 2012, '01', 90);

select
f.ACCOUNT,
f.ORGANIZATION,
f.[YEAR],
f.PERIOD,
case when [SIGN] = 'Dr' then cast(AMOUNT AS VARCHAR) else '' end Dr,
case when [SIGN] = 'Cr' then cast(AMOUNT AS VARCHAR) else '' end Cr
from
@ACCOUNT a
inner join @FACT f
on (a.ACCOUNT = f.ACCOUNT);




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)

Group: General Forum Members
Points: 7217 Visits: 6431
Lynn Pettis (6/14/2012)
Not sure why you need the SUM or GROUP BY.




I was going to say the same thing but I think Sony was assuming there might be duplicated rows (different transaction amounts) for account/org/year/month.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Lynn Pettis
Lynn Pettis
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39011 Visits: 38508
dwain.c (6/15/2012)
Lynn Pettis (6/14/2012)
Not sure why you need the SUM or GROUP BY.




I was going to say the same thing but I think Sony was assuming there might be duplicated rows (different transaction amounts) for account/org/year/month.


That's okay. Now I am wondering if this was also a homework problem.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)

Group: General Forum Members
Points: 7217 Visits: 6431
Lynn Pettis (6/15/2012) Now I am wondering if this was also a homework problem.



SELECT SolutionFor
FROM MyHomework
WHERE Solutionby = 'Lynn' OR Solutionby = 'Sony'




:-)


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
yingchai
yingchai
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 467
Thanks to all the feedback. It is actually a work problem, not a homework problem Smile
vinu512
vinu512
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1687 Visits: 1625
The Sql Server Gurus are really fast here at SSC. :-D

By the time I read the new thread, it was all done and dusted. :-P

Nice work Lynn and Dwain.

Vinu Vijayan

For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden ;-)
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: 16071 Visits: 19532
yingchai (6/15/2012)
Thanks to all the feedback. It is actually a work problem, not a homework problem Smile


It has few of the characteristics of a homework problem. Folks who are too idle to do their homework and post here hoping for a free ride are also, usually, too idle to give a full description of the problem or provide DDL and DML.
You did both ;-)

“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