2025-11-02 14:36:58 +01:00
|
|
|
|
# Corrections
|
|
|
|
|
|
|
|
|
|
|
|
## 1. Les titulaires
|
|
|
|
|
|
|
|
|
|
|
|
`holder` : table commune à tous les titulaires
|
|
|
|
|
|
|
|
|
|
|
|
- identifiant unique (`id`)
|
|
|
|
|
|
- type de titulaire (`type` = 'PERSON' ou 'COMPANY')
|
|
|
|
|
|
- date de création
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
create table holder (
|
|
|
|
|
|
id bigint primary key generated always as identity,
|
|
|
|
|
|
type text not null check (type in ('PERSON', 'COMPANY')),
|
|
|
|
|
|
created_at timestamp not null default now()
|
|
|
|
|
|
);
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
`person` : informations propres aux personnes physiques
|
|
|
|
|
|
- prénom, nom, date de naissance
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
create table person (
|
|
|
|
|
|
id bigint primary key references holder(id) on delete cascade,
|
|
|
|
|
|
firstname text not null,
|
|
|
|
|
|
lastname text not null,
|
|
|
|
|
|
birthdate date not null
|
|
|
|
|
|
);
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
`company` : informations propres aux entreprises
|
|
|
|
|
|
- raison sociale, numéro d’immatriculation, date de création
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
create table company (
|
|
|
|
|
|
id bigint primary key references holder(id) on delete cascade,
|
|
|
|
|
|
name text not null,
|
|
|
|
|
|
registration_number text unique not null,
|
|
|
|
|
|
created_at date not null
|
|
|
|
|
|
);
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
### Tests d'insertion des données
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
-- Création d’un titulaire de type personne physique
|
|
|
|
|
|
insert into holder(type) values ('PERSON') returning id;
|
|
|
|
|
|
|
|
|
|
|
|
-- Utilisons l'id qui est retourné (1)
|
|
|
|
|
|
insert into person(id, firstname, lastname, birthdate)
|
|
|
|
|
|
values (1, 'Françoise', 'Zanetti', '1995-04-12');
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
-- Création d’un titulaire de type entreprise
|
|
|
|
|
|
insert into holder(type) values ('COMPANY') returning id;
|
|
|
|
|
|
|
|
|
|
|
|
-- Utilisons l'id qui est retourné (2)
|
|
|
|
|
|
insert into company(id, name, registration_number, created_at)
|
|
|
|
|
|
values (2, 'Boulangerie de Valorgue', 'FR19803269968', '2014-08-19');
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
### Vérification
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
2025-11-02 16:21:22 +01:00
|
|
|
|
create view list_holders as
|
2025-11-02 14:36:58 +01:00
|
|
|
|
select h.id, h.type, h.created_at,
|
|
|
|
|
|
p.firstname || ' ' || p.lastname as person,
|
|
|
|
|
|
c.name as company
|
|
|
|
|
|
from holder h
|
|
|
|
|
|
left join person p on p.id = h.id
|
|
|
|
|
|
left join company c on c.id = h.id
|
|
|
|
|
|
order by h.id;
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
#### 1.5.1 Pourquoi séparer `person` et `company` ?
|
|
|
|
|
|
|
|
|
|
|
|
Parce que leurs attributs diffèrent (nom/prénom vs raison sociale).
|
|
|
|
|
|
Cela évite les colonnes inutiles et permet des contraintes spécifiques à chaque type.
|
|
|
|
|
|
|
|
|
|
|
|
#### 1.5.2 Pourquoi ne pas tout mettre dans une seule table holder ?
|
|
|
|
|
|
|
|
|
|
|
|
Cela forcerait la présence de nombreuses colonnes nulles. La séparation améliore la cohérence et la lisibilité du schéma.
|
|
|
|
|
|
|
|
|
|
|
|
#### 1.5.3 Quelle contrainte empêche d’insérer une person sans holder ?
|
|
|
|
|
|
|
|
|
|
|
|
La clé étrangère references holder(id) dans person.
|
|
|
|
|
|
|
|
|
|
|
|
### 1.6 Contôle de l'âge
|
|
|
|
|
|
|
|
|
|
|
|
Contrainte déclarative
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
alter table person
|
|
|
|
|
|
add constraint chk_person_minimum_age
|
|
|
|
|
|
check (birthdate <= current_date - interval '15 years');
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
Contrainte procédurale avec un trigger :
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
create or replace function check_person_age()
|
|
|
|
|
|
returns trigger as $$
|
|
|
|
|
|
begin
|
|
|
|
|
|
if new.birthdate > current_date - interval '15 years' then
|
|
|
|
|
|
raise exception 'Holder must be at least 15 years old';
|
|
|
|
|
|
end if;
|
|
|
|
|
|
return new;
|
|
|
|
|
|
end;
|
|
|
|
|
|
$$ language plpgsql;
|
|
|
|
|
|
|
|
|
|
|
|
create trigger trg_check_person_age
|
|
|
|
|
|
before insert or update on person
|
|
|
|
|
|
for each row execute procedure check_person_age();
|
|
|
|
|
|
```
|
2025-11-02 16:21:22 +01:00
|
|
|
|
|
|
|
|
|
|
### 2. Les comptes
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
create table account (
|
|
|
|
|
|
id bigint primary key generated always as identity,
|
|
|
|
|
|
number text unique not null,
|
|
|
|
|
|
opened_at date not null default current_date,
|
|
|
|
|
|
closed_at date,
|
|
|
|
|
|
balance numeric(18,6) not null default 0 check (balance >= 0)
|
|
|
|
|
|
);
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
Chaque compte a un numéro unique.
|
|
|
|
|
|
La contrainte check (balance >= 0) empêche les soldes négatifs.
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
create table account_holder (
|
|
|
|
|
|
account_id int not null references account(id) on delete cascade,
|
|
|
|
|
|
holder_id int not null references holder(id) on delete cascade,
|
|
|
|
|
|
share numeric(4,3) check (share > 0 and share <= 1),
|
|
|
|
|
|
primary key (account_id, holder_id)
|
|
|
|
|
|
);
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
Cette table établit la relation n–n entre account et holder.
|
|
|
|
|
|
La contrainte share assure que les parts sont comprises entre 0 et 1.
|
|
|
|
|
|
|
|
|
|
|
|
Un compte joint correspond donc à plusieurs lignes dans cette table.
|