Skip to content

Commit 0c1f3d4

Browse files
Create RANGE-Framing-in-Snowflake.md
1 parent 66267cc commit 0c1f3d4

File tree

1 file changed

+299
-0
lines changed

1 file changed

+299
-0
lines changed

RANGE-Framing-in-Snowflake.md

Lines changed: 299 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,299 @@
1+
# RANGE Framing in Snowflake: Practical Examples
2+
3+
RANGE Framing is now available in Snowflake. Here as some practical examples of using RANGE Framing in the Window Functions.
4+
5+
## Example 1. Running sum of acquitions in the last 28 daysa
6+
7+
### Input Table: Acquisitions by Date
8+
9+
|article|qty|date_acquired|
10+
|:---:|----|------------|
11+
| A | 3 | 2019-10-11 |
12+
| A | 5 | 2019-10-08 |
13+
| A | 10 | 2019-10-05 |
14+
| A | 2 | 2019-09-15 |
15+
| A | 1 | 2019-09-09 |
16+
| A | 1 | 2019-09-01 |
17+
| B | 3 | 2019-10-11 |
18+
| B | 2 | 2019-10-08 |
19+
| B | 3 | 2019-10-05 |
20+
| B | 1 | 2019-09-15 |
21+
| B | 4 | 2019-09-09 |
22+
| C | 1 | 2019-10-11 |
23+
| C | 2 | 2019-10-08 |
24+
| C | 1 | 2019-10-05 |
25+
| C | 1 | 2019-09-15 |
26+
| C | 0 | 2019-09-09 |
27+
| C | 4 | 2019-09-01 |
28+
| C | 1 | 2019-08-28 |
29+
30+
### RANGE based Window query to get running sum of acquitions in the last 28 days
31+
32+
```sql
33+
select
34+
*
35+
, sum(qty) over (partition by article
36+
order by date_acquired
37+
range between interval '28 day' preceding and current row
38+
) as sum_qty_28_days
39+
from acquisitions;
40+
```
41+
42+
### Query Output:
43+
44+
|article|qty|date_acquired|sum_qty_28_days|
45+
|---|----|------------|----|
46+
| A | 1 | 2019-09-01 | 1 |
47+
| A | 1 | 2019-09-09 | 2 |
48+
| A | 2 | 2019-09-15 | 4 |
49+
| A | 10 | 2019-10-05 | 13 |
50+
| A | 5 | 2019-10-08 | 17 |
51+
| A | 3 | 2019-10-11 | 20 |
52+
| C | 1 | 2019-08-28 | 1 |
53+
| C | 4 | 2019-09-01 | 5 |
54+
| C | 0 | 2019-09-09 | 5 |
55+
| C | 1 | 2019-09-15 | 6 |
56+
| C | 1 | 2019-10-05 | 2 |
57+
| C | 2 | 2019-10-08 | 4 |
58+
| C | 1 | 2019-10-11 | 5 |
59+
| B | 4 | 2019-09-09 | 4 |
60+
| B | 1 | 2019-09-15 | 5 |
61+
| B | 3 | 2019-10-05 | 8 |
62+
| B | 2 | 2019-10-08 | 6 |
63+
| B | 3 | 2019-10-11 | 9 |
64+
65+
66+
67+
## Example 2. Count of website visits by visitor_id in a 90 day window
68+
69+
### Input Table: Visitor Data (`visitor_data`)
70+
71+
|VISITOR_ID|DATE_VISITED|
72+
|---|------------|
73+
| 1 | 2022-04-14 |
74+
| 3 | 2022-01-13 |
75+
| 3 | 2022-03-13 |
76+
| 3 | 2022-05-13 |
77+
| 5 | 2022-01-01 |
78+
| 5 | 2022-02-01 |
79+
| 5 | 2022-05-01 |
80+
| 5 | 2022-06-01 |
81+
| 5 | 2022-08-01 |
82+
83+
### SQL Query
84+
85+
```sql
86+
select
87+
*
88+
, count(*) over (partition by visitor_id
89+
order by date_visited
90+
range between interval '90 day' preceding and current row
91+
) as count_90_days
92+
from visitor_data;
93+
```
94+
95+
### Query Output:
96+
97+
|VISITOR_ID|DATE_VISITED|COUNT_90_DAYS|
98+
|---|------------|---|
99+
| 3 | 2022-01-13 | 1 |
100+
| 3 | 2022-03-13 | 2 |
101+
| 3 | 2022-05-13 | 2 |
102+
| 1 | 2022-04-14 | 1 |
103+
| 5 | 2022-01-01 | 1 |
104+
| 5 | 2022-02-01 | 2 |
105+
| 5 | 2022-05-01 | 2 |
106+
| 5 | 2022-06-01 | 2 |
107+
| 5 | 2022-08-01 | 2 |
108+
109+
110+
## Example 3. Webpage Views. Running sum of pageviews by customer in the last 60 days
111+
112+
### Input data
113+
114+
|DATE_VIEWED|VIEWS|CUSTOMER_ID|
115+
|------------|----|---|
116+
| 2020-01-01 | 1 | a |
117+
| 2020-01-15 | 2 | b |
118+
| 2020-01-20 | 1 | a |
119+
| 2020-01-25 | 20 | b |
120+
| 2020-02-15 | 1 | a |
121+
| 2020-03-15 | 2 | b |
122+
| 2020-04-15 | 1 | a |
123+
| 2020-05-15 | 2 | b |
124+
125+
### SQL Query
126+
127+
```sql
128+
select
129+
*
130+
, sum(views) over (partition by customer_id
131+
order by date_viewed
132+
range between interval '59 day' preceding and current row)
133+
from page_views
134+
;
135+
```
136+
### Query Output
137+
138+
|DATE_VIEWED|VIEWS|CUSTOMER_ID|ROLLING_SUM_OF_VIEWS_LAST_60_DAYS|
139+
|------------|----|---|----|
140+
| 2020-01-01 | 1 | a | 1 |
141+
| 2020-01-20 | 1 | a | 2 |
142+
| 2020-02-15 | 1 | a | 3 |
143+
| 2020-04-15 | 1 | a | 1 |
144+
| 2020-01-15 | 2 | b | 2 |
145+
| 2020-01-25 | 20 | b | 22 |
146+
| 2020-03-15 | 2 | b | 22 |
147+
| 2020-05-15 | 2 | b | 2 |
148+
149+
## Example 4. Moving Average (MA) of the 3 weeks Windows of data.
150+
151+
### Analysis Goal
152+
153+
Take all the items in a brand and looking back 3 weeks including current (so 3 rows for each item) and calculate the average of the cycle length column.
154+
155+
### Input data
156+
157+
|report_date|item_id|brand|cycle_length|
158+
|------------|-----|---------|---|
159+
| 2023-09-13 | 123 | Apple | 6 |
160+
| 2023-09-13 | 500 | Apple | 5 |
161+
| 2023-09-20 | 123 | Apple | 6 |
162+
| 2023-09-20 | 500 | Apple | 5 |
163+
| 2023-09-27 | 123 | Apple | 6 |
164+
| 2023-09-27 | 500 | Apple | 4 |
165+
| 2023-10-04 | 123 | Apple | 6 |
166+
| 2023-10-04 | 500 | Apple | 4 |
167+
| 2023-09-13 | 325 | Samsung | 7 |
168+
| 2023-09-13 | 862 | Samsung | 3 |
169+
| 2023-09-13 | 455 | Samsung | 5 |
170+
| 2023-09-20 | 325 | Samsung | 7 |
171+
| 2023-09-20 | 862 | Samsung | 3 |
172+
| 2023-09-27 | 455 | Samsung | 5 |
173+
| 2023-10-04 | 325 | Samsung | 7 |
174+
| 2023-09-27 | 862 | Samsung | 4 |
175+
| 2023-10-04 | 455 | Samsung | 7 |
176+
| 2023-10-11 | 325 | Samsung | 7 |
177+
| 2023-10-04 | 862 | Samsung | 4 |
178+
| 2023-10-11 | 455 | Samsung | 7 |
179+
180+
### SQL Query
181+
182+
```sql
183+
select
184+
*
185+
, avg(cycle_length) over (partition by brand
186+
order by report_date
187+
range between interval '3 weeks' preceding and current row
188+
) as brand_avg_cycle_length_3_weeks
189+
from average_cycle
190+
order by brand, report_date;
191+
```
192+
193+
### Query Output
194+
195+
|report_date|item_id|brand|cycle_length|brand_avg_cycle_length_3_weeks|
196+
|------------|-----|---------|---|-------|
197+
| 2023-09-13 | 500 | Apple | 5 | 5.500 |
198+
| 2023-09-13 | 123 | Apple | 6 | 5.500 |
199+
| 2023-09-20 | 123 | Apple | 6 | 5.500 |
200+
| 2023-09-20 | 500 | Apple | 5 | 5.500 |
201+
| 2023-09-27 | 123 | Apple | 6 | 5.333 |
202+
| 2023-09-27 | 500 | Apple | 4 | 5.333 |
203+
| 2023-10-04 | 123 | Apple | 6 | 5.166 |
204+
| 2023-10-04 | 500 | Apple | 4 | 5.166 |
205+
| 2023-09-13 | 455 | Samsung | 5 | 5.000 |
206+
| 2023-09-13 | 862 | Samsung | 3 | 5.000 |
207+
| 2023-09-13 | 325 | Samsung | 7 | 5.000 |
208+
| 2023-09-20 | 325 | Samsung | 7 | 5.000 |
209+
| 2023-09-20 | 862 | Samsung | 3 | 5.000 |
210+
| 2023-09-27 | 455 | Samsung | 5 | 4.857 |
211+
| 2023-09-27 | 862 | Samsung | 4 | 4.857 |
212+
| 2023-10-04 | 325 | Samsung | 7 | 5.285 |
213+
| 2023-10-04 | 455 | Samsung | 7 | 5.285 |
214+
| 2023-10-04 | 862 | Samsung | 4 | 5.285 |
215+
| 2023-10-11 | 325 | Samsung | 7 | 5.857 |
216+
| 2023-10-11 | 455 | Samsung | 7 | 5.857 |
217+
218+
219+
220+
221+
## Example 5. Rolling Average of the 3 days Window of data.
222+
223+
### Analysis Goal
224+
Get the rolling average of three days as per sales of the item.
225+
226+
### Input Table
227+
228+
| sales_date | daily_sales|salesman|items|
229+
|------------|-----------|--------|------|
230+
| 2021-12-12 | 12000.30 | Max | KCR |
231+
| 2021-12-12 | 32.30 | Max | Crux |
232+
| 2021-12-12 | 13000.30 | Max | Xray |
233+
| 2021-12-13 | 14000.30 | Kyle | KCR |
234+
| 2021-12-13 | 14000.30 | Kyle | Crux |
235+
| 2021-12-13 | 99000.30 | Kyle | XRay |
236+
| 2021-12-14 | 2340.30 | Peter | XRay |
237+
| 2021-12-14 | 1200.30 | Peter | Crux |
238+
| 2021-12-14 | 22000.30 | Peter | KCR |
239+
| 2021-12-15 | 132000.30 | Remo | Crux |
240+
| 2021-12-15 | 124000.30 | Rexy | KCR |
241+
| 2021-12-15 | 120500.30 | Tom | Xray |
242+
| 2021-12-16 | 122000.30 | Felis | Crux |
243+
| 2021-12-16 | 120300.30 | Felis | KCR |
244+
| 2021-12-16 | 120040.30 | Max | Xray |
245+
| 2021-12-17 | 120005.30 | Rubert | KCR |
246+
| 2021-12-17 | 120.30 | Travis | Crux |
247+
| 2021-12-18 | 200.30 | Peter | XRay |
248+
| 2021-12-18 | 200.30 | Peter | Crux |
249+
| 2021-12-18 | 200.30 | Peter | KCR |
250+
| 2021-12-19 | 200.30 | Peter | XRay |
251+
| 2021-12-19 | 500.30 | Peter | KCR |
252+
| 2021-12-19 | 500.30 | Peter | CRUX |
253+
| 2021-12-20 | 200.30 | Peter | XRay |
254+
| 2021-12-20 | 500.30 | Peter | KCR |
255+
| 2021-12-20 | 500.30 | Peter | CRUX |
256+
257+
### SQL Query
258+
259+
```sql
260+
select
261+
items
262+
, sales_date
263+
, avg(daily_sales) over (partition by items
264+
order by sales_date
265+
range between interval '2 days' preceding and current row
266+
) as three_day_moving_average
267+
from sales_info
268+
```
269+
270+
### Query Output
271+
272+
|items|sales_date |three_day_rolling_average|
273+
|------|------------|--------------|
274+
| XRay | 2021-12-13 | 99000.30000 |
275+
| XRay | 2021-12-14 | 50670.30000 |
276+
| XRay | 2021-12-18 | 200.30000 |
277+
| XRay | 2021-12-19 | 200.30000 |
278+
| XRay | 2021-12-20 | 200.30000 |
279+
| Xray | 2021-12-12 | 13000.30000 |
280+
| Xray | 2021-12-15 | 120500.30000 |
281+
| Xray | 2021-12-16 | 120270.30000 |
282+
| CRUX | 2021-12-19 | 500.30000 |
283+
| CRUX | 2021-12-20 | 500.30000 |
284+
| KCR | 2021-12-12 | 12000.30000 |
285+
| KCR | 2021-12-13 | 13000.30000 |
286+
| KCR | 2021-12-14 | 16000.30000 |
287+
| KCR | 2021-12-15 | 53333.63333 |
288+
| KCR | 2021-12-16 | 88766.96666 |
289+
| KCR | 2021-12-17 | 121435.30000 |
290+
| KCR | 2021-12-18 | 80168.63333 |
291+
| KCR | 2021-12-19 | 40235.30000 |
292+
| KCR | 2021-12-20 | 400.30000 |
293+
| Crux | 2021-12-12 | 32.30000 |
294+
| Crux | 2021-12-13 | 7016.30000 |
295+
| Crux | 2021-12-14 | 5077.63333 |
296+
| Crux | 2021-12-15 | 49066.96666 |
297+
| Crux | 2021-12-16 | 85066.96666 |
298+
| Crux | 2021-12-17 | 84706.96666 |
299+
| Crux | 2021-12-18 | 40773.63333 |

0 commit comments

Comments
 (0)