Help with query calculations (recursive)

Advertisement
Hi All,
I want some help with a query using a base rate and the result use in the next calculation year.
Here an example:
create table rate_type(
rate_type_id    number,
rate_desc       nvarchar2(50),
rate_base_year  number
insert into rate_type(rate_type_id, rate_desc, rate_base_year) values (1, 'Desc1', 4.6590);
insert into rate_type(rate_type_id, rate_desc, rate_base_year) values (2, 'Desc2', 4.6590);
create table rates (
rate_type_id number
rate_year    number,
rate_value   number
insert into rates(rate_type_id, rate_year, rate_value) values (1, 2012, 1.2);
insert into rates(rate_type_id, rate_year, rate_value) values (1, 2013, 1.3);
insert into rates(rate_type_id, rate_year, rate_value) values (1, 2014, 1.4);
insert into rates(rate_type_id, rate_year, rate_value) values (2, 2012, 1.2);
insert into rates(rate_type_id, rate_year, rate_value) values (2, 2013, 1.3);
insert into rates(rate_type_id, rate_year, rate_value) values (2, 2014, 1.4);The calculation for the first year should be the base rate of the rate type. The next year should use the result of the previous year and so on.
The result of my sample data is:
2012 = 4.659 + 1.2 + 4.659 * (1.2 * 0.01) = 5.9149
2013 = 5.9149 + 1.3 + 5.9149 * (1.3 * 0.01) = 7.1859
2014 = 7.1859 + 1.4 + 7.1859 * (1.4 * 0.01) = 8.4721Query result:
NAME 2012 2013 2014
Desc1 5.9149 7.1859 8.4721
Desc2 XXXX XXX XXXX
How can I do this in one select statement? Any ideas?
Thanks!
Advertisement

Replay

Assuming you are on 11.2:
with t as (
           select  a.rate_type_id,
                   rate_desc,
                   rate_year,
                   rate_base_year,
                   rate_value,
                   count(*) over(partition by a.rate_type_id) cnt,
                   row_number() over(partition by a.rate_type_id order by rate_year) rn
             from  rate_type a,
                   rates b
             where a.rate_type_id = b.rate_type_id
    r(
      rate_type_id,
      rate_desc,
      rate_year,
      rate_base_year,
      rate_value,
      cnt,
      rn,
      result
     ) as (
            select  rate_type_id,
                    rate_desc,
                    rate_year,
                    rate_base_year,
                    rate_value,
                    cnt,
                    rn,
                    rate_base_year + rate_value + rate_base_year * rate_value * 0.01 result
              from  t
              where rn = 1
           union all
            select  t.rate_type_id,
                    t.rate_desc,
                    t.rate_year,
                    t.rate_base_year,
                    t.rate_value,
                    t.cnt,
                    t.rn,
                    r.result + t.rate_value + r.result * t.rate_value * 0.01 result
              from  r,
                    t
              where t.rate_type_id = r.rate_type_id
                and t.rn = r.rn + 1
select  *
  from  (
         select  rate_desc name,
                 rate_year,
                 result
           from  r
           where rn <= cnt
  pivot (sum(result) for rate_year in (2012,2013,2014))
  order by name
NAME             2012       2013       2014
Desc1        5.914908  7.2918018 8.79388703
Desc2        5.914908  7.2918018 8.79388703
SQL> Obviously pivoting assumes you know rate_year values upfront. If not, then without pivoting:
with t as (
           select  a.rate_type_id,
                   rate_desc,
                   rate_year,
                   rate_base_year,
                   rate_value,
                   count(*) over(partition by a.rate_type_id) cnt,
                   row_number() over(partition by a.rate_type_id order by rate_year) rn
             from  rate_type a,
                   rates b
             where a.rate_type_id = b.rate_type_id
    r(
      rate_type_id,
      rate_desc,
      rate_year,
      rate_base_year,
      rate_value,
      cnt,
      rn,
      result
     ) as (
            select  rate_type_id,
                    rate_desc,
                    rate_year,
                    rate_base_year,
                    rate_value,
                    cnt,
                    rn,
                    rate_base_year + rate_value + rate_base_year * rate_value * 0.01 result
              from  t
              where rn = 1
           union all
            select  t.rate_type_id,
                    t.rate_desc,
                    t.rate_year,
                    t.rate_base_year,
                    t.rate_value,
                    t.cnt,
                    t.rn,
                    r.result + t.rate_value + r.result * t.rate_value * 0.01 result
              from  r,
                    t
              where t.rate_type_id = r.rate_type_id
                and t.rn = r.rn + 1
select  rate_desc name,
        rate_year,
        result
  from  r
  where rn <= cnt
  order by name,
           rate_year
NAME        RATE_YEAR     RESULT
Desc1            2012   5.914908
Desc1            2013  7.2918018
Desc1            2014 8.79388703
Desc2            2012   5.914908
Desc2            2013  7.2918018
Desc2            2014 8.79388703
6 rows selected.
SQL> SY.