Skip to content

Commit ba3f2b0

Browse files
authored
Session 6: Workload optimization
1 parent e1c31d9 commit ba3f2b0

File tree

1 file changed

+169
-0
lines changed

1 file changed

+169
-0
lines changed

Laboratori/Sessió 6.txt

+169
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,169 @@
1+
Ex. 1
2+
3+
Donades les taules i les dades al fitxer adjunt, feu el disseny físic de la base de dades de manera que sigui òptima l'execució de les comandes següents (la freqüencia d'execució de cadascuna està indicada entre parèntesis):
4+
5+
(10%) SELECT * FROM empleats e WHERE sou BETWEEN 15000 AND 20000;
6+
(42%) SELECT * FROM departaments d WHERE seu = 1;
7+
(05%) SELECT * FROM (
8+
SELECT * FROM empleats e WHERE id = 1 union all
9+
SELECT * FROM empleats e WHERE id = 10 union all
10+
SELECT * FROM empleats e WHERE id = 100 union all
11+
SELECT * FROM empleats e WHERE id = 1000 union all
12+
SELECT * FROM empleats e WHERE id = 10000);
13+
(43%) SELECT * FROM departaments d, seus s WHERE s.id = d.seu AND s.id > 9;
14+
15+
Tingueu en compte que només podeu utilitzar 1370 blocs d'espai en total.
16+
17+
Fitxer adjunt:
18+
19+
CREATE TABLE seus (
20+
id INTEGER,
21+
ciutat CHAR(40)
22+
) PCTFREE 0 ENABLE ROW MOVEMENT;
23+
-- Id és clau candidata
24+
25+
CREATE TABLE empleats (
26+
id INTEGER,
27+
nom CHAR(200),
28+
sou INTEGER,
29+
edat INTEGER,
30+
dpt INTEGER,
31+
historial CHAR(500)
32+
) PCTFREE 0 ENABLE ROW MOVEMENT;
33+
-- Id és clau candidata
34+
35+
CREATE TABLE departaments (
36+
id INTEGER,
37+
nom CHAR(200),
38+
seu INTEGER,
39+
tasques CHAR(2000)
40+
) PCTFREE 0 ENABLE ROW MOVEMENT;
41+
-- Id és clau candidata
42+
43+
DECLARE
44+
i INTEGER;
45+
BEGIN
46+
DBMS_RANDOM.seed(0);
47+
48+
-- Insercions de seus
49+
INSERT INTO seus (id, ciutat) VALUES (1, 'BARCELONA');
50+
INSERT INTO seus (id, ciutat) VALUES (2, 'GIRONA');
51+
INSERT INTO seus (id, ciutat) VALUES (3, 'ZARAGOZA');
52+
INSERT INTO seus (id, ciutat) VALUES (4, 'MADRID');
53+
INSERT INTO seus (id, ciutat) VALUES (5, 'GRANADA');
54+
INSERT INTO seus (id, ciutat) VALUES (6, 'PARIS');
55+
INSERT INTO seus (id, ciutat) VALUES (7, 'LONDRES');
56+
INSERT INTO seus (id, ciutat) VALUES (8, 'FRANKFURT');
57+
INSERT INTO seus (id, ciutat) VALUES (9, 'LIMA');
58+
INSERT INTO seus (id, ciutat) VALUES (10, 'TOKIO');
59+
60+
-- Insercions de departaments
61+
FOR i IN 1..1100 LOOP
62+
INSERT INTO departaments (id, nom, seu, tasques) VALUES (i,
63+
LPAD(dbms_random.string('U',10),200,'*'),
64+
dbms_random.value(1,10),
65+
LPAD(dbms_random.string('U',10),2000,'*')
66+
);
67+
END LOOP;
68+
69+
-- Insercions d'empleats
70+
FOR i IN 1..(10000) LOOP
71+
INSERT INTO empleats (id, nom, sou, edat, dpt, historial) VALUES (
72+
i,
73+
LPAD(dbms_random.string('U',10),200,'*'),
74+
dbms_random.value(15000,50000),
75+
dbms_random.value(19,64),
76+
dbms_random.value(1,1100),
77+
LPAD(dbms_random.string('U',10),500,'*')
78+
);
79+
END LOOP;
80+
END;
81+
82+
ALTER TABLE empleats SHRINK SPACE;
83+
ALTER TABLE departaments SHRINK SPACE;
84+
ALTER TABLE seus SHRINK SPACE;
85+
86+
---------------------------- Update Statistics -----------------------------
87+
DECLARE
88+
esquema VARCHAR2(100);
89+
CURSOR c IS SELECT TABLE_NAME FROM USER_TABLES;
90+
BEGIN
91+
SELECT '"'||sys_context('USERENV', 'CURRENT_SCHEMA')||'"' INTO esquema FROM dual;
92+
FOR taula IN c LOOP
93+
DBMS_STATS.GATHER_TABLE_STATS(
94+
ownname => esquema,
95+
tabname => taula.table_name,
96+
estimate_percent => NULL,
97+
method_opt =>'FOR ALL COLUMNS SIZE REPEAT',
98+
granularity => 'GLOBAL',
99+
cascade => TRUE
100+
);
101+
END LOOP;
102+
END;
103+
104+
---------------------------- To check the real costs -------------------------
105+
CREATE TABLE measure (id INTEGER, weight FLOAT, i FLOAT, f FLOAT);
106+
DECLARE
107+
i0 INTEGER;
108+
i1 INTEGER;
109+
i2 INTEGER;
110+
i3 INTEGER;
111+
i4 INTEGER;
112+
r INTEGER;
113+
BEGIN
114+
select value INTO i0
115+
from v$statname c, v$sesstat a
116+
where a.statistic# = c.statistic#
117+
and sys_context('USERENV','SID') = a.sid
118+
and c.name in ('consistent gets');
119+
120+
SELECT MAX(LENGTH(e.id||e.nom||e.sou||e.edat||e.dpt||e.historial)) INTO r FROM empleats e WHERE sou BETWEEN 15000 AND 20000;
121+
122+
select value INTO i1
123+
from v$statname c, v$sesstat a
124+
where a.statistic# = c.statistic#
125+
and sys_context('USERENV','SID') = a.sid
126+
and c.name in ('consistent gets');
127+
128+
SELECT MAX(LENGTH(d.id||d.nom||d.seu||d.tasques)) INTO r FROM departaments d WHERE seu = 1;
129+
130+
select value INTO i2
131+
from v$statname c, v$sesstat a
132+
where a.statistic# = c.statistic#
133+
and sys_context('USERENV','SID') = a.sid
134+
and c.name in ('consistent gets');
135+
136+
SELECT MAX(LENGTH(e.id||e.nom||e.sou||e.edat||e.dpt||e.historial)) INTO r FROM (
137+
SELECT * FROM empleats e WHERE id = 1 union all
138+
SELECT * FROM empleats e WHERE id = 10 union all
139+
SELECT * FROM empleats e WHERE id = 100 union all
140+
SELECT * FROM empleats e WHERE id = 1000 union all
141+
SELECT * FROM empleats e WHERE id = 10000) e;
142+
143+
select value INTO i3
144+
from v$statname c, v$sesstat a
145+
where a.statistic# = c.statistic#
146+
and sys_context('USERENV','SID') = a.sid
147+
and c.name in ('consistent gets');
148+
149+
SELECT MAX(LENGTH(d.id||d.nom||d.seu||d.tasques||s.id||s.ciutat)) INTO r FROM departaments d, seus s WHERE s.id = d.seu AND s.id > 9;
150+
151+
select value INTO i4
152+
from v$statname c, v$sesstat a
153+
where a.statistic# = c.statistic#
154+
and sys_context('USERENV','SID') = a.sid
155+
and c.name in ('consistent gets');
156+
157+
INSERT INTO measure (id,weight,i,f) VALUES (1,0.10,i0,i1);
158+
INSERT INTO measure (id,weight,i,f) VALUES (2,0.42,i1,i2);
159+
INSERT INTO measure (id,weight,i,f) VALUES (3,0.05,i2,i3);
160+
INSERT INTO measure (id,weight,i,f) VALUES (4,0.43,i3,i4);
161+
END;
162+
163+
SELECT SUM((f-i)*weight) FROM measure;
164+
DROP TABLE measure PURGE;
165+
166+
Solució:
167+
168+
Bitmap sobre l'atribut seu a la taula departaments
169+
B+ sobre l'atribut id a la taula empleats

0 commit comments

Comments
 (0)