149 lines
3.7 KiB
MySQL
149 lines
3.7 KiB
MySQL
|
|
drop schema bank cascade;
|
|||
|
|
create schema bank;
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Holder : table commune à tous les titulaires
|
|||
|
|
*/
|
|||
|
|
create table holder (
|
|||
|
|
"id" bigint primary key generated always as identity, -- identifiant unique
|
|||
|
|
"type" text not null check ("type" in ('PERSON', 'COMPANY')),
|
|||
|
|
"created_at" timestamp not null default now() -- date de création
|
|||
|
|
);
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Person
|
|||
|
|
*/
|
|||
|
|
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
|
|||
|
|
*/
|
|||
|
|
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
|
|||
|
|
);
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Insertion des données
|
|||
|
|
*/
|
|||
|
|
|
|||
|
|
-- 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');
|
|||
|
|
|
|||
|
|
-- 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');
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Visualisation des données
|
|||
|
|
*/
|
|||
|
|
|
|||
|
|
-- Liste de tous les titulaires
|
|||
|
|
create view list_holders as
|
|||
|
|
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;
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Suppression des données
|
|||
|
|
*/
|
|||
|
|
|
|||
|
|
insert into holder(type) values ('PERSON') returning id;
|
|||
|
|
|
|||
|
|
insert into person(id, firstname, lastname, birthdate)
|
|||
|
|
values (3, 'Lucas', 'Zanetti', '2002-05-09');
|
|||
|
|
|
|||
|
|
select * from person;
|
|||
|
|
|
|||
|
|
delete from holder where id = 3;
|
|||
|
|
|
|||
|
|
-- La suppresion du titulaire entraine la suppression de l'individu
|
|||
|
|
select * from person;
|
|||
|
|
|
|||
|
|
-- Contrainte sur l'âge du titulaire
|
|||
|
|
alter table person
|
|||
|
|
add constraint chk_person_minimum_age
|
|||
|
|
check (birthdate <= current_date - interval '15 years');
|
|||
|
|
|
|||
|
|
insert into holder(type) values ('PERSON') returning id;
|
|||
|
|
|
|||
|
|
insert into person(id, firstname, lastname, birthdate)
|
|||
|
|
values (3, 'Mattéo', 'Zanetti', '2012-12-12');
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Account
|
|||
|
|
* Chaque compte a un numéro unique.
|
|||
|
|
* La contrainte check (balance >= 0) empêche les soldes négatifs
|
|||
|
|
*/
|
|||
|
|
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)
|
|||
|
|
);
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Account -> Holder
|
|||
|
|
* Cette table établit la relation n–n entre account et holder.
|
|||
|
|
* Un compte joint correspond donc à plusieurs lignes dans cette table.
|
|||
|
|
* La contrainte share assure que les parts sont comprises entre 0 et 1.
|
|||
|
|
*/
|
|||
|
|
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) default 1 check (share > 0 and share <= 1),
|
|||
|
|
primary key (account_id, holder_id)
|
|||
|
|
);
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Compte individuel pour Françoise Zanetti.
|
|||
|
|
*/
|
|||
|
|
|
|||
|
|
insert into account (number)
|
|||
|
|
values ('AA') returning id;
|
|||
|
|
|
|||
|
|
insert into account_holder
|
|||
|
|
values (1, 1);
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Ajout d'un nouveau titulaire : Justin Hébrard né le 11/03/1993.
|
|||
|
|
*/
|
|||
|
|
|
|||
|
|
insert into holder(type) values ('PERSON') returning id;
|
|||
|
|
|
|||
|
|
insert into person(id, firstname, lastname, birthdate)
|
|||
|
|
values (5, 'Justin', 'Hébrard', '1993-03-11');
|
|||
|
|
|
|||
|
|
/*
|
|||
|
|
* Compte joint pour Françoise et Justin.
|
|||
|
|
*/
|
|||
|
|
|
|||
|
|
insert into account (number)
|
|||
|
|
values ('AB') returning id;
|
|||
|
|
|
|||
|
|
insert into account_holder
|
|||
|
|
values (2, 1, 0.5);
|
|||
|
|
|
|||
|
|
insert into account_holder
|
|||
|
|
values (2, 5, 0.5);
|
|||
|
|
|