diff --git a/Application.cfc b/Application.cfc index e85ed3f..ea85241 100644 --- a/Application.cfc +++ b/Application.cfc @@ -60,6 +60,10 @@ + + + + @@ -69,13 +73,15 @@ - + + + - + + + + + + + + + + + + + + + + + + + + + + + + + + select + --install + DATE_TRUNC('month', dayscale.dt)::date as m + ,dayscale.dt::date + ,siv.price as price_i + ,siv.quantity as quantity_i + ,siv0.price as price0_i + ,siv0.quantity as quantity0_i + ,a.is_actual as is_actual_i + ,a.probability_perc as p_i + ,(100-COALESCE(a.probability_perc,0)) as p_i_rest + ,siv.specification_item_uid as si_uid_i + ,siv.agreement_version as av_i + ,siv0.specification_item_uid as si_uid0_i + ,siv0.agreement_version as av0_i + ,null as price_f + ,null as quantity_f + ,null as price0_f + ,null as quantity0_f + ,null as is_actual_f + ,null as p_f + ,null as p_f_rest + ,null as cost_f + ,null as cost_month_f + ,null as dt_from_f + ,null as dt_to_f + ,null as dt_from0_f + ,null as dt_to0_f + ,null as si_uid_f + ,null as av_f + ,null as si_uid0_f + ,null as av0_f + + from (SELECT dd::date as dt FROM generate_series( + '#DAYSCALE_START#'::timestamp + ,'#DAYSCALE_FINISH#'::timestamp + ,'1 day'::interval) dd + ) dayscale + left outer join specification_item_version siv on (dayscale.dt=siv.dt_from) + left outer join specification_item si on (siv.specification_item_uid=si.specification_item_uid AND si.pricing_model_id in (1)) + left outer join specification s on (si.specification_id=s.specification_id) + left outer join agreement a on (s.contract_id=a.contract_id AND siv.agreement_version=a.agreement_version AND a.agreement_version=(select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=si.specification_item_uid + --AND ia.is_actual + )) + join contract d on s.contract_id=d.contract_id + join contragent k on d.contragent_id=k.contragent_id + join svc on (si.svc_id=svc.svc_id) + left outer join agreement a0 on (s.contract_id=a0.contract_id AND a0.agreement_version=(select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=si.specification_item_uid + AND ia.agreement_version < a.agreement_version + AND ia.is_actual + )) + left outer join specification_item_version siv0 on (siv0.specification_item_uid=si.specification_item_uid + AND siv0.agreement_version=a0.agreement_version AND (dayscale.dt=siv0.dt_from)) + where 1=1 + + union all + + --fix and payg + select + DATE_TRUNC('month', dayscale.dt)::date as m + ,dayscale.dt::date + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.quantity + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.price + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.quantity + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,a.is_actual as is_actual_f + ,a.probability_perc as p_f + ,(100-COALESCE(a.probability_perc,0)) as p_f_rest + + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price/dayscale.monthdays*siv.quantity*a.probability_perc/100 + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + + + COALESCE(case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.price/dayscale.monthdays*siv0.quantity*(100- a.probability_perc)/100 + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end,0) + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price*siv.quantity*a.probability_perc/100 + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + + + COALESCE(case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.price*siv0.quantity*(100- a.probability_perc)/100 + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end,0) + ,siv.dt_from + ,siv.dt_to + ,siv0.dt_from + ,siv0.dt_to + ,siv.specification_item_uid + ,siv.agreement_version + ,siv0.specification_item_uid + ,siv0.agreement_version + + + from (SELECT dd::date as dt + , DATE_PART('days', DATE_TRUNC('month', dd) + '1 MONTH'::INTERVAL - '1 DAY'::INTERVAL) monthdays + FROM generate_series( + '#DAYSCALE_START#'::timestamp + ,'#DAYSCALE_FINISH#'::timestamp + ,'1 day'::interval) dd + ) dayscale + left outer join specification_item_version siv on (dayscale.dt >= siv.dt_from /*AND (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL)*/ + AND siv.agreement_version=(select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=siv.specification_item_uid + AND (dayscale.dt >= iiv.dt_from /*AND (iiv.dt_to > dayscale.dt OR iiv.dt_to IS NULL)*/))) + /*AND ia.is_actual*/ /*свежее соглашение не обязано быть действующим*/ + join specification_item si on (siv.specification_item_uid=si.specification_item_uid AND si.pricing_model_id in (2,3)) + join specification s on (si.specification_id=s.specification_id) + join agreement a on (s.contract_id=a.contract_id AND a.agreement_version=siv.agreement_version) + join contract d on s.contract_id=d.contract_id + join contragent k on d.contragent_id=k.contragent_id + join svc on (si.svc_id=svc.svc_id) + -- находим предыдущее действующее соглашение + -- если свежее соглашение действует, то впр + -- нам нужно, чтобы в прошлом (до dt_from свежего соглашения) свежак был прозрачен, + -- а в будущем (после dt_to) факт перетирался свежим соглашением + left outer join agreement a0 on (s.contract_id=a0.contract_id AND a0.agreement_version=( + select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=si.specification_item_uid + AND ia.agreement_version < siv.agreement_version + AND ia.is_actual /*именно действующее соглашение, принимаемое за факт*/ + ) + ) + left outer join specification_item_version siv0 on (siv0.specification_item_uid=si.specification_item_uid + AND siv0.agreement_version=a0.agreement_version AND (dayscale.dt >= siv0.dt_from /*AND (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL)*/)) + where 1=1 + +order by dt + + + + + + + + + + + + + + + + + + + Выручка по дням 2023-01-01 .. 2029-12-31 + + + + + + + + + +
+ #qRead.recordCount# записей + + +
+ Дни и месяцы без данных не показаны. + Инсталл и ежемес могут генерировать отдельные строки на один день. + Вариант с локальной рабочей версией строки (инстанса) + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
ДатаИнсталл рабочаяИнсталл базоваяЕжемес рабочаяЕжемес базоваяЕжемес
#dateFormat(dt,"YYYY-MM-DD")# + + + (#myNumFmt(price_i)#*#quantity_i#*#p_i#%(#p_i_rest#%) +
+
+
+ + + #myNumFmt(price0_i)#*#quantity0_i# +
+
+
+ + + + [#av_f#] + #myNumFmt(price_f)#*#quantity_f#*#p_f#%(#p_f_rest#%) + #dateFormat(dt_from_f,'YYYY-MM-DD')# - #dateFormat(dt_to_f,'YYYY-MM-DD')# +
+
+
+
+ + + + [#av0_f#] + #myNumFmt(price0_f)#*#quantity0_f# + #dateFormat(dt_from0_f,'YYYY-MM-DD')# - #dateFormat(dt_to0_f,'YYYY-MM-DD')# +
+
+
+
#myNumFmt(cost_month_f)# | #myNumFmt(cost_f)#
+
+ +
+ diff --git a/inc/menu.cfm b/inc/menu.cfm index f7dc591..977e58c 100644 --- a/inc/menu.cfm +++ b/inc/menu.cfm @@ -18,6 +18,7 @@ + diff --git a/income_daily_rpt.cfm b/income_daily_rpt.cfm index 4d5fb9d..b723d08 100644 --- a/income_daily_rpt.cfm +++ b/income_daily_rpt.cfm @@ -53,8 +53,8 @@ from ( ,0 as rec0 ,count(*) as cnt from (SELECT dd::date as dt FROM generate_series( - '2023-01-01'::timestamp - ,'2029-12-31'::timestamp + '#DAYSCALE_START#'::timestamp + ,'#DAYSCALE_FINISH#'::timestamp ,'1 day'::interval) dd ) dayscale left outer join specification_item_version siv on (dayscale.dt=siv.dt_from) @@ -92,7 +92,7 @@ from ( ,0 ,0 ,0 - ,COALESCE(sum( + + + ,sum( + COALESCE(case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price*siv.quantity*( + case when a.is_actual then 100 else a.probability_perc end + )/100/dayscale.monthdays + else 0 /*по окончании рабочей сделки она дает нулевой вклад*/ + end,0) + + + COALESCE(case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.price/dayscale.monthdays*siv0.quantity*(100- COALESCE( + case when a.is_actual then 100 else a.probability_perc end + ,0))/100 + else 0 /*по окончании базовой сделки она дает нулевой вклад*/ + end,0) + ) ,sum( case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then siv.price*siv.quantity*COALESCE( case when a.is_actual then 100 else a.probability_perc end - ,0)/100/dayscale.days + ,0)/100/dayscale.monthdays else 0 end ) @@ -122,17 +138,16 @@ from ( .dt_to IS NULL) then 0 else siv0.price*siv0.quantity*(100-COALESCE( case when a.is_actual then 100 else a.probability_perc end - ,0))/100/dayscale.days - --else 0 + ,0))/100/dayscale.monthdays end ) ,count(*) from (SELECT dd::date as dt - , DATE_PART('days', DATE_TRUNC('month', dd) + '1 MONTH'::INTERVAL - '1 DAY'::INTERVAL) days + , DATE_PART('days', DATE_TRUNC('month', dd) + '1 MONTH'::INTERVAL - '1 DAY'::INTERVAL) monthdays FROM generate_series( - '2023-01-01'::timestamp - ,'2029-12-31'::timestamp + '#DAYSCALE_START#'::timestamp + ,'#DAYSCALE_FINISH#'::timestamp ,'1 day'::interval) dd ) dayscale left outer join specification_item_version siv on (dayscale.dt >= siv.dt_from /*AND (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL)*/ diff --git a/income_daily_rpt.old.cfm b/income_daily_rpt.old.cfm new file mode 100644 index 0000000..d6bd512 --- /dev/null +++ b/income_daily_rpt.old.cfm @@ -0,0 +1,416 @@ + + + + + + + + + + + + + + + + + + + + + + + + + + select + --install + DATE_TRUNC('month', dayscale.dt)::date as m + ,dayscale.dt::date + ,siv.price as price_i + ,siv.quantity as quantity_i + ,siv0.price as price0_i + ,siv0.quantity as quantity0_i + ,a.is_actual as is_actual_i + ,a.probability_perc as p_i + ,(100-COALESCE(a.probability_perc,0))/100 as p_i_rest + ,siv.specification_item_uid as si_uid_i + ,siv.agreement_version as av_i + ,siv0.specification_item_uid as si_uid0_i + ,siv0.agreement_version as av0_i + ,null as price_f + ,null as quantity_f + ,null as price0_f + ,null as quantity0_f + ,null as is_actual_f + ,null as p_f + ,null as p_f_rest + ,null as sum_f + ,null as dt_from_f + ,null as dt_to_f + ,null as dt_from0_f + ,null as dt_to0_f + ,null as si_uid_f + ,null as av_f + ,null as si_uid0_f + ,null as av0_f + + from (SELECT dd::date as dt FROM generate_series( + '2023-01-01'::timestamp + ,'2029-12-31'::timestamp + ,'1 day'::interval) dd + ) dayscale + left outer join specification_item_version siv on (dayscale.dt=siv.dt_from) + left outer join specification_item si on (siv.specification_item_uid=si.specification_item_uid AND si.pricing_model_id in (1)) + left outer join specification s on (si.specification_id=s.specification_id) + left outer join agreement a on (s.contract_id=a.contract_id AND siv.agreement_version=a.agreement_version AND a.agreement_version=(select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=si.specification_item_uid + --AND ia.is_actual + )) + join contract d on s.contract_id=d.contract_id + join contragent k on d.contragent_id=k.contragent_id + join svc on (si.svc_id=svc.svc_id) + left outer join agreement a0 on (s.contract_id=a0.contract_id AND a0.agreement_version=(select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=si.specification_item_uid + AND ia.agreement_version < a.agreement_version + AND ia.is_actual + )) + left outer join specification_item_version siv0 on (siv0.specification_item_uid=si.specification_item_uid + AND siv0.agreement_version=a0.agreement_version AND (dayscale.dt=siv0.dt_from)) + where 1=1 + + union all + + --fix and payg + select + DATE_TRUNC('month', dayscale.dt)::date as m + ,dayscale.dt::date + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,null + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.quantity + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.price + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.quantity + /*до окончания свежей сделки она суммируется с прошлой актуальной по правилу вероятностей, считая вероятность актуальной за сделки за 1*/ + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + ,a.is_actual as is_actual_f + ,a.probability_perc as p_f + ,(100-COALESCE(a.probability_perc,0))/100 as p_f_rest + + ,case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price/dayscale.days*siv.quantity*a.probability_perc/100 + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end + + + COALESCE(case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv.price/dayscale.days*siv.quantity*(100- a.probability_perc)/100 + else 0 /*по окончании свежей сделки она дает нулевой вклад*/ + end,0) + ,siv.dt_from + ,siv.dt_to + ,siv0.dt_from + ,siv0.dt_to + ,siv.specification_item_uid + ,siv.agreement_version + ,siv0.specification_item_uid + ,siv0.agreement_version + + + from (SELECT dd::date as dt + , DATE_PART('days', DATE_TRUNC('month', dd) + '1 MONTH'::INTERVAL - '1 DAY'::INTERVAL) days + FROM generate_series( + '2023-01-01'::timestamp + ,'2029-12-31'::timestamp + ,'1 day'::interval) dd + ) dayscale + left outer join specification_item_version siv on (dayscale.dt >= siv.dt_from /*AND (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL)*/ + AND siv.agreement_version=(select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=siv.specification_item_uid + AND (dayscale.dt >= iiv.dt_from /*AND (iiv.dt_to > dayscale.dt OR iiv.dt_to IS NULL)*/))) + /*AND ia.is_actual*/ /*свежее соглашение не обязано быть действующим*/ + join specification_item si on (siv.specification_item_uid=si.specification_item_uid AND si.pricing_model_id in (2,3)) + join specification s on (si.specification_id=s.specification_id) + join agreement a on (s.contract_id=a.contract_id AND a.agreement_version=siv.agreement_version) + join contract d on s.contract_id=d.contract_id + join contragent k on d.contragent_id=k.contragent_id + join svc on (si.svc_id=svc.svc_id) + -- находим предыдущее действующее соглашение + -- если свежее соглашение действует, то впр + -- нам нужно, чтобы в прошлом (до dt_from свежего соглашения) свежак был прозрачен, + -- а в будущем (после dt_to) факт перетирался свежим соглашением + left outer join agreement a0 on (s.contract_id=a0.contract_id AND a0.agreement_version=( + select max(iiv.agreement_version) from specification_item_version iiv + join specification_item ii on (iiv.specification_item_uid=ii.specification_item_uid) + join specification isp on (ii.specification_id=isp.specification_id) + join agreement ia on (isp.contract_id=ia.contract_id AND iiv.agreement_version=ia.agreement_version) + where iiv.specification_item_uid=si.specification_item_uid + AND ia.agreement_version < siv.agreement_version + AND ia.is_actual /*именно действующее соглашение, принимаемое за факт*/ + ) + ) + left outer join specification_item_version siv0 on (siv0.specification_item_uid=si.specification_item_uid + AND siv0.agreement_version=a0.agreement_version AND (dayscale.dt >= siv0.dt_from /*AND (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL)*/)) + where 1=1 + +order by dt + + + + + + + + + + + + + + + + + + + Выручка по дням 2023-01-01 .. 2029-12-31 + + + + + + + + + +
+ #qRead.recordCount# записей + + +
+ Дни и месяцы без данных не показаны. + Инсталл и ежемес могут генерировать отдельные строки на один день. + Вариант с локальной рабочей версией строки (инстанса) + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
ДатаИнсталл рабочаяИнсталл базоваяЕжемес рабочаяЕжемес базоваяЕжемес
#dateFormat(dt,"YYYY-MM-DD")# + + + #myNumFmt(price_i)#*#quantity_i#*#p_i#(#p_i_rest#) + + + + + + #myNumFmt(price0_i)#*#quantity0_i# + + + + + + #myNumFmt(price_f)#*#quantity_f#*#p_f#(#p_f_rest#) + #dateFormat(dt_from_f,'YYYY-MM-DD')# - #dateFormat(dt_to_f,'YYYY-MM-DD')# + + + + + + #myNumFmt(price0_f)#*#quantity0_f# + #dateFormat(dt_from0_f,'YYYY-MM-DD')# - #dateFormat(dt_to0_f,'YYYY-MM-DD')# + + + #myNumFmt(sum_f)#
+
+ + + +  +
+ + + select m + , sum(income_install) as income_install + , sum(income_recurring) as income_recurring + , sum(income) as income + from qRead + group by m + order by m + +
+ Суммировано по месяцам: + + + + + + + + + + + + + + + + + + + +
МесяцИнсталлЕжемесВыручка
#dateFormat(m,"MM.YYYY")##myNumFmt(income_install)##myNumFmt(income_recurring)##myNumFmt(income)#
+
+ +
+ + + + \ No newline at end of file diff --git a/income_monthly_rpt.cfm b/income_monthly_rpt.cfm index e21ad8a..9c62732 100644 --- a/income_monthly_rpt.cfm +++ b/income_monthly_rpt.cfm @@ -46,9 +46,9 @@ from ( ) as income_install ,0 as income_recurring from - (SELECT dd::date as dt FROM generate_series - ( '2023-01-01'::timestamp - , '2029-12-31'::timestamp + (SELECT dd::date as dt FROM generate_series ( + '#DAYSCALE_START#'::timestamp + ,'#DAYSCALE_FINISH#'::timestamp , '1 day'::interval) dd) dayscale join specification_item_version siv on (dayscale.dt=siv.dt_from) join specification_item si on (siv.specification_item_uid=si.specification_item_uid AND si.pricing_model_id in (1)) @@ -81,14 +81,14 @@ from ( select DATE_TRUNC('month', dayscale.dt)::date as m ,0 - /*,sum(siv.price*siv.quantity*a.probability_perc/100/dayscale.days - + COALESCE(siv0.price*siv0.quantity*(100-a.probability_perc)/100/dayscale.days, 0) + /*,sum(siv.price*siv.quantity*a.probability_perc/100/dayscale.monthdays + + COALESCE(siv0.price*siv0.quantity*(100-a.probability_perc)/100/dayscale.monthdays, 0) )*/ - ,COALESCE(sum( + + ,sum( + COALESCE(case when (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL) then + siv.price*siv.quantity*( + case when a.is_actual then 100 else a.probability_perc end + )/100/dayscale.monthdays + else 0 /*по окончании рабочей сделки она дает нулевой вклад*/ + end,0) + + + COALESCE(case when (siv0.dt_to > dayscale.dt OR siv0.dt_to IS NULL) then + siv0.price/dayscale.monthdays*siv0.quantity*(100- COALESCE( + case when a.is_actual then 100 else a.probability_perc end + ,0))/100 + else 0 /*по окончании базовой сделки она дает нулевой вклад*/ + end,0) + ) from (SELECT dd::date as dt - , DATE_PART('days', DATE_TRUNC('month', dd) + '1 MONTH'::INTERVAL - '1 DAY'::INTERVAL) days + , DATE_PART('days', DATE_TRUNC('month', dd) + '1 MONTH'::INTERVAL - '1 DAY'::INTERVAL) monthdays FROM generate_series( - '2023-01-01'::timestamp - ,'2029-12-31'::timestamp + '#DAYSCALE_START#'::timestamp + ,'#DAYSCALE_FINISH#'::timestamp ,'1 day'::interval) dd ) dayscale left outer join specification_item_version siv on (dayscale.dt >= siv.dt_from /*AND (siv.dt_to > dayscale.dt OR siv.dt_to IS NULL)*/ @@ -196,12 +211,12 @@ select count(*) as cnt from specification_item where 1=1 #dateFormat(m,"MM.YYYY")# - #myNumFmt(income_install)# - #myNumFmt(income_recurring)# - #myNumFmt(income)# - #myNumFmt(safeNum(income) - income_old)# + #myNumFmt(income_install)# + #myNumFmt(income_recurring)# + #myNumFmt(income)# + #myNumFmt(safeNum(income) - income_old)# - #myNumFmt(income_recurring-income_recurring_old)# + #myNumFmt(income_recurring-income_recurring_old)#