Practica 2
This commit is contained in:
parent
a9c9e2d38a
commit
7e26615aa7
6 changed files with 126 additions and 0 deletions
27
practicas/prac2/03_create_squema.sql
Normal file
27
practicas/prac2/03_create_squema.sql
Normal file
|
@ -0,0 +1,27 @@
|
|||
create table departamento(
|
||||
cod_dep char(5) not null constraint cp_dep primary key initially immediate deferrable,
|
||||
nombre varchar(40) not null,
|
||||
director varchar(20),
|
||||
telefono char(15));
|
||||
|
||||
create table profesor(
|
||||
cod_pro char(5) not null constraint cp_prof primary key initially immediate deferrable,
|
||||
nombre varchar(40) not null,
|
||||
telefono char(15),
|
||||
cod_dep char(5) constraint ca_prof_dep references departamento(cod_dep) initially immediate deferrable);
|
||||
|
||||
create table asignatura(
|
||||
cod_asg char(5) not null constraint cp_asi primary key initially immediate deferrable,
|
||||
nombre varchar(40) not null,
|
||||
semestre char(2) not null,
|
||||
teoria number(3,1) not null,
|
||||
prac number(3,1) not null,
|
||||
cod_dep char(5) constraint ca_asi_dep references departamento(cod_dep) initially immediate deferrable);
|
||||
|
||||
create table docencia(
|
||||
cod_pro char(5) not null constraint ca_doc_prof references profesor(cod_pro) initially immediate deferrable,
|
||||
cod_asg char(5) not null constraint ca_doc_asi references asignatura(cod_asg) initially immediate deferrable,
|
||||
gteo number(2) not null,
|
||||
gprac number(2) not null,
|
||||
constraint cp_doc primary key(cod_pro, cod_asg) initially immediate deferrable);
|
||||
|
18
practicas/prac2/05_populate_squema.sql
Normal file
18
practicas/prac2/05_populate_squema.sql
Normal file
|
@ -0,0 +1,18 @@
|
|||
insert into departamento values('DSIC','Sistemas Informaticos y Computacion','V. Botti','3500');
|
||||
insert into departamento values('DISCA','Ingenieria de Sistemas y Automatica','A. Crespo','6400');
|
||||
insert into profesor values('JCC','Juan Carlos Casamayor','3523','DSIC');
|
||||
insert into profesor values('MCG','Matilde Celma Gimenez','3234','DSIC');
|
||||
insert into profesor values('MAP','Maria Pastor','3666','DISCA');
|
||||
insert into asignatura values('BDA','Bases de Datos','2B',3,3,'DSIC');
|
||||
insert into asignatura values('AD3','Algoritmos y Estructuras de Datos III','2B',3,3,'DSIC');
|
||||
insert into asignatura values('BDV','Bases de Datos Avanzadas','5A',3,3,'DSIC');
|
||||
insert into asignatura values('APB','Desarrollo de aplicaciones de BD','3B',3,3,'DSIC');
|
||||
insert into asignatura values('SO','Sistemas Operativos','2A',3,3,'DISCA');
|
||||
insert into docencia values('MCG','SO',1,1);
|
||||
insert into docencia values('MCG','BDA',2,1);
|
||||
insert into docencia values('MCG','AD3',1,1);
|
||||
insert into docencia values('JCC','BDA',1,2);
|
||||
insert into docencia values('MAP','BDA',1,2);
|
||||
insert into docencia values('MAP','BDV',1,2);
|
||||
commit;
|
||||
|
22
practicas/prac2/06_create_views.sql
Normal file
22
practicas/prac2/06_create_views.sql
Normal file
|
@ -0,0 +1,22 @@
|
|||
CREATE VIEW prof_dsic AS SELECT
|
||||
cod_pro, nombre, telefono
|
||||
FROM
|
||||
profesor
|
||||
WHERE
|
||||
cod_dep = 'DSIC';
|
||||
|
||||
CREATE VIEW docencia_dsic AS SELECT
|
||||
prof_dsic.cod_pro, prof_dsic.nombre AS nombre_pro, asignatura.cod_asg,
|
||||
asignatura.nombre AS nombre_asg, gteo, gprac
|
||||
FROM
|
||||
prof_dsic, asignatura, docencia
|
||||
WHERE
|
||||
prof_dsic.cod_pro = docencia.cod_pro AND
|
||||
docencia.cod_asg = asignatura.cod_asg;
|
||||
|
||||
CREATE VIEW asg_dsic AS SELECT
|
||||
asignatura.cod_asg, nombre_asg as nombre, semestre, teoria, prac,
|
||||
COUNT(DISTINCT cod_pro) AS profesores, SUM(gteo + gprac) AS creditos
|
||||
FROM
|
||||
docencia_dsic JOIN asignatura ON docencia_dsic.cod_asg = asignatura.cod_asg
|
||||
GROUP BY nombre_asg, semestre, teoria, prac, asignatura.cod_asg;
|
12
practicas/prac2/08_view_insert_trigger.sql
Normal file
12
practicas/prac2/08_view_insert_trigger.sql
Normal file
|
@ -0,0 +1,12 @@
|
|||
CREATE OR REPLACE TRIGGER prof_dsic_insert_trigger
|
||||
INSTEAD OF INSERT ON prof_dsic
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
INSERT INTO profesor VALUES (:NEW.cod_pro, :NEW.nombre, :NEW.telefono, 'DSIC');
|
||||
END;
|
||||
/
|
||||
|
||||
-- Probar disparador (ver insercion antes y despues)
|
||||
INSERT INTO prof_dsic VALUES ('pp', 'Pepe', '963123123');
|
||||
DELETE FROM prof_dsic WHERE cod_pro = 'pp';
|
||||
DELETE FROM profesor WHERE cod_pro = 'pp';
|
24
practicas/prac2/09_mod_constraints.sql
Normal file
24
practicas/prac2/09_mod_constraints.sql
Normal file
|
@ -0,0 +1,24 @@
|
|||
INSERT INTO PROFESOR(cod_pro, nombre) VALUES('JR', 'Juan Ruiz');
|
||||
-- Fails here, constraint is INITIALLY IMMEDIATE
|
||||
INSERT INTO PROFESOR(cod_pro, nombre) VALUES('JR', 'Javier Pérez');
|
||||
ROLLBACK; -- Don't save the first insertion
|
||||
|
||||
-- Change constraint to be INITIALLY DEFERRED
|
||||
ALTER TABLE profesor DROP PRIMARY KEY CASCADE KEEP INDEX;
|
||||
ALTER TABLE profesor ADD CONSTRAINT cp_prof PRIMARY KEY(cod_pro) INITIALLY DEFERRED DEFERRABLE;
|
||||
-- Because we used CASCADE to DROP the primary key constraint,
|
||||
-- we need to restore the FOREIGN KEY in docencia
|
||||
ALTER TABLE docencia
|
||||
ADD CONSTRAINT ca_doc_prof
|
||||
FOREIGN KEY(cod_pro) REFERENCES profesor(cod_pro) INITIALLY IMMEDIATE DEFERRABLE;
|
||||
|
||||
INSERT INTO PROFESOR(cod_pro, nombre) VALUES('JR', 'Juan Ruiz');
|
||||
INSERT INTO PROFESOR(cod_pro, nombre) VALUES('JR', 'Javier Pérez');
|
||||
-- Fails here, constraint is INITIALLY DEFERRED
|
||||
COMMIT;
|
||||
|
||||
-- Restore constraint to initial setting
|
||||
ALTER TABLE profesor DROP PRIMARY KEY CASCADE KEEP INDEX;
|
||||
ALTER TABLE profesor ADD CONSTRAINT cp_prof PRIMARY KEY(cod_pro) INITIALLY IMMEDIATE DEFERRABLE;
|
||||
ALTER TABLE docencia ADD CONSTRAINT ca_doc_prof FOREIGN KEY(cod_pro) REFERENCES profesor(cod_pro) INITIALLY IMMEDIATE DEFERRABLE;
|
||||
|
23
practicas/prac2/10_cascade_trigger.sql
Normal file
23
practicas/prac2/10_cascade_trigger.sql
Normal file
|
@ -0,0 +1,23 @@
|
|||
-- In WHEN, NEW and OLD don't need the colon
|
||||
|
||||
-- Update docencia.cod_pro when profesor.cod_pro changes
|
||||
CREATE OR REPLACE TRIGGER cascade_profesor_update
|
||||
AFTER UPDATE ON profesor
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.cod_pro <> NEW.cod_pro)
|
||||
BEGIN
|
||||
UPDATE docencia
|
||||
SET cod_pro = :new.cod_pro
|
||||
WHERE cod_pro = :old.cod_pro;
|
||||
END;
|
||||
/
|
||||
|
||||
-- Delete entries from docencia when profesor is deleted
|
||||
CREATE OR REPLACE TRIGGER cascade_profesor_delete
|
||||
AFTER DELETE ON profesor
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
DELETE FROM docencia
|
||||
WHERE cod_pro = :old.cod_pro;
|
||||
END;
|
||||
/
|
Loading…
Reference in a new issue