2025-11-01 14:28:58 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Base de données pour l'apprentissage du langage SQL
|
|
|
|
|
-- PostgreSQL v18
|
|
|
|
|
-- 3 novembre 2025
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
2025-10-14 21:11:54 +02:00
|
|
|
show server_version;
|
2025-10-31 07:42:56 +01:00
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- extensions
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
2025-10-05 19:16:58 +02:00
|
|
|
select * from pg_available_extensions;
|
|
|
|
|
|
2025-10-14 21:11:54 +02:00
|
|
|
create schema postgis;
|
|
|
|
|
create extension if not exists postgis schema postgis;
|
|
|
|
|
create extension if not exists pgrouting schema postgis;
|
|
|
|
|
|
2025-10-14 22:28:15 +02:00
|
|
|
create schema ext;
|
|
|
|
|
create extension if not exists ltree schema ext;
|
|
|
|
|
create extension if not exists pgcrypto schema ext;
|
2025-10-31 07:42:56 +01:00
|
|
|
create extension if not exists vector schema ext;
|
2025-11-01 08:18:17 +01:00
|
|
|
create extension if not exists isn schema ext;
|
2025-10-14 22:28:15 +02:00
|
|
|
|
|
|
|
|
create schema pgtap;
|
|
|
|
|
create extension if not exists pgtap schema pgtap;
|
2025-09-01 07:56:13 +02:00
|
|
|
|
2025-10-17 07:29:28 +02:00
|
|
|
-- ----------------------------------------------------------------------
|
2025-10-31 07:42:56 +01:00
|
|
|
-- Pays
|
2025-10-17 07:29:28 +02:00
|
|
|
-- ----------------------------------------------------------------------
|
2025-11-01 14:28:58 +01:00
|
|
|
create schema geo;
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
select 'Pays --------------------' as msg;
|
2025-11-01 14:28:58 +01:00
|
|
|
|
|
|
|
|
create table geo.pays (
|
2025-10-17 07:29:28 +02:00
|
|
|
code2 text not null,
|
|
|
|
|
code3 text not null,
|
|
|
|
|
code_num text not null,
|
|
|
|
|
pays text not null,
|
|
|
|
|
forme_longue text,
|
|
|
|
|
nom_eng text,
|
|
|
|
|
nom_spa text,
|
|
|
|
|
drapeau_unicode character(2)
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
comment on column geo.pays.code2
|
2025-10-17 07:29:28 +02:00
|
|
|
is 'code ISO 3166-1 alpha 2';
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
comment on column geo.pays.code3
|
2025-10-17 07:29:28 +02:00
|
|
|
is 'code ISO 3166-1 alpha 3';
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
comment on column geo.pays.code_num
|
2025-10-17 07:29:28 +02:00
|
|
|
is 'code ISO 3166-1 numérique. Identique à la division statistique des Nations Unies UN M.49';
|
|
|
|
|
|
|
|
|
|
create index pays_nom
|
2025-11-01 14:28:58 +01:00
|
|
|
on geo.pays using btree (pays asc nulls last);
|
2025-10-17 07:29:28 +02:00
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays
|
2025-10-17 07:29:28 +02:00
|
|
|
add check (code2 ~ '^[A-Z]{2}$');
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays
|
2025-10-17 07:29:28 +02:00
|
|
|
add check (code3 ~ '^[A-Z]{3}$');
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays
|
2025-10-17 07:29:28 +02:00
|
|
|
add check (code_num ~ '^[0-9]{3}$');
|
|
|
|
|
|
|
|
|
|
create unique index pays_pk
|
2025-11-01 14:28:58 +01:00
|
|
|
on geo.pays
|
2025-10-17 07:29:28 +02:00
|
|
|
using btree (code2);
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays
|
2025-10-17 07:29:28 +02:00
|
|
|
add primary key using index pays_pk;
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
\copy geo.pays (code2, code3, code_num, pays, drapeau_unicode, forme_longue) from '/tmp/geo/pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
2025-10-17 07:29:28 +02:00
|
|
|
|
|
|
|
|
-- Noms des pays en anglais et espagnol
|
|
|
|
|
|
|
|
|
|
create temporary table pays_tmp (
|
|
|
|
|
nom text,
|
|
|
|
|
code_num text,
|
|
|
|
|
code3 text
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
\copy pays_tmp FROM '/tmp/geo/pays_es.txt' (FORMAT CSV, delimiter E'\t', ENCODING 'UTF8');
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
update geo.pays set nom_spa = (select t.nom from pays_tmp t where pays.code3 = t.code3);
|
2025-10-17 07:29:28 +02:00
|
|
|
|
|
|
|
|
truncate table pays_tmp;
|
|
|
|
|
|
|
|
|
|
\copy pays_tmp FROM '/tmp/geo/pays_en.txt' (FORMAT CSV, delimiter E'\t', ENCODING 'UTF8');
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
update geo.pays set nom_eng = (select t.nom from pays_tmp t where pays.code3 = t.code3);
|
|
|
|
|
update geo.pays set nom_eng = 'Taiwan' where code2 = 'TW';
|
2025-10-17 07:29:28 +02:00
|
|
|
|
|
|
|
|
drop table pays_tmp;
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- langues
|
|
|
|
|
-- ----------------------------------------------------------------------
|
2025-11-01 14:28:58 +01:00
|
|
|
|
2025-11-01 16:36:49 +01:00
|
|
|
select 'Langues ----------------' as msg;
|
2025-11-01 14:28:58 +01:00
|
|
|
|
|
|
|
|
create table geo.langues (
|
2025-10-17 07:29:28 +02:00
|
|
|
code3 char(3) not null,
|
|
|
|
|
langue text default null,
|
|
|
|
|
francais text default null
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
comment on table geo.langues is 'ISO 639-3';
|
2025-10-17 07:29:28 +02:00
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add check (code3 ~ '^[a-z]{3}$');
|
|
|
|
|
|
|
|
|
|
create unique index langues_pk
|
2025-11-01 14:28:58 +01:00
|
|
|
on geo.langues
|
2025-10-17 07:29:28 +02:00
|
|
|
using btree (code3);
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add primary key using index langues_pk;
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
create table geo.pays_langues (
|
2025-10-17 07:29:28 +02:00
|
|
|
pays_code char(2) not null,
|
|
|
|
|
langue_code char(3) not null,
|
|
|
|
|
officiel boolean default false,
|
|
|
|
|
pourcentage decimal(4,1) not null DEFAULT '0.0'
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays_langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add check (pays_code ~ '^[A-Z]{2}$');
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays_langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add check (langue_code ~ '^[a-z]{3}$');
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table geo.pays_langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add primary key (pays_code, langue_code);
|
|
|
|
|
|
2025-11-01 14:28:58 +01:00
|
|
|
\copy geo.langues from '/tmp/geo/langues.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
|
|
|
\copy geo.pays_langues from '/tmp/geo/langues_pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
2025-10-17 07:29:28 +02:00
|
|
|
|
|
|
|
|
-- pays_langues -> pays
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table only geo.pays_langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add foreign key (pays_code)
|
2025-11-01 14:28:58 +01:00
|
|
|
references geo.pays (code2) match simple
|
2025-10-17 07:29:28 +02:00
|
|
|
on update no action
|
|
|
|
|
on delete no action;
|
|
|
|
|
|
|
|
|
|
-- pays_langues -> langues
|
2025-11-01 14:28:58 +01:00
|
|
|
alter table only geo.pays_langues
|
2025-10-17 07:29:28 +02:00
|
|
|
add foreign key (langue_code)
|
2025-11-01 14:28:58 +01:00
|
|
|
references geo.langues (code3) match simple
|
2025-10-17 07:29:28 +02:00
|
|
|
on update no action
|
|
|
|
|
on delete no action;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
2025-10-31 07:42:56 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Fournisseurs
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
create table fournisseur (
|
|
|
|
|
id int primary key,
|
|
|
|
|
fournisseur text not null
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Produits
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
create table produit (
|
|
|
|
|
id bigint primary key,
|
2025-11-01 08:18:17 +01:00
|
|
|
ean13 ext.EAN13 null,
|
2025-10-31 07:42:56 +01:00
|
|
|
nom text not null,
|
|
|
|
|
marque text null,
|
|
|
|
|
categorie text null,
|
|
|
|
|
energie int not null,
|
|
|
|
|
proteines float4 null,
|
|
|
|
|
glucides float4 null,
|
|
|
|
|
sucres float4 null,
|
|
|
|
|
graisses float4 null,
|
|
|
|
|
graisses_saturees float4 null,
|
|
|
|
|
sel float4 null,
|
|
|
|
|
fibres float4 null,
|
|
|
|
|
nutriscore int null,
|
|
|
|
|
additifs int null,
|
|
|
|
|
additifs_list text[] null,
|
|
|
|
|
potassium float null,
|
|
|
|
|
calcium float null,
|
|
|
|
|
magnesium float null,
|
|
|
|
|
sodium float null,
|
|
|
|
|
chlorure float null,
|
|
|
|
|
sulfate float null,
|
|
|
|
|
nitrate float null,
|
|
|
|
|
hydrogenocarbonate float null,
|
|
|
|
|
silice float null,
|
|
|
|
|
fluor float null,
|
|
|
|
|
residu float null,
|
|
|
|
|
ph float null,
|
|
|
|
|
vitamin_a float null,
|
|
|
|
|
vitamin_c float null
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
-- Ajouter les commentaires
|
|
|
|
|
comment on column produit.potassium IS 'K⁺ en mg/L';
|
|
|
|
|
comment on column produit.calcium IS 'Ca²⁺ en mg/L';
|
|
|
|
|
comment on column produit.magnesium IS 'Mg²⁺ en mg/L';
|
|
|
|
|
comment on column produit.sodium IS 'Na⁺ en mg/L';
|
|
|
|
|
comment on column produit.chlorure IS 'Cl⁻ en mg/L';
|
|
|
|
|
comment on column produit.sulfate IS 'SO₄²⁻ en mg/L';
|
|
|
|
|
comment on column produit.nitrate IS 'NO₃⁻ en mg/L';
|
|
|
|
|
comment on column produit.hydrogenocarbonate IS 'HCO₃⁻ en mg/L';
|
|
|
|
|
comment on column produit.silice IS 'SiO₂ en mg/L';
|
|
|
|
|
comment on column produit.fluor IS 'F en mg/L';
|
|
|
|
|
|
2025-09-01 07:56:13 +02:00
|
|
|
create table adherent (
|
|
|
|
|
id int primary key,
|
|
|
|
|
nom text,
|
|
|
|
|
prenom text,
|
|
|
|
|
genre smallint,
|
|
|
|
|
naissance date,
|
|
|
|
|
codepostal text
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Marché (Market)
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
create schema market;
|
|
|
|
|
|
2025-09-01 07:56:13 +02:00
|
|
|
create table famille (
|
|
|
|
|
code text primary key,
|
|
|
|
|
famille text,
|
|
|
|
|
code_parent text, -- references famille(code)
|
2025-10-14 22:28:15 +02:00
|
|
|
arborescence ext.ltree
|
2025-09-01 07:56:13 +02:00
|
|
|
);
|
|
|
|
|
|
|
|
|
|
create table article (
|
|
|
|
|
code text primary key,
|
|
|
|
|
article text,
|
|
|
|
|
famille_code text, -- references famille(code)
|
|
|
|
|
factpoids boolean,
|
|
|
|
|
unitevente int,
|
|
|
|
|
prix decimal,
|
|
|
|
|
suivistock int
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
create table market.ticket (
|
2025-09-01 07:56:13 +02:00
|
|
|
id int primary key,
|
|
|
|
|
date_ticket timestamp,
|
2025-11-02 07:35:49 +01:00
|
|
|
adherent_id int, -- references adherent(id)
|
2025-09-01 07:56:13 +02:00
|
|
|
mode_rglt int
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
create table market.ligne (
|
2025-09-01 07:56:13 +02:00
|
|
|
id int primary key,
|
2025-11-02 07:35:49 +01:00
|
|
|
ticket_id int, -- references ticket (id),
|
2025-09-01 07:56:13 +02:00
|
|
|
article_code text, -- references article (code)
|
|
|
|
|
prix_unitaire decimal,
|
|
|
|
|
quantite decimal
|
|
|
|
|
);
|
2025-09-12 12:54:16 +02:00
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
alter table market.ligne
|
2025-11-01 08:18:17 +01:00
|
|
|
add column total decimal
|
|
|
|
|
generated always as (prix_unitaire * quantite) stored;
|
|
|
|
|
|
|
|
|
|
create table prix_historique (
|
|
|
|
|
id int generated always as identity,
|
|
|
|
|
article_code text not null,
|
|
|
|
|
prix_unitaire decimal not null,
|
|
|
|
|
dates daterange not null
|
|
|
|
|
);
|
2025-09-17 00:39:54 +02:00
|
|
|
|
2025-09-14 22:12:09 +02:00
|
|
|
create table marque (
|
|
|
|
|
id int primary key,
|
2025-10-31 07:42:56 +01:00
|
|
|
marque text not null,
|
|
|
|
|
fournisseur_id int
|
2025-09-14 22:12:09 +02:00
|
|
|
);
|
|
|
|
|
|
2025-10-31 07:42:56 +01:00
|
|
|
create table categorie (
|
2025-09-12 12:54:16 +02:00
|
|
|
id int primary key,
|
2025-10-31 07:42:56 +01:00
|
|
|
categorie text not null
|
2025-09-12 12:54:16 +02:00
|
|
|
);
|
|
|
|
|
|
2025-11-01 16:36:49 +01:00
|
|
|
CREATE TABLE employees (
|
|
|
|
|
"EmployeeID" smallint NOT NULL,
|
|
|
|
|
"LastName" character varying(20) NOT NULL,
|
|
|
|
|
"FirstName" character varying(10) NOT NULL,
|
|
|
|
|
"Title" character varying(30),
|
|
|
|
|
"TitleOfCourtesy" character varying(25),
|
|
|
|
|
"BirthDate" date,
|
|
|
|
|
"HireDate" date,
|
|
|
|
|
"Address" character varying(60),
|
|
|
|
|
"City" character varying(15),
|
|
|
|
|
"Region" character varying(15),
|
|
|
|
|
"PostalCode" character varying(10),
|
|
|
|
|
"Country" character varying(15),
|
|
|
|
|
"HomePhone" character varying(24),
|
|
|
|
|
"Extension" character varying(4),
|
|
|
|
|
"Photo" bytea,
|
|
|
|
|
"Notes" text,
|
|
|
|
|
"ReportsTo" smallint,
|
|
|
|
|
"PhotoPath" character varying(255)
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
2025-09-12 22:14:49 +02:00
|
|
|
create table region (
|
2025-09-12 12:54:16 +02:00
|
|
|
id int primary key,
|
|
|
|
|
region text not null
|
|
|
|
|
);
|
2025-09-12 22:14:49 +02:00
|
|
|
|
|
|
|
|
insert into region values
|
2025-10-31 07:42:56 +01:00
|
|
|
(1, 'Est'), (2, 'Ouest'), (3, 'Nord'), (4, 'Sud'), (5, 'Centre');
|
|
|
|
|
|
2025-11-01 08:18:17 +01:00
|
|
|
|
|
|
|
|
create table personne (
|
2025-11-02 07:35:49 +01:00
|
|
|
id bigint,
|
2025-11-01 08:18:17 +01:00
|
|
|
prenom text,
|
|
|
|
|
nom text,
|
|
|
|
|
telephone text,
|
|
|
|
|
ville text
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
create table societe (
|
2025-11-02 07:35:49 +01:00
|
|
|
id bigint,
|
2025-11-01 08:18:17 +01:00
|
|
|
societe text
|
2025-11-01 16:36:49 +01:00
|
|
|
);
|
2025-11-01 08:18:17 +01:00
|
|
|
|
|
|
|
|
|
2025-11-01 16:36:49 +01:00
|
|
|
/*
|
2025-11-01 08:18:17 +01:00
|
|
|
CREATE TABLE emplois (
|
|
|
|
|
id bigint generated always as identity,
|
|
|
|
|
id_personne int NOT NULL,
|
|
|
|
|
id_societe int NOT NULL,
|
|
|
|
|
dates daterange,
|
2025-11-01 16:36:49 +01:00
|
|
|
temps_travail decimal(5,2) DEFAULT 151.67 CHECK(temps_travail > 0 AND temps_travail <= 400),
|
2025-11-01 08:18:17 +01:00
|
|
|
salaire_mensuel decimal(10,2) NOT NULL,
|
|
|
|
|
poste text,
|
2025-11-01 16:36:49 +01:00
|
|
|
FOREIGN KEY (id_personne) REFERENCES personne(id),
|
2025-11-01 08:18:17 +01:00
|
|
|
FOREIGN KEY (id_societe) REFERENCES societe(id)
|
|
|
|
|
);
|
2025-11-01 14:29:19 +01:00
|
|
|
*/
|
2025-11-01 08:18:17 +01:00
|
|
|
|
2025-11-01 14:29:19 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Banque
|
|
|
|
|
-- ----------------------------------------------------------------------
|
2025-11-01 08:18:17 +01:00
|
|
|
|
2025-11-01 14:29:19 +01:00
|
|
|
create schema banque;
|
2025-11-01 08:18:17 +01:00
|
|
|
|
2025-11-01 14:29:19 +01:00
|
|
|
-- Générateur de numéro aléatoire
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
CREATE OR REPLACE FUNCTION banque.rand_account(n integer)
|
|
|
|
|
RETURNS text AS $$
|
|
|
|
|
DECLARE
|
2025-11-02 07:35:49 +01:00
|
|
|
chars text := '0123456789ABCDEFGHJKLMNPRSTUWXYZ';
|
2025-11-01 14:29:19 +01:00
|
|
|
out text := '';
|
|
|
|
|
b bytea := gen_random_bytes(n); -- n octets aléatoires
|
|
|
|
|
i int;
|
|
|
|
|
idx int;
|
|
|
|
|
BEGIN
|
|
|
|
|
IF n <= 0 THEN
|
|
|
|
|
RAISE EXCEPTION 'La longueur doit être > 0';
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
FOR i IN 0..(n - 1) LOOP
|
|
|
|
|
idx := (get_byte(b, i) % length(chars)) + 1;
|
|
|
|
|
out := out || substr(chars, idx, 1);
|
|
|
|
|
END LOOP;
|
|
|
|
|
|
|
|
|
|
RETURN out;
|
|
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
-- Devises (Currencies)
|
2025-11-01 14:29:19 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
2025-11-01 16:36:49 +01:00
|
|
|
create table banque.currency (
|
2025-11-01 14:29:19 +01:00
|
|
|
code text not null,
|
|
|
|
|
num4217 integer default null,
|
|
|
|
|
symbole character varying(5) default null,
|
|
|
|
|
nom text default null,
|
|
|
|
|
division integer default 0,
|
|
|
|
|
minor text default null,
|
|
|
|
|
minors text default null
|
|
|
|
|
);
|
|
|
|
|
|
2025-11-01 16:36:49 +01:00
|
|
|
alter table banque.currency
|
2025-11-01 14:29:19 +01:00
|
|
|
add check (code ~ '^[A-Z]{3}$');
|
|
|
|
|
|
|
|
|
|
create table pays_devises (
|
|
|
|
|
pays_code text not null,
|
|
|
|
|
devise_code text not null,
|
|
|
|
|
valide daterange default null
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
alter table pays_devises
|
|
|
|
|
add check (pays_code ~ '^[A-Z]{2}$');
|
|
|
|
|
|
|
|
|
|
alter table pays_devises
|
|
|
|
|
add check (devise_code ~ '^[A-Z]{3}$');
|
|
|
|
|
|
|
|
|
|
create unique index currency_pk
|
2025-11-01 16:36:49 +01:00
|
|
|
on banque.currency
|
2025-11-01 14:29:19 +01:00
|
|
|
using btree (code);
|
|
|
|
|
|
2025-11-01 16:36:49 +01:00
|
|
|
alter table banque.currency
|
2025-11-01 14:29:19 +01:00
|
|
|
add primary key using index currency_pk;
|
|
|
|
|
|
2025-11-02 07:47:26 +01:00
|
|
|
\copy banque.currency from '/tmp/banque/devises.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
|
|
|
\copy pays_devises from '/tmp/banque/devises_pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
2025-11-01 14:29:19 +01:00
|
|
|
|
|
|
|
|
-- pays_devises -> pays
|
|
|
|
|
alter table only pays_devises
|
|
|
|
|
add foreign key (pays_code)
|
|
|
|
|
references geo.pays (code2);
|
|
|
|
|
|
|
|
|
|
-- pays_devises -> devises
|
|
|
|
|
alter table only pays_devises
|
|
|
|
|
add foreign key (devise_code)
|
2025-11-01 16:36:49 +01:00
|
|
|
references banque.currency (code);
|
2025-11-01 14:29:19 +01:00
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
-- Taux de change ()
|
|
|
|
|
-- ----------------------------------------------------------------------
|
2025-11-01 14:29:19 +01:00
|
|
|
CREATE TABLE banque.exchange_rate (
|
2025-11-01 16:36:49 +01:00
|
|
|
from_currency CHAR(3) references banque.currency(code),
|
|
|
|
|
to_currency CHAR(3) references banque.currency(code),
|
|
|
|
|
rate DECIMAL(12,6) NOT NULL,
|
|
|
|
|
fee_percent DECIMAL(5,2) DEFAULT 0,
|
|
|
|
|
last_updated TIMESTAMP DEFAULT NOW(),
|
|
|
|
|
PRIMARY KEY (from_currency, to_currency, last_updated)
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
create temporary table exchange (
|
|
|
|
|
jour date,
|
|
|
|
|
rate decimal(12,6)
|
2025-11-01 14:29:19 +01:00
|
|
|
);
|
2025-11-01 16:36:49 +01:00
|
|
|
|
|
|
|
|
DO $$
|
|
|
|
|
DECLARE
|
|
|
|
|
rec RECORD;
|
|
|
|
|
path TEXT;
|
|
|
|
|
BEGIN
|
|
|
|
|
-- Liste des devises à importer
|
|
|
|
|
FOR rec IN
|
|
|
|
|
SELECT code FROM banque.currency WHERE code <> 'EUR'
|
|
|
|
|
LOOP
|
|
|
|
|
path := format('/tmp/webstat/Webstat_Export_fr_EXR.M.%s.EUR.SP00.E.csv', rec.code);
|
|
|
|
|
|
|
|
|
|
-- Import CSV temporaire
|
|
|
|
|
EXECUTE format(
|
|
|
|
|
$sql$
|
|
|
|
|
copy exchange FROM %L (FORMAT CSV, HEADER, DELIMITER ';', ENCODING 'UTF8')
|
|
|
|
|
$sql$,
|
|
|
|
|
path
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
-- Insertion dans la table principale
|
|
|
|
|
EXECUTE format(
|
|
|
|
|
$sql$
|
|
|
|
|
INSERT INTO banque.exchange_rate (from_currency, to_currency, rate, fee_percent, last_updated)
|
|
|
|
|
SELECT 'EUR', %L, rate, 0, jour FROM exchange
|
|
|
|
|
$sql$,
|
|
|
|
|
rec.code
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
-- Nettoyage
|
|
|
|
|
TRUNCATE TABLE exchange;
|
|
|
|
|
END LOOP;
|
|
|
|
|
END $$;
|
|
|
|
|
|
|
|
|
|
DROP table exchange;
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Titulaires
|
2025-11-01 14:29:19 +01:00
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
CREATE TABLE banque.titulaire (
|
2025-11-01 14:29:19 +01:00
|
|
|
id bigint primary key generated always as identity,
|
2025-11-02 07:35:49 +01:00
|
|
|
type_titulaire TEXT CHECK (type_titulaire IN ('individu', 'société')) NOT NULL,
|
|
|
|
|
created_at timestamp with time zone not null default now()
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
CREATE FUNCTION auto_titulaire_physique()
|
|
|
|
|
RETURNS TRIGGER AS $$
|
|
|
|
|
DECLARE
|
|
|
|
|
new_titulaire_id INTEGER;
|
|
|
|
|
BEGIN
|
|
|
|
|
IF NEW.id IS NULL THEN
|
|
|
|
|
INSERT INTO banque.titulaire (type_titulaire) VALUES ('individu')
|
|
|
|
|
RETURNING id INTO new_titulaire_id;
|
|
|
|
|
NEW.id := new_titulaire_id;
|
|
|
|
|
END IF;
|
|
|
|
|
RETURN NEW;
|
|
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE TRIGGER trg_auto_titulaire_physique
|
|
|
|
|
BEFORE INSERT ON personne
|
|
|
|
|
FOR EACH ROW
|
|
|
|
|
EXECUTE FUNCTION auto_titulaire_physique();
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION auto_titulaire_morale()
|
|
|
|
|
RETURNS TRIGGER AS $$
|
|
|
|
|
DECLARE
|
|
|
|
|
new_titulaire_id INTEGER;
|
|
|
|
|
BEGIN
|
|
|
|
|
IF NEW.id IS NULL THEN
|
|
|
|
|
INSERT INTO banque.titulaire (type_titulaire) VALUES ('morale')
|
|
|
|
|
RETURNING id INTO new_titulaire_id;
|
|
|
|
|
NEW.id := new_titulaire_id;
|
|
|
|
|
END IF;
|
|
|
|
|
RETURN NEW;
|
|
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE TRIGGER trg_auto_titulaire_morale
|
|
|
|
|
BEFORE INSERT ON societe
|
|
|
|
|
FOR EACH ROW
|
|
|
|
|
EXECUTE FUNCTION auto_titulaire_morale();
|
|
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Comptes (Accounts)
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
create table banque.account (
|
|
|
|
|
id bigint primary key generated always as identity,
|
|
|
|
|
account_number text unique not null,
|
|
|
|
|
balance numeric(18,6) not null default 0,
|
|
|
|
|
currency char(3) not null,
|
|
|
|
|
created_at timestamp with time zone not null default now()
|
2025-11-01 08:18:17 +01:00
|
|
|
);
|
|
|
|
|
|
2025-11-02 07:35:49 +01:00
|
|
|
create table banque.account_holders (
|
|
|
|
|
account_id bigint NOT NULL REFERENCES banque.account(id) ON DELETE CASCADE,
|
|
|
|
|
titulaire_id int NOT NULL REFERENCES banque.titulaire(id) ON DELETE CASCADE,
|
|
|
|
|
share numeric(5,2) CHECK (share >= 0 AND share <= 100),
|
|
|
|
|
role text DEFAULT 'Titulaire',
|
|
|
|
|
PRIMARY KEY (account_id, titulaire_id)
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
2025-11-01 14:29:19 +01:00
|
|
|
CREATE TABLE banque."transaction" (
|
|
|
|
|
id UUID PRIMARY KEY DEFAULT uuidv7(),
|
2025-11-01 08:18:17 +01:00
|
|
|
reference TEXT,
|
2025-11-02 07:35:49 +01:00
|
|
|
amount NUMERIC(18,6) NOT NULL,
|
2025-11-01 08:18:17 +01:00
|
|
|
currency CHAR(3) NOT NULL,
|
2025-11-01 14:29:19 +01:00
|
|
|
from_account BIGINT NOT NULL REFERENCES banque.account(id),
|
|
|
|
|
to_account BIGINT NOT NULL REFERENCES banque.account(id),
|
2025-11-01 08:18:17 +01:00
|
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
|
|
|
|
processed BOOLEAN NOT NULL DEFAULT FALSE -- indique si ledger + soldes ont été appliqués
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
-- ledger (écritures comptables immuables) : append-only
|
2025-11-01 14:29:19 +01:00
|
|
|
CREATE TABLE banque.ledger_entry (
|
|
|
|
|
id bigint primary key generated always as identity,
|
|
|
|
|
transaction_id UUID NOT NULL REFERENCES banque."transaction"(id),
|
|
|
|
|
account_id BIGINT NOT NULL REFERENCES banque.account(id),
|
2025-11-02 07:35:49 +01:00
|
|
|
amount NUMERIC(18,6) NOT NULL, -- convention: positif = crédit, négatif = débit (ici from = -amount, to = +amount)
|
2025-11-01 08:18:17 +01:00
|
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
|
|
|
|
description TEXT
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
-- index pour performance et idempotence par transaction/account
|
2025-11-01 14:29:19 +01:00
|
|
|
CREATE UNIQUE INDEX ux_ledger_tx_account
|
|
|
|
|
ON banque.ledger_entry(transaction_id, account_id);
|
2025-11-01 08:18:17 +01:00
|
|
|
|
|
|
|
|
-- outbox pour publisher reliable (pattern outbox)
|
2025-11-01 14:29:19 +01:00
|
|
|
CREATE TABLE banque.outbox_event (
|
|
|
|
|
id bigint primary key generated always as identity,
|
2025-11-01 08:18:17 +01:00
|
|
|
occurrenced_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
|
|
|
|
topic TEXT NOT NULL,
|
|
|
|
|
payload JSONB NOT NULL,
|
|
|
|
|
transaction_id UUID, -- lien optionnel
|
|
|
|
|
processed BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
|
processed_at TIMESTAMP WITH TIME ZONE NULL
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
-- table very simple de blockchain / chain d'audit
|
2025-11-01 14:29:19 +01:00
|
|
|
CREATE TABLE banque.block_chain (
|
|
|
|
|
id bigint primary key generated always as identity,
|
2025-11-01 08:18:17 +01:00
|
|
|
block_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
|
|
|
|
tx_id UUID NOT NULL, -- transaction incluse dans ce bloc (ou multiple selon choix)
|
|
|
|
|
previous_hash TEXT NULL,
|
|
|
|
|
block_hash TEXT NOT NULL,
|
|
|
|
|
block_data JSONB NOT NULL -- stockage lisible des éléments du bloc (pour audit)
|
|
|
|
|
);
|
2025-11-01 14:29:19 +01:00
|
|
|
|
|
|
|
|
CREATE INDEX idx_block_chain_txid ON banque.block_chain(tx_id);
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION perform_transaction(
|
|
|
|
|
from_account_id INT,
|
|
|
|
|
to_account_id INT,
|
2025-11-02 07:35:49 +01:00
|
|
|
amount DECIMAL(18,6),
|
2025-11-01 14:29:19 +01:00
|
|
|
description TEXT
|
|
|
|
|
) RETURNS VOID AS $$
|
|
|
|
|
DECLARE
|
|
|
|
|
from_currency CHAR(3);
|
|
|
|
|
to_currency CHAR(3);
|
|
|
|
|
rate DECIMAL(12,6);
|
2025-11-02 07:35:49 +01:00
|
|
|
fee DECIMAL(18,6);
|
|
|
|
|
base_amount DECIMAL(18,6);
|
|
|
|
|
converted_amount DECIMAL(18,6);
|
2025-11-01 14:29:19 +01:00
|
|
|
tx_id INT;
|
|
|
|
|
prev_hash TEXT;
|
|
|
|
|
new_hash TEXT;
|
|
|
|
|
BEGIN
|
|
|
|
|
SELECT currency_code INTO from_currency FROM banque.account WHERE id = from_account_id;
|
|
|
|
|
SELECT currency_code INTO to_currency FROM banque.account WHERE id = to_account_id;
|
|
|
|
|
|
|
|
|
|
SELECT hash INTO prev_hash FROM banque.transaction ORDER BY id DESC LIMIT 1;
|
|
|
|
|
|
|
|
|
|
-- Création de la transaction principale
|
|
|
|
|
INSERT INTO banque.transaction (description, previous_hash)
|
|
|
|
|
VALUES (description, prev_hash)
|
|
|
|
|
RETURNING id INTO tx_id;
|
|
|
|
|
|
|
|
|
|
IF from_currency = to_currency THEN
|
|
|
|
|
rate := 1;
|
|
|
|
|
fee := 0;
|
|
|
|
|
converted_amount := amount;
|
|
|
|
|
ELSE
|
|
|
|
|
SELECT rate, fee_percent INTO rate, fee
|
|
|
|
|
FROM banque.exchange_rate
|
2025-11-01 16:36:49 +01:00
|
|
|
WHERE from_currency = from_currency AND to_currency = to_currency ORDER BY last_updated desc LIMIT 1;
|
2025-11-01 14:29:19 +01:00
|
|
|
|
2025-11-01 16:36:49 +01:00
|
|
|
converted_amount := amount * rate * (1 - fee / 100);
|
2025-11-01 14:29:19 +01:00
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
-- Débit
|
|
|
|
|
INSERT INTO banque.ledger_entry (transaction_id, account_id, amount, currency_code, entry_type, rate_to_base, converted_amount)
|
|
|
|
|
VALUES (tx_id, from_account_id, -amount, from_currency, 'debit', rate, amount * rate);
|
|
|
|
|
|
|
|
|
|
-- Crédit
|
|
|
|
|
INSERT INTO banque.ledger_entry (transaction_id, account_id, amount, currency_code, entry_type, rate_to_base, converted_amount)
|
|
|
|
|
VALUES (tx_id, to_account_id, converted_amount, to_currency, 'credit', rate, converted_amount);
|
|
|
|
|
|
|
|
|
|
-- Mise à jour des soldes
|
|
|
|
|
UPDATE banque.account SET balance = balance - amount WHERE id = from_account_id;
|
2025-11-01 16:36:49 +01:00
|
|
|
UPDATE banque.account SET balance = balance + converted_amount WHERE id = to_account_id;
|
2025-11-01 14:29:19 +01:00
|
|
|
|
|
|
|
|
-- Génération du hash blockchain
|
|
|
|
|
SELECT encode(digest(concat(tx_id, description, prev_hash, NOW()::text), 'sha256'), 'hex') INTO new_hash;
|
|
|
|
|
UPDATE banque.transaction SET hash = new_hash WHERE id = tx_id;
|
|
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION notify_transaction()
|
|
|
|
|
RETURNS TRIGGER AS $$
|
|
|
|
|
DECLARE
|
|
|
|
|
payload JSON;
|
|
|
|
|
BEGIN
|
|
|
|
|
payload := json_build_object(
|
|
|
|
|
'transaction_id', NEW.id,
|
|
|
|
|
'description', NEW.description,
|
|
|
|
|
'timestamp', NEW.timestamp,
|
|
|
|
|
'hash', NEW.hash
|
|
|
|
|
);
|
|
|
|
|
PERFORM pg_notify('transactions', payload::text); -- canal PostgreSQL NOTIFY
|
|
|
|
|
RETURN NEW;
|
|
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE TRIGGER tr_notify_transaction
|
|
|
|
|
AFTER INSERT ON banque.transaction
|
|
|
|
|
FOR EACH ROW
|
|
|
|
|
EXECUTE FUNCTION notify_transaction();
|
|
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Business Intelligence
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
create schema business;
|
|
|
|
|
|
|
|
|
|
-- Chronologie
|
|
|
|
|
create table business.chronologie as
|
|
|
|
|
with recursive calendrier as (
|
|
|
|
|
select
|
|
|
|
|
'2010-01-01 00:00:00'::timestamp as jour
|
|
|
|
|
union all
|
|
|
|
|
select
|
|
|
|
|
jour + interval '1 day'
|
|
|
|
|
from calendrier
|
|
|
|
|
where jour + interval '1 day' <= '2026-12-31'
|
|
|
|
|
)
|
|
|
|
|
select
|
|
|
|
|
extract(epoch from jour) / 86400::int as jj,
|
|
|
|
|
jour,
|
|
|
|
|
extract (year from jour) as annee,
|
|
|
|
|
extract (month from jour) as mois,
|
|
|
|
|
extract (day from jour) as jmois,
|
|
|
|
|
extract (week from jour) as semaine,
|
|
|
|
|
extract (dow from jour) as jsemaine,
|
|
|
|
|
extract (doy from jour) as jannee,
|
|
|
|
|
floor((extract(month from jour) - 1) / 6) + 1 as semestre,
|
|
|
|
|
floor((extract(month from jour) - 1) / 4) + 1 as quadrimestre,
|
|
|
|
|
extract(quarter from jour)::int as trimestre,
|
|
|
|
|
floor((extract(month from jour) - 1) / 2) + 1 as bimestre,
|
|
|
|
|
extract (day from jour) / extract (day from (date_trunc('month', '2025-03-16'::date) + interval '1 month' - interval '1 day')) as frac_mois,
|
|
|
|
|
extract (doy from jour) / extract (doy from (extract (year from jour)||'-12-31')::date) as frac_annee
|
|
|
|
|
from calendrier;
|
|
|
|
|
|
|
|
|
|
comment on column business.chronologie.jj
|
|
|
|
|
is 'jour julien';
|
|
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Musique
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
-- Biblio
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
|
|
|
|
|
|
|
|
create schema biblio;
|
|
|
|
|
|
|
|
|
|
CREATE TABLE biblio.genres (
|
|
|
|
|
genre_id int primary key,
|
|
|
|
|
genre text
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
INSERT INTO biblio.genres (genre_id, genre) VALUES
|
|
|
|
|
(1,'Science-Fiction'),
|
|
|
|
|
(2,'Fantasy'),
|
|
|
|
|
(3,'Young adult'),
|
|
|
|
|
(4,'Bit-lit'),
|
|
|
|
|
(5,'Policier'),
|
|
|
|
|
(6,'Romance'),
|
|
|
|
|
(7,'Espionnage'),
|
|
|
|
|
(8,'Aventure'),
|
|
|
|
|
(9,'Fantastique'),
|
|
|
|
|
(10,'Historique'),
|
|
|
|
|
(11,'Noir'),
|
|
|
|
|
(12,'Biographie'),
|
|
|
|
|
(13,'Cyberpunk'),
|
|
|
|
|
(14,'Steampunk');
|
|
|
|
|
|
|
|
|
|
create table biblio.auteurs (
|
|
|
|
|
auteur_id integer not null,
|
|
|
|
|
nom text not null,
|
|
|
|
|
"references" text[]
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
create table biblio.editeurs (
|
|
|
|
|
editeur_id integer not null,
|
|
|
|
|
editeur_nom text not null,
|
|
|
|
|
ville text
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
create table biblio.oeuvres (
|
|
|
|
|
oeuvre_id integer not null,
|
|
|
|
|
titre text not null,
|
|
|
|
|
infos jsonb
|
|
|
|
|
--constraint fk_oeuvre_genre foreign key (genre_id) references genres (genre_id)
|
|
|
|
|
);
|