Skip to content

Commit 80aaccb

Browse files
author
Connor McDonald
committed
New analytical SQL sample scripts
1 parent 1e143b8 commit 80aaccb

34 files changed

+5409
-1
lines changed

sql/analytical-sql-examples

Submodule analytical-sql-examples deleted from c5e889d

sql/analytical-sql-examples/README.md

+1
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
Run these "analytics"-prefixed scripts standalone, or follow them as part of the complete Analytics class at https://tinyurl.com/devgym-classes
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,41 @@
1+
REM Script: 18c approx_count function
2+
REM Data analysis applications heavily use aggregate functions. Approximate query processing (available since Oracle Database 12c Release 1) aims to deliver faster results for these queries. The approximate results are not identical to the exact results but they are very close. New approximate SQL functions for rank, sum and count are now available for Top-N style queries.
3+
4+
By making use of approximate query processing, you can instantly improve the performance of existing analytic workloads and enable faster ad-hoc data exploration
5+
6+
drop table t purge;
7+
8+
create table t as
9+
select * from all_objects
10+
where owner in ('SYS','SYSTEM','PUBLIC','SCOTT','HR','SALES');
11+
12+
select owner, count(*)
13+
from t
14+
group by owner
15+
order by 1;
16+
17+
-- For the new approx_count functions, you must have a matching approx_rank function as part of the GROUP BY definition
18+
select owner, approx_count(*)
19+
from t
20+
group by owner
21+
order by 1;
22+
23+
select owner, approx_count(*)
24+
from t
25+
group by owner
26+
having approx_rank(partition by owner order by approx_count(*) desc) <= 1
27+
order by 1;
28+
29+
select owner, approx_count(*) , approx_rank(partition by owner order by approx_count(*) desc)
30+
from t
31+
group by owner
32+
having approx_rank(partition by owner order by approx_count(*) desc) <= 1
33+
order by 1;
34+
35+
-- You can see the benefit of the restriction when you see that the partition by clause can be a subset of the group by aggregation columns. Hence in this example, we get the top 8 ranked object types *per owner*
36+
select owner, object_type, approx_count(*) , approx_rank(partition by owner order by approx_count(*) desc)
37+
from t
38+
group by owner, object_type
39+
having approx_rank(partition by owner order by approx_count(*) desc) <= 8
40+
order by 1;
41+
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,32 @@
1+
REM Script: 18c character encoding validation
2+
REM New routines in UTL_I18N allow for validation of characters within a particular characterset
3+
4+
REM Script: 18c character encoding validation
5+
6+
7+
REM New routines in UTL_I18N allow for validation of characters within a particular characterset
8+
9+
10+
select * from database_properties
11+
where property_name in ('NLS_NCHAR_CHARACTERSET','NLS_CHARACTERSET') ;
12+
13+
drop table charset_test;
14+
15+
create table charset_test(col1 varchar2(20), col2 nvarchar2(20)) ;
16+
17+
insert into charset_test
18+
values(
19+
unistr('foo\D800bar'),
20+
unistr('foo\D800bar')
21+
) ;
22+
23+
commit
24+
25+
26+
select * from charset_test ;
27+
28+
select
29+
utl_i18n.validate_character_encoding(col1) invalid_offset_column1,
30+
utl_i18n.validate_character_encoding(col2) invalid_offset_column2
31+
from charset_test ;
32+

sql/analytical-sql-examples/analytics-Deleting-Duplicates.sql

