Files
sql/banque.sql
2025-11-04 23:29:06 +01:00

382 lines
10 KiB
PL/PgSQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
drop schema if exists bank cascade;
create schema bank;
set search_path TO 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 dun 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 dun 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 holders_list 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 holders_list;
delete from holder where id = 3;
-- La suppresion du titulaire entraine la suppression de l'individu
select * from holders_list;
-- 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 (4, '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 nn 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);
create view accounts_list as
select
a.number,
h.type,
coalesce(p.firstname || ' ' || p.lastname, c.name) as holder_name,
ah.share,
a.balance
from account a
join account_holder ah on ah.account_id = a.id
join holder h on h.id = ah.holder_id
left join person p on p.id = h.id
left join company c on c.id = h.id
order by a.id, h.id;
/*
* Une transaction
* L'enregistrement réel de toutes les entités s'effectue au commit
*/
begin;
insert into holder(type) values ('PERSON') returning id;
insert into person(id, firstname, lastname, birthdate)
values (6, 'Mattéo', 'Zanetti', '2012-12-12');
commit;
create or replace procedure create_person_holder(
p_firstname text,
p_lastname text,
p_birthdate date
)
language plpgsql
as $$
declare
v_holder_id bigint;
begin
-- Vérification métier
if p_birthdate > current_date - interval '15 years' then
raise exception 'Le titulaire doit avoir au moins 15 ans (%).', p_birthdate
using errcode = 'P0001';
end if;
-- Création atomique du titulaire
insert into holder(type)
values ('PERSON')
returning id into v_holder_id;
insert into person(id, firstname, lastname, birthdate)
values (v_holder_id, p_firstname, p_lastname, p_birthdate);
raise notice 'Titulaire créé avec succès : %, % % (ID=%)',
p_firstname, p_lastname, to_char(p_birthdate, 'YYYY-MM-DD'), v_holder_id;
end;
$$;
call create_person_holder('Mattéo', 'Zanetti', '2012-12-12');
call create_person_holder('Clotilde', 'Hébrard', '1989-07-14');
select account_id, sum(share) as total_share
from account_holder
group by account_id;
create or replace procedure create_account(
p_iban text,
p_name text,
p_holders int[],
p_shares numeric[]
)
language plpgsql
as $$
declare
v_account_id int;
v_sum numeric(6,4) := 0;
v_count int;
begin
-- Vérification des tailles
if array_length(p_holders, 1) is null or array_length(p_shares, 1) is null then
raise exception 'Les tableaux de titulaires et de parts ne peuvent pas être vides.';
end if;
if array_length(p_holders, 1) <> array_length(p_shares, 1) then
raise exception 'Les tableaux de titulaires et de parts doivent avoir la même taille.';
end if;
-- Calcul de la somme des parts
-- select sum(unnest(p_shares)) into v_sum;
for i in 1..array_length(p_shares, 1) loop
v_sum := v_sum + p_shares[i];
end loop;
if abs(v_sum - 1.0) > 0.0001 then
raise exception 'La somme des parts (%.4f) doit être égale à 1.0000', v_sum;
end if;
-- Vérification des titulaires
select count(*) into v_count from holder where id = any(p_holders);
if v_count <> array_length(p_holders, 1) then
raise exception 'Un ou plusieurs titulaires n''existent pas.';
end if;
-- Création du compte
insert into account(iban, name)
values (p_iban, p_name)
returning id into v_account_id;
-- Association des titulaires
for i in 1..array_length(p_holders, 1) loop
insert into account_holder(account_id, holder_id, share)
values (v_account_id, p_holders[i], p_shares[i]);
end loop;
raise notice 'Compte créé avec succès (ID=%) avec % titulaires.',
v_account_id, array_length(p_holders, 1);
end;
$$;
create or replace procedure record_operation(
p_account_id int,
p_kind text,
p_amount numeric,
p_description text default null
)
language plpgsql
as $$
declare
v_balance numeric(12,2);
begin
-- Vérification du type dopération
if p_kind not in ('DEPOSIT', 'WITHDRAWAL') then
raise exception 'Type dopération invalide : % (attendu: DEPOSIT ou WITHDRAWAL)', p_kind;
end if;
-- Vérification que le compte existe
if not exists (select 1 from account where id = p_account_id) then
raise exception 'Le compte % nexiste pas.', p_account_id;
end if;
-- Calcul du solde actuel
select coalesce(sum(case when kind = 'DEPOSIT' then amount else -amount end), 0)
into v_balance
from operation
where account_id = p_account_id;
-- Vérification du solde si retrait
if p_kind = 'WITHDRAWAL' and v_balance < p_amount then
raise exception 'Fonds insuffisants : solde actuel %.2f, retrait demandé %.2f',
v_balance, p_amount;
end if;
-- Insertion de lopération
insert into operation(account_id, kind, amount, description)
values (p_account_id, p_kind, p_amount, p_description);
raise notice 'Opération enregistrée : % de %.2f sur compte %',
p_kind, p_amount, p_account_id;
end;
$$;
CREATE TABLE transaction (
id bigint primary key generated always as identity,
account_id INT NOT NULL REFERENCES account(id),
amount NUMERIC(18, 6) NOT NULL CHECK (amount <> 0),
operation_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE OR REPLACE PROCEDURE deposit(p_account_id INT, p_amount NUMERIC)
LANGUAGE plpgsql
AS $$
BEGIN
IF p_amount <= 0 THEN
RAISE EXCEPTION 'Deposit amount must be positive';
END IF;
UPDATE account
SET balance = balance + p_amount
WHERE id = p_account_id;
IF NOT FOUND THEN
RAISE EXCEPTION 'Account % not found', p_account_id;
END IF;
INSERT INTO transaction (account_id, amount)
VALUES (p_account_id, p_amount);
END;
$$;
CREATE OR REPLACE PROCEDURE withdraw(p_account_id INT, p_amount NUMERIC)
LANGUAGE plpgsql
AS $$
DECLARE
current_balance NUMERIC;
BEGIN
IF p_amount <= 0 THEN
RAISE EXCEPTION 'Withdraw amount must be positive';
END IF;
SELECT balance INTO current_balance
FROM account
WHERE id = p_account_id;
IF NOT FOUND THEN
RAISE EXCEPTION 'Account % not found', p_account_id;
END IF;
IF current_balance < p_amount THEN
RAISE EXCEPTION 'Insufficient funds: balance = %, attempted withdrawal = %',
current_balance, p_amount;
END IF;
UPDATE account
SET balance = balance - p_amount
WHERE id = p_account_id;
INSERT INTO transaction (account_id, amount)
VALUES (p_account_id, -p_amount);
END;
$$;
CALL deposit(1, 500);
CALL withdraw(1, 200);
CALL withdraw(1, 1000); -- Doit échouer
create table entry (
id bigint primary key generated always as identity,
transaction_id bigint,
amount NUMERIC(18, 6) NOT NULL CHECK (amount <> 0),
sens
)