├── .github └── ISSUE_TEMPLATE │ ├── bug_report.md │ └── feature_request.md ├── LICENSE ├── README.md ├── officineDB ├── constraints.sql ├── data.sql └── domains-tables.sql └── university_DB ├── constraints.sql ├── data.sql └── domains-tables.sql /.github/ISSUE_TEMPLATE/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Create a report to help us improve 4 | title: '' 5 | labels: '' 6 | assignees: '' 7 | 8 | --- 9 | 10 | **Describe the bug** 11 | A clear and concise description of what the bug is. 12 | 13 | **To Reproduce** 14 | Steps to reproduce the behavior: 15 | 1. Go to '...' 16 | 2. Click on '....' 17 | 3. Scroll down to '....' 18 | 4. See error 19 | 20 | **Expected behavior** 21 | A clear and concise description of what you expected to happen. 22 | 23 | **Screenshots** 24 | If applicable, add screenshots to help explain your problem. 25 | 26 | **Desktop (please complete the following information):** 27 | - OS: [e.g. iOS] 28 | - Browser [e.g. chrome, safari] 29 | - Version [e.g. 22] 30 | 31 | **Smartphone (please complete the following information):** 32 | - Device: [e.g. iPhone6] 33 | - OS: [e.g. iOS8.1] 34 | - Browser [e.g. stock browser, safari] 35 | - Version [e.g. 22] 36 | 37 | **Additional context** 38 | Add any other context about the problem here. 39 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/feature_request.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Feature request 3 | about: Suggest an idea for this project 4 | title: '' 5 | labels: '' 6 | assignees: '' 7 | 8 | --- 9 | 10 | **Is your feature request related to a problem? Please describe.** 11 | A clear and concise description of what the problem is. Ex. I'm always frustrated when [...] 12 | 13 | **Describe the solution you'd like** 14 | A clear and concise description of what you want to happen. 15 | 16 | **Describe alternatives you've considered** 17 | A clear and concise description of any alternative solutions or features you've considered. 18 | 19 | **Additional context** 20 | Add any other context or screenshots about the feature request here. 21 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | This is free and unencumbered software released into the public domain. 2 | 3 | Anyone is free to copy, modify, publish, use, compile, sell, or 4 | distribute this software, either in source code form or as a compiled 5 | binary, for any purpose, commercial or non-commercial, and by any 6 | means. 7 | 8 | In jurisdictions that recognize copyright laws, the author or authors 9 | of this software dedicate any and all copyright interest in the 10 | software to the public domain. We make this dedication for the benefit 11 | of the public at large and to the detriment of our heirs and 12 | successors. We intend this dedication to be an overt act of 13 | relinquishment in perpetuity of all present and future rights to this 14 | software under copyright law. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 17 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 18 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 19 | IN NO EVENT SHALL THE AUTHORS BE LIABLE FOR ANY CLAIM, DAMAGES OR 20 | OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, 21 | ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR 22 | OTHER DEALINGS IN THE SOFTWARE. 23 | 24 | For more information, please refer to 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL-DB 2 | 3 | Easy implementation of some postgreSQL Databases for practicing with Conceptual analysis of requirements, design of relational databases and SQL queries. 4 | Databases created during the course of *Database 2nd module* at Computer Science Bachelor Degree Course, La Sapienza University in Rome. 5 | 6 | 7 | License 8 | ------- 9 | 10 | This repository is [unlicensed](https://github.com/edoardottt/PostgresSQL-DB/blob/master/LICENSE). 11 | [edoardottt.com](https://edoardottt.com/) to contact me. 12 | -------------------------------------------------------------------------------- /officineDB/constraints.sql: -------------------------------------------------------------------------------- 1 | -- no constraints. -------------------------------------------------------------------------------- /officineDB/data.sql: -------------------------------------------------------------------------------- 1 | begin transaction; 2 | 3 | set constraints all deferred; 4 | 5 | INSERT INTO Dipendente(codDip,nome,cognome,indirizzo,stipendio) 6 | VALUES 7 | ('0000000000000001', 'Mario', 'Rossi', 'via dei castagni 1', '30000'), 8 | ('0000000000000002', 'Maria', 'Rossi', 'via dei castagni 2', '29000'), 9 | ('0000000000000003', 'Andrea', 'Verdi', 'via dei palazzi 1', '31000'), 10 | ('0000000000000004', 'Paolo', 'Rossi', 'via del moro 7', '33000'), 11 | ('0000000000000005', 'Mario', 'Bianchi', 'via delle pezze 1', '34000'), 12 | ('0000000000000006', 'Fabio', 'Gialli', 'via delle pezze 4', '28000'), 13 | ('0000000000000007', 'Andrea', 'Rossi', 'via del risorgimento 5', '30000'), 14 | ('0000000000000008', 'Maria', 'Pasini', 'via del consorzio 55', '29000'), 15 | ('0000000000000009', 'Alessandro', 'Rossi','via dei castagni 1', '30000'), 16 | ('0000000000000010', 'Marco', 'Ferrari', 'via dei castagni 1', '30500'), 17 | ('0000000000000011', 'Matteo', 'Arcangeli','via delle pezze 11', '32000'), 18 | ('0000000000000013', 'Ajeje', 'Brazorf', 'via principale 1', '20000'), 19 | ('0000000000000014', 'Giovanni', 'Storti','via dei cirri 1', '30000'), 20 | ('0000000000000015', 'Cataldo', 'Baglio', 'via dei casali 10', '30000'); 21 | 22 | INSERT INTO Dirigente(codDir,nome,cognome,indirizzo,stipendio) 23 | VALUES 24 | ('1000000000000001', 'Mario', 'Gialli', 'via dei castagni 5', '40000'), 25 | ('1000000000000002', 'Maria', 'Mari', 'via dei castagni 2', '49000'), 26 | ('1000000000000003', 'Andrea', 'Arcangeli', 'via dei palazzi 11', '41000'), 27 | ('1000000000000004', 'Paolo', 'Rossi', 'via del moro 67', '43000'), 28 | ('1000000000000005', 'Mario', 'Baglio', 'via delle pezze 19','44000'), 29 | ('1000000000000006', 'Tony', 'Gialli', 'via delle pezze 99','48000'), 30 | ('1000000000000007', 'Andrea', 'Gabrielli', 'via del risorgimento 5','40000'), 31 | ('1000000000000008', 'Maria', 'Pasini', 'via del consorzio 55', '49000'), 32 | ('1000000000000009', 'Alessandro', 'Rossi', 'via dei castagni 1', '40000'), 33 | ('1000000000000010', 'Marco', 'Ferrari', 'via dei castagni 1', '40500'), 34 | ('1000000000000011', 'Matteo', 'Arcangeli', 'via delle pezze 11', '42000'), 35 | ('1000000000000012', 'Gianluca', 'Mancini', 'via dei tamarri 61', '40000'), 36 | ('1000000000000013', 'Ajeje', 'Brazorf', 'via principale 41', '40000'), 37 | ('1000000000000014', 'Giovanni', 'Storti', 'via dei cirri 12', '40000'), 38 | ('1000000000000015', 'Edoardo', 'Poltroni', 'via dei casali 1', '300000'); 39 | 40 | INSERT INTO Proprietario(codPro,nome,cognome,indirizzo) 41 | VALUES 42 | ('2000000000000001', 'Mario', 'Polli', 'via dei castagni 5'), 43 | ('2000000000000002', 'Maria', 'Mari', 'via dei castagni 2'), 44 | ('2000000000000003', 'Paola', 'Arcangeli', 'via dei palazzi 11'), 45 | ('2000000000000004', 'Matteo', 'Rossi', 'via del moro 67'), 46 | ('2000000000000005', 'Mario', 'Baglio', 'via delle pezze 19'), 47 | ('2000000000000006', 'Tony', 'Gialli', 'via delle pezze 99'), 48 | ('2000000000000007', 'Andrea', 'Manfredi', 'via del risorgimento 5'), 49 | ('2000000000000008', 'Luca', 'Pasini', 'via del consorzio 55'), 50 | ('2000000000000009', 'Alessandro', 'Rossi', 'via dei castagni 1'), 51 | ('2000000000000010', 'Marco', 'Antiochia', 'via dei castagni 1'), 52 | ('2000000000000011', 'Matteo', 'Arcangeli', 'via delle pezze 11'), 53 | ('2000000000000012', 'Fabio', 'Mancini', 'via dei marri 61'), 54 | ('2000000000000013', 'Ajeje', 'Brazorf', 'via principale 41'), 55 | ('2000000000000014', 'Giovanni', 'Storti', 'via dei cirri 12'); 56 | 57 | INSERT INTO Officina(nome,codO,indirizzo,nDip) 58 | VALUES 59 | ('macchine&co','1','via dei castagni 5','25'), 60 | ('prontomachine','2','via dei beduini 5','35'), 61 | ('prontocar','3','via dei saltimbanchi 5','80'), 62 | ('macchine','4','via Garibaldi 5','45'), 63 | ('cocar','5','via dei calti 5','100'), 64 | ('Supermacchine','6','via dei castagni 5','235'), 65 | ('riparationman','7','via del piave 5','29'), 66 | ('miacar','8','via dei rossi 3','20'); 67 | 68 | INSERT INTO dirige(dirigente,officina) 69 | VALUES 70 | ('1000000000000015','6'), 71 | ('1000000000000013','4'), 72 | ('1000000000000001','2'), 73 | ('1000000000000003','3'), 74 | ('1000000000000005','1'), 75 | ('1000000000000006','5'), 76 | ('1000000000000007','7'), 77 | ('1000000000000008','8'); 78 | 79 | INSERT INTO lavora(dipendente,officina) 80 | VALUES 81 | ('0000000000000001','1'), 82 | ('0000000000000002','1'), 83 | ('0000000000000003','2'), 84 | ('0000000000000004','3'), 85 | ('0000000000000005','3'), 86 | ('0000000000000006','3'), 87 | ('0000000000000007','6'), 88 | ('0000000000000008','4'), 89 | ('0000000000000009','6'), 90 | ('0000000000000010','6'), 91 | ('0000000000000011','6'), 92 | ('0000000000000012','7'), 93 | ('0000000000000013','4'), 94 | ('0000000000000014','8'), 95 | ('0000000000000015','5'); 96 | 97 | INSERT INTO ValoreTel(tel) 98 | VALUES 99 | ('0000'), 100 | ('0001'), 101 | ('0010'), 102 | ('0011'), 103 | ('0100'), 104 | ('0101'), 105 | ('0110'), 106 | ('0111'), 107 | ('1000'), 108 | ('1001'), 109 | ('1010'), 110 | ('1011'), 111 | ('1100'), 112 | ('1101'), 113 | ('1110'), 114 | ('1111'); 115 | 116 | INSERT INTO TelefonoDIP(persona,telefono) 117 | VALUES 118 | ('0000000000000001','0000'), 119 | ('0000000000000002','0001'), 120 | ('0000000000000003','1001'), 121 | ('0000000000000004','1101'); 122 | 123 | INSERT INTO TelefonoDIR(persona,telefono) 124 | VALUES 125 | ('1000000000000001','0010'), 126 | ('1000000000000015','0011'), 127 | ('1000000000000002','1000'), 128 | ('1000000000000003','1011'); 129 | 130 | INSERT INTO TelefonoPRO(persona,telefono) 131 | VALUES 132 | ('2000000000000002','0100'), 133 | ('2000000000000003','0111'), 134 | ('2000000000000011','0110'), 135 | ('2000000000000014','0101'); 136 | 137 | INSERT INTO effettuaRip(riparazione,officina) 138 | VALUES 139 | ('000','1'), 140 | ('001','2'), 141 | ('010','3'), 142 | ('011','5'), 143 | ('100','6'), 144 | ('101','6'), 145 | ('110','3'), 146 | ('111','2'); 147 | 148 | INSERT INTO Riparazione(codR,veicolo,dataAcc) 149 | VALUES 150 | ('000','AA067AA','2018-12-01'), 151 | ('001','HA239AB','2018-12-03'), 152 | ('010','BU007AC','2018-12-04'), 153 | ('011','YC450AD','2018-12-03'), 154 | ('100','HB560AF','2018-12-03'), 155 | ('101','NF080AG','2018-11-03'), 156 | ('110','RH024AH','2018-12-03'), 157 | ('111','AU000AI','2018-09-03'); 158 | 159 | INSERT INTO Veicolo(targa,tipo,modello,annoImm,proprietario) 160 | VALUES 161 | ('AA067AA','auto','y','2018-11-03','2000000000000012'), 162 | ('HA239AB','moto','e','2018-10-09','2000000000000011'), 163 | ('BU007AC','furgone','x','2018-10-30','2000000000000010'), 164 | ('YC450AD','auto','x','2018-02-25','2000000000000001'), 165 | ('HB560AF','auto','e','2018-05-03','2000000000000003'), 166 | ('NF080AG','moto','x','2018-12-08','2000000000000002'), 167 | ('RH024AH','auto','y','2017-11-04','2000000000000006'), 168 | ('AU000AI','auto','x','2016-12-03','2000000000000009'); 169 | 170 | INSERT INTO Terminate (codTer,riconsegna) 171 | VALUES 172 | ('000','2018-12-05'); 173 | 174 | 175 | commit; 176 | -------------------------------------------------------------------------------- /officineDB/domains-tables.sql: -------------------------------------------------------------------------------- 1 | begin transaction; 2 | 3 | -- Creazione dei domini 4 | 5 | create domain PosInteger as integer check (value >=0); 6 | 7 | create type tipoV as 8 | enum('furgone','auto','moto','camion'); 9 | 10 | create domain stringa as varchar(100); 11 | 12 | create domain Vtarga as varchar(8); 13 | 14 | create domain cf as varchar(16); 15 | 16 | -- Creazione dello schema relazionale 17 | 18 | create table Dipendente ( 19 | codDip cf not null, 20 | nome stringa not null, 21 | cognome stringa not null, 22 | indirizzo stringa not null, 23 | stipendio PosInteger not null, 24 | primary key (codDip) 25 | ); 26 | 27 | create table Dirigente ( 28 | codDir cf not null, 29 | nome stringa not null, 30 | cognome stringa not null, 31 | indirizzo stringa not null, 32 | stipendio PosInteger not null, 33 | primary key (codDir) 34 | ); 35 | 36 | create table Proprietario ( 37 | codPro cf not null, 38 | nome stringa not null, 39 | cognome stringa not null, 40 | indirizzo stringa not null, 41 | primary key (codPro) 42 | ); 43 | 44 | create table Officina ( 45 | nome stringa not null, 46 | codO PosInteger not null, 47 | indirizzo stringa not null, 48 | nDip PosInteger not null, 49 | primary key (codO) 50 | ); 51 | 52 | create table Riparazione ( 53 | codR PosInteger not null, 54 | veicolo Vtarga not null, 55 | dataAcc date not null, 56 | primary key (codR) 57 | ); 58 | 59 | create table Terminate ( 60 | codTer PosInteger not null, 61 | riconsegna date not null, 62 | primary key (codTer), 63 | foreign key (codTer) references Riparazione(codR) deferrable 64 | ); 65 | 66 | create table Veicolo ( 67 | targa Vtarga not null, 68 | tipo tipoV not null, 69 | modello stringa not null, 70 | annoImm date not null, 71 | proprietario cf not null, 72 | primary key (targa), 73 | foreign key (proprietario) references Proprietario(codPro) deferrable 74 | ); 75 | 76 | create table ValoreTel ( 77 | tel stringa not null, 78 | primary key (tel) 79 | ); 80 | 81 | create table telefonoDIP ( 82 | persona cf not null, 83 | telefono stringa not null, 84 | primary key (telefono), 85 | foreign key (persona) references Dipendente(codDip) deferrable, 86 | foreign key (telefono) references ValoreTel(tel) deferrable 87 | ); 88 | 89 | create table telefonoDIR ( 90 | persona cf not null, 91 | telefono stringa not null, 92 | primary key (telefono), 93 | foreign key (persona) references Dirigente(codDir) deferrable, 94 | foreign key (telefono) references ValoreTel(tel) deferrable 95 | ); 96 | 97 | create table telefonoPRO ( 98 | persona cf not null, 99 | telefono stringa not null, 100 | primary key (telefono), 101 | foreign key (persona) references Proprietario(codPro) deferrable, 102 | foreign key (telefono) references ValoreTel(tel) deferrable 103 | ); 104 | 105 | create table effettuaRip ( 106 | riparazione PosInteger not null, 107 | officina PosInteger not null, 108 | primary key (riparazione), 109 | foreign key (riparazione) references Riparazione(codR) deferrable, 110 | foreign key (officina) references Officina(codO) deferrable 111 | ); 112 | 113 | alter table Riparazione 114 | add foreign key (codR) references effettuaRip(riparazione) deferrable; 115 | alter table Riparazione 116 | add foreign key (veicolo) references Veicolo(targa) deferrable; 117 | 118 | create table lavora ( 119 | dipendente cf not null, 120 | officina PosInteger not null, 121 | primary key (dipendente), 122 | foreign key (dipendente) references Dipendente(codDip) deferrable, 123 | foreign key (officina) references Officina(codO) deferrable 124 | ); 125 | 126 | alter table Dipendente 127 | add foreign key (codDip) references lavora(dipendente) deferrable; 128 | 129 | create table dirige ( 130 | dirigente cf not null, 131 | officina PosInteger not null, 132 | primary key (officina), 133 | foreign key (dirigente) references Dirigente(codDir) deferrable, 134 | foreign key (officina) references Officina(codO) deferrable 135 | ); 136 | 137 | alter table Officina 138 | add foreign key (codO) references dirige(officina) deferrable; 139 | 140 | 141 | commit; -------------------------------------------------------------------------------- /university_DB/constraints.sql: -------------------------------------------------------------------------------- 1 | begin transaction; 2 | 3 | -- DISGIUNZIONE TRA STUDENTE E DOCENTE 4 | 5 | CREATE FUNCTION V_PERSONA_isa_disj() RETURNS trigger AS 6 | $V_PERSONA_isa_disj$ 7 | declare isError boolean = false; -- variabile locale 8 | begin 9 | case --TG_TABLE_NAME: nome tabella relativa all'operazione 10 | when TG_TABLE_NAME ilike 'Studente' then 11 | isError = exists (select * from Docente d where d.cf = new.cf ); 12 | when TG_TABLE_NAME ilike 'Docente' then 13 | isError = exists (select * from Studente s where s.cf = new.cf); 14 | else raise exception 'La funzione non può essere invocata sulla funzione 15 | %',TG_TABLE_NAME; 16 | end case; 17 | if (isError) then raise exception 'Vincolo V.personaNotStudenteAndDocente 18 | violato da Persona.id = %',new.cf; 19 | end if; 20 | return new; 21 | end; 22 | $V_PERSONA_isa_disj$ language plpgsql; 23 | 24 | CREATE TRIGGER V_PERSONA_isa_disj_trigger_Studente 25 | before insert or update on Studente 26 | for each row execute procedure V_PERSONA_isa_disj(); 27 | 28 | CREATE TRIGGER V_PERSONA_isa_disj_trigger_Docente 29 | before insert or update on Docente 30 | for each row execute procedure V_PERSONA_isa_disj(); 31 | 32 | -- ------------------------------------------------------------------------------------------ 33 | 34 | -- STUDENTE SUPERA SOLO I CORSI DELLA PROPRIA FACOLTÀ 35 | 36 | CREATE FUNCTION V_STUDENTE_supera() RETURNS trigger AS 37 | $V_STUDENTE_supera$ 38 | declare isError boolean = false; 39 | begin 40 | case 41 | when TG_TABLE_NAME ILIKE 'superato' then 42 | isError = not exists (select * from Corso,Studente where new.corso = corso.cod and studente.matricola = new.studente and studente.facolta = corso.facolta); 43 | else raise exception 'La funzione non può essere invocata sulla funzione %',TG_TABLE_NAME; 44 | end case; 45 | if (isError) then raise exception 'Vincolo V.studenteSuperaCorso violato da superato.matricola = %',new.studente; 46 | end if; 47 | return new; 48 | end; 49 | $V_STUDENTE_supera$ language plpgsql; 50 | 51 | CREATE TRIGGER V_STUDENTE_supera_trigger 52 | before insert or update on superato 53 | for each row execute procedure V_STUDENTE_supera(); 54 | 55 | -- ----------------------------------------------------------------------------------------- 56 | 57 | -- DATA NASCITA STUDENTE > ISCRIZIONE UNIVERSITÀ 58 | 59 | CREATE FUNCTION V_STUDENTE_iscritto() RETURNS trigger AS 60 | $V_STUDENTE_iscritto$ 61 | declare isError boolean = false; 62 | begin 63 | case 64 | when TG_TABLE_NAME ilike 'Studente' then 65 | isError = exists (select * from Persona where Persona.cf = new.cf AND new.annoIscrizione < persona.datadinascita); 66 | else raise exception 'La funzione non può essere invocata sulla funzione %',TG_TABLE_NAME; 67 | end case; 68 | if (isError) then raise exception 'Vincolo V.studenteiscritto violato da studente.annoIscrizione = %',new.cf; 69 | end if; 70 | return new; 71 | end; 72 | $V_STUDENTE_iscritto$ language plpgsql; 73 | 74 | 75 | CREATE TRIGGER V_STUDENTE_ISCRITTO_trigger 76 | before insert or update on Studente 77 | for each row execute procedure V_STUDENTE_iscritto(); 78 | 79 | -- --------------------------------------------------------------------------------------- 80 | 81 | -- COMPLETEZZA TRA STUDENTE E DOCENTE 82 | 83 | CREATE FUNCTION V_PERSONA_completeness() RETURNS trigger AS 84 | $V_PERSONA_completeness$ 85 | declare isError boolean = false; 86 | begin 87 | case 88 | when TG_TABLE_NAME ilike 'Persona' then 89 | isError = not exists ( select cf from Studente where new.cf = studente.cf union distinct select cf from Docente where new.cf = docente.cf); 90 | else raise exception 'La funzione non può essere invocata sulla funzione %', TG_TABLE_NAME; 91 | end case; 92 | if (isError) then raise exception 'Vincolo V.Persona.completezza violato da Persona.cf = %',new.cf; 93 | end if; 94 | return new; 95 | end; 96 | $V_PERSONA_completeness$ language plpgsql; 97 | 98 | 99 | CREATE TRIGGER V_PERSONA_COMPLETENESS_trigger 100 | after insert or update on Persona 101 | for each row execute procedure V_PERSONA_completeness(); 102 | 103 | -- ---------------------------------------------------------------------------------------- 104 | 105 | -- ELIMINAZIONE CONSEGUENTE IN PERSONA DA CANCELLAZIONE STUDENTE 106 | 107 | CREATE FUNCTION V_STUDENTE_delete() RETURNS trigger AS 108 | $V_STUDENTE_delete$ 109 | declare isError boolean = false; 110 | begin 111 | case 112 | when TG_TABLE_NAME ilike 'Studente' then 113 | isError = exists ( select * from Persona where old.cf=persona.cf); 114 | else raise exception 'La funzione non può essere invocata sulla funzione %',TG_TABLE_NAME; 115 | end case; 116 | if (isError) then delete from Persona where persona.cf=old.cf; 117 | end if; 118 | if (isError) then delete from nata where nata.cf=old.cf; 119 | end if; 120 | if (isError) then delete from superato where superato.studente=old.matricola; 121 | end if; 122 | if (isError) then delete from email where email.cf=old.cf; 123 | end if; 124 | return old; 125 | end; 126 | $V_STUDENTE_delete$ language plpgsql; 127 | 128 | 129 | CREATE TRIGGER V_STUDENTE_delete_trigger 130 | after delete on Studente 131 | for each row execute procedure V_STUDENTE_delete(); 132 | 133 | -- ---------------------------------------------------------------------------------------- 134 | 135 | -- ELIMINAZIONE CONSEGUENTE IN PERSONA DA CANCELLAZIONE DOCENTE 136 | 137 | CREATE FUNCTION V_DOCENTE_delete() RETURNS trigger AS 138 | $V_DOCENTE_delete$ 139 | declare isError boolean = false; 140 | begin 141 | case 142 | when TG_TABLE_NAME ilike 'Docente' then 143 | isError = exists (select * from Persona where old.cf=persona.cf); 144 | else raise exception 'La funzione non può essere invocata sulla funzione %',TG_TABLE_NAME; 145 | end case; 146 | if (isError) then delete from Persona where persona.cf=old.cf; 147 | end if; 148 | if (isError) then delete from nata where nata.cf=old.cf; 149 | end if; 150 | if (isError) then delete from email where email.cf=old.cf; 151 | end if; 152 | return old; 153 | end; 154 | $V_DOCENTE_delete$ language plpgsql; 155 | 156 | 157 | CREATE TRIGGER V_DOCENTE_delete_trigger 158 | after delete on Docente 159 | for each row execute procedure V_DOCENTE_delete(); 160 | 161 | 162 | commit work; 163 | -------------------------------------------------------------------------------- /university_DB/data.sql: -------------------------------------------------------------------------------- 1 | begin transaction; 2 | 3 | set constraints all deferred; 4 | 5 | 6 | INSERT INTO Persona(datadinascita, cf, nome, cognome) VALUES 7 | ('1997-02-01', 'aaaaaaaaaaaaaaaa', 'Alessia', 'Braccialetti'), 8 | ('1995-04-05', 'bbbbbbbbbbbbbbbb', 'Orazio', 'Orsato'), 9 | ('1960-12-12', 'cccccccccccccccc', 'Harry', 'Quebert'), 10 | ('1969-11-10', 'dddddddddddddddd', 'Max', 'Renati'), 11 | ('1964-08-11', 'eeeeeeeeeeeeeeee', 'Franco', 'Poligono'), 12 | ('1971-10-10', 'ffffffffffffffff', 'Ermenegildo','Racciante'); 13 | 14 | INSERT INTO Facolta(cod, nome, tipo) VALUES 15 | ('1', 'Lingue', 'Letteraria'), 16 | ('2', 'Ingegneria', 'Scientifica'); 17 | 18 | INSERT INTO Corso(cod, nome, orelezione, facolta) VALUES 19 | ('1', 'Analisi', '5', '2'), 20 | ('2' , 'Programmazione', '3', '2'), 21 | ('3', 'Traduzione consecutiva', '5', '1'), 22 | ('4', 'Interpretariato', '4', '1'); 23 | 24 | INSERT INTO Studente(matricola, cf, facolta, annoiscrizione) VALUES 25 | ('123456789', 'aaaaaaaaaaaaaaaa', '1', '12-07-2015'), 26 | ('234567891', 'bbbbbbbbbbbbbbbb', '2', '13-08-2015'); 27 | 28 | INSERT INTO Docente(cf, corso) VALUES 29 | ('cccccccccccccccc', '4'), 30 | ('dddddddddddddddd', '1'), 31 | ('eeeeeeeeeeeeeeee', '3'), 32 | ('ffffffffffffffff', '2'); 33 | 34 | INSERT INTO Regione(nome) VALUES 35 | ('Lazio'), 36 | ('Umbria'); 37 | 38 | INSERT INTO Citta(nome, regione) VALUES 39 | ('Roma', 'Lazio'), 40 | ('Viterbo', 'Lazio'), 41 | ('San Liberato', 'Umbria'); 42 | 43 | INSERT INTO Email(emailvalue, cf) VALUES 44 | ('laverita@gmail.com', 'cccccccccccccccc'), 45 | ('helloworld@gmail.com', 'ffffffffffffffff'), 46 | ('mrenati@gmail.com', 'dddddddddddddddd'), 47 | ('fpoli@gmail.com', 'eeeeeeeeeeeeeeee'), 48 | ('oorsato@gmail.com', 'bbbbbbbbbbbbbbbb'); 49 | 50 | INSERT INTO Nata(cf, citta, regione) VALUES 51 | ('cccccccccccccccc', 'Roma', 'Lazio'), 52 | ('ffffffffffffffff', 'San Liberato', 'Umbria'), 53 | ('dddddddddddddddd', 'Viterbo', 'Lazio'), 54 | ('eeeeeeeeeeeeeeee', 'Roma', 'Lazio'), 55 | ('bbbbbbbbbbbbbbbb', 'Viterbo', 'Lazio'), 56 | ('aaaaaaaaaaaaaaaa', 'Roma', 'Lazio'); 57 | 58 | INSERT INTO Superato(studente,corso,voto) VALUES 59 | ('123456789', '3', '29'), 60 | ('234567891', '1', '18'), 61 | ('234567891', '2', '32'); 62 | 63 | commit; 64 | -------------------------------------------------------------------------------- /university_DB/domains-tables.sql: -------------------------------------------------------------------------------- 1 | begin transaction; 2 | 3 | --Creazione dei domini 4 | 5 | create domain Matricola as varchar(9); 6 | 7 | create type tipoFacoltà as 8 | enum('Scientifica','Letteraria'); 9 | 10 | create domain oreLezione as integer check (value >0 AND value<6); 11 | 12 | create domain Cf as varchar(16); 13 | 14 | create domain StringaM as varchar(100); 15 | 16 | create domain Voto as integer check(value>17 AND value<33); 17 | 18 | --Creazione schema relazionale 19 | 20 | create table Persona( 21 | datadinascita date not null, 22 | cf Cf not null, 23 | nome StringaM not null, 24 | cognome StringaM, 25 | primary key (cf) 26 | ); 27 | 28 | create table Facolta( 29 | cod integer not null, 30 | nome StringaM not null, 31 | tipo tipoFacoltà, 32 | primary key(cod) 33 | ); 34 | 35 | create table Corso( 36 | cod integer not null, 37 | nome StringaM not null, 38 | orelezione oreLezione not null, 39 | facolta integer not null, 40 | primary key(cod), 41 | foreign key(facolta) references Facolta(cod) 42 | ); 43 | 44 | create table Studente( 45 | matricola Matricola not null, 46 | cf Cf not null, 47 | facolta integer not null, 48 | annoiscrizione date not null, 49 | primary key (cf), 50 | unique(matricola), 51 | foreign key (cf) references Persona(cf) deferrable, 52 | foreign key (facolta) references Facolta(cod) 53 | ); 54 | 55 | create table Docente( 56 | cf Cf not null, 57 | corso integer not null, 58 | primary key (cf), 59 | foreign key (cf) references Persona(cf) deferrable, 60 | foreign key (corso) references Corso(cod) 61 | ); 62 | 63 | create table Regione( 64 | nome StringaM not null, 65 | primary key(nome) 66 | ); 67 | 68 | create table Citta( 69 | nome StringaM not null, 70 | regione StringaM not null, 71 | primary key (nome, regione), 72 | foreign key (regione) references Regione(nome) 73 | ); 74 | 75 | create table Email( 76 | emailvalue StringaM not null, 77 | cf Cf not null, 78 | primary key (emailvalue), 79 | foreign key (cf) references Persona(cf) deferrable 80 | ); 81 | 82 | create table nata( 83 | cf Cf not null, 84 | citta StringaM not null, 85 | regione StringaM not null, 86 | primary key(cf), 87 | foreign key (cf) references Persona(cf) deferrable, 88 | foreign key(citta,regione) references Citta(nome,regione) 89 | ); 90 | 91 | create table superato( 92 | studente Matricola not null, 93 | corso integer not null, 94 | voto Voto not null, 95 | primary key (studente, corso), 96 | foreign key (studente) references Studente(matricola) deferrable, 97 | foreign key (corso) references Corso(cod) 98 | ); 99 | 100 | ALTER TABLE Persona 101 | ADD CONSTRAINT nataaa 102 | foreign key(cf) references nata(cf) deferrable; 103 | 104 | commit; 105 | --------------------------------------------------------------------------------