窗口函数的名字是over()函数,常用的有两个属性partition by和order by,partition by类似于group by,我们通常将group by叫做分组,而partition by称作分区。
一般结构为:
Function(arg1 , arg2 ……) over(partition by clause order by clause windowing clause ) Windowing clause : rows | range between start_expr and end_expr Start_expr is unbounded preceding | current row | n preceding | n following End_expr is unbounded following | current row | n preceding | n following
Function可以是下面函数,后面有星号 (*) 的函数允许完整的语法,包括windowing_clause。 AVG * CLUSTER_DETAILS CLUSTER_DISTANCE CLUSTER_ID CLUSTER_PROBABILITY CLUSTER_SET CORR * COUNT * COVAR_POP * COVAR_SAMP * CUME_DIST DENSE_RANK FEATURE_DETAILS FEATURE_ID FEATURE_SET FEATURE_VALUE FIRST FIRST_VALUE * LAG LAST LAST_VALUE * LEAD LISTAGG MAX * MIN * NTH_VALUE * NTILE PERCENT_RANK PERCENTILE_CONT PERCENTILE_DISC PREDICTION PREDICTION_COST PREDICTION_DETAILS PREDICTION_PROBABILITY PREDICTION_SET RANK RATIO_TO_REPORT REGR_ (Linear Regression) Functions * ROW_NUMBER STDDEV * STDDEV_POP * STDDEV_SAMP * SUM * VAR_POP * VAR_SAMP * VARIANCE * Windowing clause 指定分析函数的对象物理或逻辑行集( ROWS | RANGE )。 举个例子。 conn test/test@localhost:1521/pdb create table test_tab (student_id number, subject_id number, score number); insert into test_tab values(1,1,90); insert into test_tab values(1,2,98); insert into test_tab values(1,3,99); insert into test_tab values(1,4,95); insert into test_tab values(2,1,98); insert into test_tab values(2,2,95); insert into test_tab values(2,3,98); insert into test_tab values(2,4,97); insert into test_tab values(3,1,93); insert into test_tab values(3,2,94); insert into test_tab values(3,3,94); insert into test_tab values(3,4,91); commit; --以“subject_id”分区,找出每个人和相同“subject_id”的平均“score”的偏离值。 SQL> set autot on SQL> select t.*,(t.score-avg(t.score) over( partition by t.subject_id)) as gaps from test_tab t order by student_id,subject_id; 2 3 STUDENT_ID SUBJECT_ID SCORE GAPS ---------- ---------- ---------- ---------- 1 1 90 -3.6666667 1 2 98 2.33333333 1 3 99 2 1 4 95 .666666667 2 1 98 4.33333333 2 2 95 -.66666667 2 3 98 1 2 4 97 2.66666667 3 1 93 -.66666667 3 2 94 -1.6666667 3 3 94 -3 3 4 91 -3.3333333 12行が選択されました。 実行計画 ---------------------------------------------------------- Plan hash value: 2491645504 -------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 12 | 108 | 5 (40)| 00:00:01 | | 1 | SORT ORDER BY | | 12 | 108 | 5 (40)| 00:00:01 | | 2 | WINDOW SORT | | 12 | 108 | 5 (40)| 00:00:01 | | 3 | TABLE ACCESS FULL| TEST_TAB | 12 | 108 | 3 (0)| 00:00:01 | -------------------------------------------------------------------------------- 統計 ---------------------------------------------------------- 59 recursive calls 23 db block gets 99 consistent gets 1 physical reads 4080 redo size 1158 bytes sent via SQL*Net to client 608 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 7 sorts (memory) 0 sorts (disk) 12 rows processed --不使用窗口函数取得上面的结果。 select t1.*, (t1.score - t3.avgs) as gaps from test_student_score t1, (select t2.subject_id, avg(t2.score) as avgs from test_student_score t2 group by t2.subject_id) t3 where t1.subject_id = t3.subject_id order by t1.student_id,t1.subject_id; STUDENT_ID SUBJECT_ID SCORE GAPS ---------- ---------- ---------- ---------- 1 1 90 -3.6666667 1 2 98 2.33333333 1 3 99 2 1 4 95 .666666667 2 1 98 4.33333333 2 2 95 -.66666667 2 3 98 1 2 4 97 2.66666667 3 1 93 -.66666667 3 2 94 -1.6666667 3 3 94 -3 3 4 91 -3.3333333 12行が選択されました。 実行計画 ---------------------------------------------------------- Plan hash value: 1945508744 ------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 36 | 2772 | 7 (15)| 00:00:01 | | 1 | SORT GROUP BY | | 36 | 2772 | 7 (15)| 00:00:01 | |* 2 | HASH JOIN | | 36 | 2772 | 6 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL| TEST_STUDENT_SCORE | 12 | 612 | 3 (0)| 00:00:01 | | 4 | TABLE ACCESS FULL| TEST_STUDENT_SCORE | 12 | 312 | 3 (0)| 00:00:01 | ------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("T1"."SUBJECT_ID"="T2"."SUBJECT_ID") Note ----- - dynamic statistics used: dynamic sampling (level=2) 統計 ---------------------------------------------------------- 374 recursive calls 0 db block gets 363 consistent gets 0 physical reads 0 redo size 1158 bytes sent via SQL*Net to client 608 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 28 sorts (memory) 0 sorts (disk) 12 rows processed 简单比较一下,似乎使用窗口函数时的COST更小。复制
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。
评论
相关阅读
【专家有话说第五期】在不同年龄段,DBA应该怎样规划自己的职业发展?
墨天轮编辑部
1495次阅读
2025-03-13 11:40:53
Oracle RAC ASM 磁盘组满了,无法扩容怎么在线处理?
Lucifer三思而后行
906次阅读
2025-03-17 11:33:53
RAC 19C 删除+新增节点
gh
556次阅读
2025-03-14 15:44:18
2月“墨力原创作者计划”获奖名单公布
墨天轮编辑部
507次阅读
2025-03-13 14:38:19
Oracle DataGuard高可用性解决方案详解
孙莹
385次阅读
2025-03-26 23:27:33
墨天轮个人数说知识点合集
JiekeXu
328次阅读
2025-04-01 15:56:03
XTTS跨版本迁移升级方案(11g to 19c RAC for Linux)
zwtian
318次阅读
2025-04-08 09:12:48
Oracle SQL 执行计划分析与优化指南
Digital Observer
284次阅读
2025-04-01 11:08:44
切换Oracle归档路径后,不能正常删除原归档路径上的归档文件
dbaking
274次阅读
2025-03-19 14:41:51
风口浪尖!诚通证券扩容采购Oracle 793万...
Roger的数据库专栏
271次阅读
2025-03-24 09:42:53