| 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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'A%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'B%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'C%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'D%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'E%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'F%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'G%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'H%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'I%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'J%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'K%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'L%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'M%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'N%'UNIONSELECT '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..MosaicAnalysisWHERE PN_USERCHAR_5 LIKE 'O%'SELECT 'A' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'A%' UNIONSELECT 'B' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'B%' UNIONSELECT 'C' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'C%' UNIONSELECT 'D' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'D%' UNIONSELECT 'E' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'E%' UNIONSELECT 'F' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'F%' UNIONSELECT 'G' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'G%' UNIONSELECT 'H' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'H%' UNIONSELECT 'I' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'I%' UNIONSELECT 'J' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'J%' UNIONSELECT 'K' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'K%' UNIONSELECT 'L' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'L%' UNIONSELECT 'M' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'M%' UNIONSELECT 'N' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'N%' UNIONSELECT 'O' AS [Mosaic], COUNT (PN_ID) AS [COUNT] FROM Alice_Working..MosaicAnalysis WHERE PN_USERCHAR_5 LIKE 'O%' UNIONSELECT '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 |
|
|
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..MosaicAnalysiswhere 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. |
 |
|
|
NaeemK
Starting Member
10 Posts |
Posted - 2011-05-19 : 08:12:18
|
| thank you. I will try this out. |
 |
|
|
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. |
 |
|
|
|
|
|