+274
Large diffs are not rendered by default.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,51 @@
1+
REM Script: Display columns as rows for any SQL query
2+
REM If you have a SQL query that produces output that might wrap on a terminal, then this script will let you run it and print columns as rows rather than columns.
3+
4+
The 'p_query' parameter contains the query to be run. If you want to run this from SQL*Plus or SQLcl, simply change the contents to "&1" to pass the SQL query as a parameter to this script
5+
6+
-- To use this as a utility script for a dynamically provided SQL query, replace "select * from scott.emp" with "&1", and save the script as (say) "printrows.sql". Then the script can be run from SQLcl, SQL*Plus or SQL Developer with a simple: @printrows "select * from scott.emp"
7+
declare
8+
p_query varchar2(32767) := q'{select * from scott.emp}';
9+
10+
l_theCursor integer default dbms_sql.open_cursor;
11+
l_columnValue varchar2(4000);
12+
l_status integer;
13+
l_descTbl dbms_sql.desc_tab;
14+
l_colCnt number;
15+
n number := 0;
16+
procedure p(msg varchar2) is
17+
l varchar2(4000) := msg;
18+
begin
19+
while length(l) > 0 loop
20+
dbms_output.put_line(substr(l,1,80));
21+
l := substr(l,81);
22+
end loop;
23+
end;
24+
begin
25+
execute immediate 'alter session set nls_date_format=''dd-MON-yyyy hh24:mi:ss'' ';
26+
27+
dbms_sql.parse( l_theCursor, p_query, dbms_sql.native );
28+
dbms_sql.describe_columns( l_theCursor, l_colCnt, l_descTbl );
29+
30+
for i in 1 .. l_colCnt loop
31+
dbms_sql.define_column(l_theCursor, i, l_columnValue, 4000);
32+
end loop;
33+
34+
l_status := dbms_sql.execute(l_theCursor);
35+
36+
while ( dbms_sql.fetch_rows(l_theCursor) > 0 ) loop
37+
for i in 1 .. l_colCnt loop
38+
dbms_sql.column_value( l_theCursor, i, l_columnValue );
39+
p( rpad( l_descTbl(i).col_name, 30 )
40+
|| ': ' ||
41+
l_columnValue );
42+
end loop;
43+
dbms_output.put_line( '-----------------' );
44+
n := n + 1;
45+
end loop;
46+
if n = 0 then
47+
dbms_output.put_line( chr(10)||'No data found '||chr(10) );
48+
end if;
49+
end;
50+
/
51+
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,38 @@
1+
REM Script: Analytics - Dynamically sized windows
2+
REM SQL from the KISS (Keep It Simply SQL) Analytic video series by Developer Advocate Connor McDonald. This script is using a PL/SQL function to create dynamic window range.
3+
4+
Run this script standalone, or take it as part of the complete Analytics class at https://tinyurl.com/devgym-classes
5+
6+
select time_id,
7+
sum(amount_sold) sold_per_day
8+
from sh.sales
9+
group by time_Id
10+
order by 1;
11+
12+
create or replace
13+
function LAST_CLOSE(p_close_date date)
14+
return number is
15+
begin
16+
return
17+
case to_char(p_close_date,'DY')
18+
when 'SUN' then 2
19+
when 'MON' then 3
20+
else 1
21+
end;
22+
end;
23+
/
24+
25+
select
26+
time_id,
27+
to_char(time_id,'DY') close_day,
28+
sum(sold_per_day)
29+
over (
30+
order by time_id
31+
range between LAST_CLOSE(time_id) preceding and 0 following) as close_off
32+
from (
33+
select time_id,
34+
sum(amount_sold) sold_per_day
35+
from sh.sales
36+
group by time_Id
37+
);
38+
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,61 @@
1+
REM Script: Analytics - First look at Window functions
2+
REM SQL from the KISS (Keep It Simply SQL) Analytic video series by Developer Advocate Connor McDonald. This script introduces the window clause.
3+
4+
Run this script standalone, or take it as part of the complete Analytics class at https://tinyurl.com/devgym-classes
5+
6+
drop table water purge;
7+
8+
create table water ( name varchar2(30) primary key,
9+
type varchar2(10),
10+
square_km int );
11+
12+
insert into water(name,type,square_km) values ('Pacific Ocean','Ocean',155557000);
13+
14+
insert into water(name,type,square_km) values ('Atlantic Ocean','Ocean',76762000);
15+
16+
insert into water(name,type,square_km) values ('Indian Ocean','Ocean',68556000);
17+
18+
insert into water(name,type,square_km) values ('Southern Ocean','Ocean',20327000);
19+
20+
insert into water(name,type,square_km) values ('Arctic Ocean','Ocean',14056000);
21+
22+
insert into water(name,type,square_km) values ('Mediterranean Sea','Sea',2965800);
23+
24+
insert into water(name,type,square_km) values ('Caribbean Sea','Sea',2718200);
25+
26+
insert into water(name,type,square_km) values ('South China Sea','Sea',2319000);
27+
28+
insert into water(name,type,square_km) values ('Bering Sea','Sea',2291900);
29+
30+
insert into water(name,type,square_km) values ('Gulf of Mexico','Gulf',1592800);
31+
32+
insert into water(name,type,square_km) values ('Okhotsk Sea','Sea',1589700);
33+
34+
insert into water(name,type,square_km) values ('East China Sea','Sea',1249200);
35+
36+
insert into water(name,type,square_km) values ('Hudson Bay','Bay',1232300);
37+
38+
insert into water(name,type,square_km) values ('Japan Sea','Sea',1007800);
39+
40+
insert into water(name,type,square_km) values ('Andaman Sea','Sea',797700);
41+
42+
insert into water(name,type,square_km) values ('North Sea','Sea',575200);
43+
44+
insert into water(name,type,square_km) values ('Red Sea','Sea',438000);
45+
46+
insert into water(name,type,square_km) values ('Baltic Sea','Sea',422200);
47+
48+
commit
49+
50+
51+
select *
52+
from water
53+
order by 3 desc;
54+
55+
select name, type, square_km,
56+
sum(square_km) over ( order by square_km desc
57+
rows between unbounded preceding and current row
58+
) as tot
59+
from water
60+
order by 3 desc;
61+
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,79 @@
1+
REM Script: Analytics - Grouping ranges of data
2+
REM SQL from the KISS (Keep It Simply SQL) Analytic video series by Developer Advocate Connor McDonald. This script looks at the classical problem of identifying groups of data within a set of rows.
3+
4+
Run this script standalone, or take it as part of the complete Analytics class at https://tinyurl.com/devgym-classes
5+
6+
drop table LAB_SAMPLES;
7+
8+
drop sequence LAB_SAMPLES_SEQ;
9+
10+
create sequence LAB_SAMPLES_SEQ;
11+
12+
create table LAB_SAMPLES
13+
( sample_id int default LAB_SAMPLES_SEQ.NEXTVAL,
14+
date_taken date
15+
);
16+
17+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-01');
18+
19+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-02');
20+
21+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-03');
22+
23+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-04');
24+
25+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-07');
26+
27+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-08');
28+
29+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-09');
30+
31+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-10');
32+
33+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-14');
34+
35+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-15');
36+
37+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-16');
38+
39+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-19');
40+
41+
insert into LAB_SAMPLES ( date_taken) values (date '2015-12-20');
42+
43+
select * from LAB_SAMPLES order by 2;
44+
45+
select
46+
date_taken,
47+
lag(date_taken) over ( order by date_taken) prev
48+
from lab_samples
49+
order by 1;
50+
51+
select
52+
date_taken,
53+
case
54+
when nvl(lag(date_taken) over (order by date_taken),date_taken) != date_taken-1
55+
then date_taken end loval
56+
from lab_samples
57+
order by 1;
58+
59+
select date_taken, max(loval) over (order by date_taken) loval
60+
from (
61+
select date_taken,
62+
case
63+
when nvl(lag(date_taken) over (order by date_taken),date_taken) !=
64+
date_taken-1 then date_taken end loval
65+
from lab_samples )
66+
order by 1;
67+
68+
select min(date_taken) range_start, max(date_taken) range_end
69+
from (
70+
select date_taken,max(loval) over (order by date_taken) loval
71+
from (
72+
select date_taken,
73+
case
74+
when nvl(lag(date_taken) over (order by date_taken),date_taken) !=
75+
date_taken-1 then date_taken end loval
76+
from lab_samples))
77+
group by loval
78+
order by 1;
79+

0 commit comments

Comments
 (0)