/*похоже, надо делать фулл джойн между базовым и актуальным временными диапазонами, может быть, неявно актуальность соглашения зависит от времени. в нашем примере сначала актуально соглашение 0 */ --fix and payg select dayscale.dt::date ,siv.agreement_version as actual_version ,siv0.agreement_version as base_version ,a.agreement_version ,siv.quantity ,siv0.quantity ,a.probability_perc as actual_probability ,a0.probability_perc as base_probability ,a.is_actual, a0.is_actual --,sum(siv.price*siv.quantity*a.probability_perc/100/dayscale.days)+ sum(siv0.price*siv0.quantity*(100-a.probability_perc)/100/dayscale.days) ,(siv.price*siv.quantity*COALESCE(a.probability_perc,0)/100/dayscale.days) as rec1 ,(siv0.price*siv0.quantity*(100-COALESCE(a.probability_perc,0))/100/dayscale.days) as rec0 --,count(*) 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 join specification_item_version siv on (dayscale.dt >= siv.dt_from AND (siv.dt_to >= dayscale.dt OR siv.dt_to IS NULL)) left join specification_item si on (siv.specification_item_uid=si.specification_item_uid AND si.pricing_model_id in (2,3)) left join specification s on (si.specification_id=s.specification_id ) left 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) where 1=1 and d.contragent_id=3 order by 1