Thread: Group by a range of values
Say I have a field of ints, as for example created by with ordinality or generate_series, is it possible to group by a range? eq
1,2,3,4,5,6,7,8,9,10
step 3
so output is
1 1
2 1
3 1
4 2
5 2
6 2
7 3
8 3
9 3
10 4
thanks
Hi,
maybe this does the job already (/ is integer division):
SELECT i, 1 + (i-1) / 3
FROM generate_series(1,10) AS i;
An expression like (i-1) / 3 could, of course, also be used as partitioning criterion in GROUP BY and/or window functions.
Cheers,
—T
On Sat, Aug 1, 2020 at 2:15 PM Mike Martin <redtux1@gmail.com> wrote:
Say I have a field of ints, as for example created by with ordinality or generate_series, is it possible to group by a range? eq1,2,3,4,5,6,7,8,9,10step 3so output is1 12 13 14 25 26 27 38 39 310 4thanks
On 8/1/20 6:34 AM, Torsten Grust wrote: > Hi, > > maybe this does the job already (/ is integer division): > > SELECT i, 1 + (i-1) / 3 > FROM generate_series(1,10) AS i; > > An expression like (i-1) / 3 could, of course, also be used as > partitioning criterion in GROUP BY and/or window functions. > > Cheers, > —T > > On Sat, Aug 1, 2020 at 2:15 PM Mike Martin <redtux1@gmail.com > <mailto:redtux1@gmail.com>> wrote: > > Say I have a field of ints, as for example created by with > ordinality or generate_series, is it possible to group by a range? eq > > 1,2,3,4,5,6,7,8,9,10 > step 3 > so output is > > 1 1 > 2 1 > 3 1 > 4 2 > 5 2 > 6 2 > 7 3 > 8 3 > 9 3 > 10 4 > > thanks > > > > -- > | Torsten Grust > | Torsten.Grust@gmail.com <mailto:Torsten.Grust@gmail.com> > My version is as follows, the point being that the "grouping" requested is simply an ordering of the step mechanism. Naturally this series is generated in order shown but real data for val likely won't be. test=# with ts as (select generate_series(1,10) as val) select s.val, (s.val /3)+1 as ord from ts as s order by ord; val | ord -----+----- 1 | 1 2 | 1 3 | 2 4 | 2 5 | 2 6 | 3 7 | 3 8 | 3 9 | 4 10 | 4 (10 rows)
On Sat, Aug 1, 2020 at 5:15 AM Mike Martin <redtux1@gmail.com> wrote:
Say I have a field of ints, as for example created by with ordinality or generate_series, is it possible to group by a range? eq1,2,3,4,5,6,7,8,9,10step 3so output is1 12 13 14 25 26 27 38 39 310 4thanks
My solution would be:
select num, ceiling(CAST (num as float)/3) as grp from AggYields:
num grp
1 1
2 1
3 1
4 2
5 2
6 2
7 3
8 3
9 3
10 4
1 1
2 1
3 1
4 2
5 2
6 2
7 3
8 3
9 3
10 4
For DDL of:
CREATE TABLE Agg
("num" int);INSERT INTO Agg
("num")
VALUES
(1),
(2),
(3),
(4),
(5),
(6),
(7),
(8),
(9),
(10);
I created this in SQL Fiddle: http://sqlfiddle.com/#!17/37519e/30/0