I have a table containing the following:
ID low_value high_value
1 3270200000 3270210000
2 3270210000 3270220000
3 3270220000 3270230000
4 3270230000 3270231000
5 3270231000 3270232000
6 3270232000 3270240000
...
In one single query using Oracle 11g I'd like to retrieve following result in which I list each unique number that exists within the range defined with
start value = with low_value /
end value = high_value - 1
low_value high_value unique_value
3270200000 3270210000 3270200000
3270200000 3270210000 3270200001
3270200000 3270210000 3270200002
3270200000 3270210000 3270200003
...
3270200000 3270210000 3270209999
3270210000 3270220000 3270210001
3270210000 3270220000 3270210002
3270210000 3270220000 3270210002
...
3270210000 3270220000 3270219999
...
I've been playing with the connect by & model clause but so far without success.
tx for your help
using the model clause:
SQL> create table foo1
2 (id number,
3 low_value number,
4 high_value number);
Table created.
SQL>
SQL> insert into foo1 values (1, 3270200000, 3270200010);
1 row created.
SQL> insert into foo1 values (2, 3270210000, 3270210005);
1 row created.
SQL> insert into foo1 values (3, 10, 10);
1 row created.
SQL> commit;
Commit complete.
SQL>
SQL>
SQL> with foo as
2 (select f.id, f.low_value, f.high_value, f.high_value - f.low_value
3 range from foo1 f)
4 select key, low_value, high_value, unique_value
5 from foo
6 model partition by(id as key)
7 dimension by(0 as f)
8 measures(low_value as unique_value, low_value, high_value, range)
9 rules (unique_value [for f from 0 to range[0] increment 1] = low_value[0] + cv(f),
10 low_value[for f from 0 to range[0] increment 1] = low_value[0],
11 high_value[for f from 0 to range[0] increment 1] = high_value[0]);
KEY LOW_VALUE HIGH_VALUE UNIQUE_VALUE
---------- ---------- ---------- ------------
1 3270200000 3270200010 3270200000
1 3270200000 3270200010 3270200001
1 3270200000 3270200010 3270200002
1 3270200000 3270200010 3270200003
1 3270200000 3270200010 3270200004
1 3270200000 3270200010 3270200005
1 3270200000 3270200010 3270200006
1 3270200000 3270200010 3270200007
1 3270200000 3270200010 3270200008
1 3270200000 3270200010 3270200009
1 3270200000 3270200010 3270200010
2 3270210000 3270210005 3270210000
2 3270210000 3270210005 3270210001
2 3270210000 3270210005 3270210002
2 3270210000 3270210005 3270210003
2 3270210000 3270210005 3270210004
2 3270210000 3270210005 3270210005
3 10 10 10
18 rows selected.
SQL>
and 11g recursive factoring
SQL> with foo (id, low_value, high_value, unique_value)
2 as (select f.id, f.low_value, f.high_value, low_value unique_value
3 from foo1 f
4 union all
5 select id, low_Value, high_value, unique_value + 1
6 from foo
7 where unique_value < high_value)
8 select id, low_value, high_value, unique_value
9 from foo
10 order by id, unique_value
11 /
ID LOW_VALUE HIGH_VALUE UNIQUE_VALUE
---------- ---------- ---------- ------------
1 3270200000 3270200010 3270200000
1 3270200000 3270200010 3270200001
1 3270200000 3270200010 3270200002
1 3270200000 3270200010 3270200003
1 3270200000 3270200010 3270200004
1 3270200000 3270200010 3270200005
1 3270200000 3270200010 3270200006
1 3270200000 3270200010 3270200007
1 3270200000 3270200010 3270200008
1 3270200000 3270200010 3270200009
1 3270200000 3270200010 3270200010
ID LOW_VALUE HIGH_VALUE UNIQUE_VALUE
---------- ---------- ---------- ------------
2 3270210000 3270210005 3270210000
2 3270210000 3270210005 3270210001
2 3270210000 3270210005 3270210002
2 3270210000 3270210005 3270210003
2 3270210000 3270210005 3270210004
2 3270210000 3270210005 3270210005
3 10 10 10
18 rows selected.
SQL>