Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Query too long

Author  Topic 

NaeemK
Starting Member

10 Posts

Posted - 2011-05-19 : 06:14:37
Hi, I was wondering if anyone can suggest a better way of doing the below extraction?


SELECT
'A' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'A%'
UNION
SELECT
'B' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'B%'
UNION
SELECT
'C' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'C%'
UNION
SELECT
'D' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'D%'
UNION
SELECT
'E' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'E%'
UNION
SELECT
'F' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'F%'
UNION
SELECT
'G' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'G%'
UNION
SELECT
'H' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'H%'
UNION
SELECT
'I' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'I%'
UNION
SELECT
'J' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'J%'
UNION
SELECT
'K' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'K%'
UNION
SELECT
'L' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'L%'
UNION
SELECT
'M' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'M%'
UNION
SELECT
'N' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'N%'
UNION
SELECT
'O' AS [Mosaic], COUNT (PN_ID) AS [COUNT],
SUM (ConfBookNo) AS [ConfBookNo], SUM (ConfBookVal) AS [ConfBookVal],
SUM (CancBookNo) AS [CancBookNo], SUM (CancBookVal) AS [CancBookVal],
SUM (TotBookNo) AS [TotBookNo], SUM (TotBookVal) AS [TotBookVal],
SUM (HandbookNo) AS [HandbookNo], SUM (HandbookVal) AS [HandbookVal],
SUM (DonationNo) AS [DonationNo], SUM (DonationVal) AS [DonationVal],
SUM (HandbookOnly) AS [HandbookOnly], SUM (Booker1) AS [Booker1], SUM (Booker2) AS [Booker2], SUM ([Booker3+]) AS [Booker3+]
FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 LIKE 'O%'

SELECT 'A' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'A%' UNION
SELECT 'B' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'B%' UNION
SELECT 'C' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'C%' UNION
SELECT 'D' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'D%' UNION
SELECT 'E' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'E%' UNION
SELECT 'F' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'F%' UNION
SELECT 'G' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'G%' UNION
SELECT 'H' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'H%' UNION
SELECT 'I' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'I%' UNION
SELECT 'J' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'J%' UNION
SELECT 'K' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'K%' UNION
SELECT 'L' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'L%' UNION
SELECT 'M' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'M%' UNION
SELECT 'N' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'N%' UNION
SELECT 'O' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'O%' UNION
SELECT 'Other' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis
WHERE PN_USERCHAR_5 NOT LIKE 'A%'
AND PN_USERCHAR_5 NOT LIKE 'B%'
AND PN_USERCHAR_5 NOT LIKE 'C%'
AND PN_USERCHAR_5 NOT LIKE 'D%'
AND PN_USERCHAR_5 NOT LIKE 'E%'
AND PN_USERCHAR_5 NOT LIKE 'F%'
AND PN_USERCHAR_5 NOT LIKE 'G%'
AND PN_USERCHAR_5 NOT LIKE 'H%'
AND PN_USERCHAR_5 NOT LIKE 'I%'
AND PN_USERCHAR_5 NOT LIKE 'J%'
AND PN_USERCHAR_5 NOT LIKE 'K%'
AND PN_USERCHAR_5 NOT LIKE 'L%'
AND PN_USERCHAR_5 NOT LIKE 'M%'
AND PN_USERCHAR_5 NOT LIKE 'N%'
AND PN_USERCHAR_5 NOT LIKE 'O%'

raghuveer125
Constraint Violating Yak Guru

285 Posts

Posted - 2011-05-19 : 06:21:58
Hint: Want your questions answered fast? Follow the direction in this link
http://weblogs.sqlteam.com/brettk/archive/2005/05/25/5276.aspx

In Love... With Me!
Go to Top of Page

nigelrivett
Master Smack Fu Yak Hacker

3385 Posts

Posted - 2011-05-19 : 07:09:15
SELECT
left(PN_USERCHAR_5,1) AS [Mosaic]
, COUNT (PN_ID) AS [COUNT]
, SUM (ConfBookNo) AS [ConfBookNo]
...
from Alice_Working..MosaicAnalysis
where left(PN_USERCHAR_5,1) in ('A','B',...)
group by left(PN_USERCHAR_5,1)


==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page

NaeemK
Starting Member

10 Posts

Posted - 2011-05-19 : 08:12:18
thank you. I will try this out.
Go to Top of Page

NaeemK
Starting Member

10 Posts

Posted - 2011-05-20 : 04:39:22
Hey nigel, that worked a treat and is much neater and efficent. Thank you very much.
Go to Top of Page
   

- Advertisement -