1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199
|
WITH V_CLE as (
SELECT usr.id as usr_id,
cle.clu_id,
cle.cou_id,
cle.gsa_id,
cle.apc_id,
rty.rty_code
FROM T_ROLE_TYPE_RTY rty
INNER JOIN
T_ROLE_ROL rol
ON rol.rty_id = rty.id
INNER JOIN
T_CLEARANCE_CLE cle
ON cle.rol_id = rol.id
INNER JOIN
T_USER_USR usr
ON usr.id = cle.usr_id
WHERE usr_id = 4
), LVL_NONE as (
SELECT apc.id as apc_id
FROM V_CLE cle
INNER JOIN
T_GSA_COU_APC apc
on 1=1
WHERE rty_code = 'NON'
), LVL_CLUSTER as (
SELECT apc.id as apc_id
FROM V_CLE cle
INNER JOIN
T_CLUSTER_CLU clu
ON clu.id = CLE.CLU_ID AND clu.deleted = 0
INNER JOIN
T_CLUSTSEG_CLS cls
ON clu.id = cls.clu_id AND cls.deleted = 0
INNER JOIN
T_GSA_GSA gsa
ON gsa.cls_id = cls.id AND gsa.deleted = 0
INNER JOIN
T_GSA_COU_APC apc
ON APC.GSA_ID = gsa.id AND apc.deleted = 0
WHERE rty_code = 'CLU'
), LVL_COUNTRY as (
SELECT apc.id as apc_id
FROM V_CLE cle
INNER JOIN
T_COUNTRY_COU cou
on cou.id = cle.cou_id AND cou.deleted = 0
INNER JOIN
T_GSA_COU_APC apc
on APC.COU_ID = cou.id AND apc.deleted = 0
WHERE rty_code = 'COU'
), LVL_GSA as (
SELECT apc.id as apc_id
FROM V_CLE cle
INNER JOIN
T_GSA_GSA gsa
ON cle.gsa_id = gsa.id AND gsa.deleted = 0
INNER JOIN
T_GSA_COU_APC apc
ON apc.gsa_id = gsa.id AND apc.deleted = 0
WHERE rty_code = 'ACC'
), LVL_APC as (
SELECT apc.id as apc_id
FROM V_CLE cle
INNER JOIN
T_GSA_COU_APC apc
ON cle.apc_id = apc.id AND apc.deleted = 0
WHERE rty_code = 'APC'
), LVL_CLC as (
SELECT apc.id as apc_id
FROM V_CLE cle
INNER JOIN
T_CLUSTER_CLU clu
ON clu.id = CLE.CLU_ID AND clu.deleted = 0
INNER JOIN
T_CLUSTSEG_CLS cls
ON clu.id = cls.clu_id AND cls.deleted = 0
INNER JOIN
T_GSA_GSA gsa
ON gsa.cls_id = cls.id AND gsa.deleted = 0
INNER JOIN
T_COUNTRY_COU cou
ON cle.cou_id = cou.id AND cou.deleted = 0
INNER JOIN
T_GSA_COU_APC apc
ON APC.GSA_ID = gsa.id AND apc.cou_id = cou.id and apc.deleted = 0
WHERE rty_code = 'CLC'
), V_TOT as (
SELECT distinct apc_id
FROM (
select apc_id
from LVL_NONE non
union all
select apc_id
from LVL_CLUSTER clu
union all
select apc_id
from LVL_COUNTRY cou
union all
select apc_id
from LVL_GSA gsa
union all
select apc_id
from LVL_APC apc
union all
select apc_id
from LVL_CLC clc
) tmp
), tmp AS (
SELECT yea.yea_year,
cou.id as cou_id,
cou.cou_name,
cls.id as cls_id,
cls.cls_name,
gsa.id as gsa_id,
gsa.gsa_name,
qua.id as qua_id,
qua.qua_quarter,
cast(round(sum(sal.SAL_AMO_EUR) / 1000000, 3) as number(10, 3)) as amount,
grouping_id(qua.qua_quarter) as grp_qua,
grouping_id (cou.cou_name) as grp_cou,
grouping_id (cls.cls_name) as grp_cls,
grouping_id (gsa.gsa_name) as grp_gsa
FROM t_sale_sal sal
INNER JOIN
v_tot tot
on tot.apc_id = sal.apc_id
INNER JOIN
t_gsa_cou_apc apc
on apc.id = sal.apc_id and apc.deleted = 0 and apc.apc_enabled = 1
INNER JOIN
t_country_cou cou
on cou.id = apc.cou_id and cou.deleted = 0
INNER JOIN
t_gsa_gsa gsa
on gsa.id = apc.gsa_id and gsa.deleted = 0
INNER JOIN
t_gsa_status_sta sta
on sta.id = gsa.sta_id and sta_code = 'OPR'
INNER JOIN
t_clustseg_cls cls
on cls.id = gsa.cls_id and cls.deleted = 0
INNER JOIN
t_sale_type_sat sat
on sal.sat_id = sat.id and sat.sat_code = 'NON'
INNER JOIN
t_activity_act act
on sal.act_id = act.id and act.deleted= 0 and act.act_enabled = 1
INNER JOIN
t_act_type_tac tac
on tac.id = act.tac_id and tac_code = 'ACT'
INNER JOIN
t_quarter_qua qua
on qua.id = sal.qua_id
INNER JOIN
t_year_yea yea
on yea.id = qua.yea_id
WHERE (yea.yea_year BETWEEN (2011 -2) AND (2011 -1)
AND trim(qua.qua_quarter) IN ('Q1', 'Q2', 'Q3', 'Q4')
)
OR ( yea.yea_year = 2011 AND trim(qua.qua_quarter) IN ('Q1', 'Q2', 'Q3', 'Q4') )
OR ( yea.yea_year = 2011 AND qua.qua_quarter = 'Q3' )
OR ( yea.yea_year = (2011 +1) AND qua_quarter = 'FQ1' )
GROUP BY yea.yea_year, CUBE ((qua.id, qua_quarter), (cls.id, cls.cls_name), (gsa.id, gsa.gsa_name), (cou.id, cou.cou_name))
)
SELECT tmp.*,
TRIM(typ.typ_code) as typ_code,
apc.id as apc_id
FROM tmp
LEFT JOIN
t_gsa_gsa gsa
on gsa.id = tmp.gsa_id and gsa.deleted = 0
LEFT JOIN
t_gsa_type_typ typ
on typ.id = gsa.typ_id
LEFT JOIN
t_gsa_cou_apc apc
on apc.gsa_id = tmp.gsa_id
and apc.cou_id = tmp.cou_id
and apc.deleted = 0
and apc.apc_enabled = 1
WHERE ( yea_year = 2011
AND ((grp_cou = 1 and grp_qua = 1 and grp_cls = 1 and grp_gsa = 1) OR
(grp_cou = 1 and grp_qua = 0 and grp_cls = 1 and grp_gsa = 1) OR
(grp_cou = 1 and grp_qua = 1 and grp_cls = 0 and grp_gsa = 1) OR
(grp_cou = 1 and grp_qua = 0 and grp_cls = 0 and grp_gsa = 1) OR
(grp_cou = 1 and grp_qua = 1 and grp_cls = 0 and grp_gsa = 0) OR
(grp_cou = 1 and grp_qua = 0 and grp_cls = 0 and grp_gsa = 0) OR
(grp_cou = 0 and grp_qua = 1 and grp_cls = 0 and grp_gsa = 0) OR
(grp_cou = 0 and grp_qua = 0 and grp_cls = 0 and grp_gsa = 0))
)
OR ( yea_year BETWEEN (2011 -2) AND (2011 -1)
AND ((grp_cou = 1 and grp_qua = 1 and grp_cls = 1 and grp_gsa = 1) OR
(grp_cou = 1 and grp_qua = 1 and grp_cls = 0 and grp_gsa = 1) OR
(grp_cou = 1 and grp_qua = 1 and grp_cls = 0 and grp_gsa = 0) OR
(grp_cou = 0 and grp_qua = 1 and grp_cls = 0 and grp_gsa = 0))
)
ORDER BY tmp.cls_name NULLS FIRST, tmp.cou_name NULLS FIRST, tmp.gsa_name NULLS FIRST, yea_year |