337 lines
8.5 KiB
SQL
337 lines
8.5 KiB
SQL
show server_version;
|
|
|
|
-- ----------------------------------------------------------------------
|
|
-- extensions
|
|
-- ----------------------------------------------------------------------
|
|
|
|
select * from pg_available_extensions;
|
|
|
|
create schema postgis;
|
|
create extension if not exists postgis schema postgis;
|
|
create extension if not exists pgrouting schema postgis;
|
|
|
|
create schema ext;
|
|
create extension if not exists ltree schema ext;
|
|
create extension if not exists pgcrypto schema ext;
|
|
create extension if not exists vector schema ext;
|
|
create extension if not exists isn;
|
|
|
|
create schema pgtap;
|
|
create extension if not exists pgtap schema pgtap;
|
|
|
|
-- ----------------------------------------------------------------------
|
|
-- Pays
|
|
-- ----------------------------------------------------------------------
|
|
create table pays (
|
|
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)
|
|
);
|
|
|
|
comment on column pays.code2
|
|
is 'code ISO 3166-1 alpha 2';
|
|
|
|
comment on column pays.code3
|
|
is 'code ISO 3166-1 alpha 3';
|
|
|
|
comment on column pays.code_num
|
|
is 'code ISO 3166-1 numérique. Identique à la division statistique des Nations Unies UN M.49';
|
|
|
|
create index pays_nom
|
|
on pays using btree (pays asc nulls last);
|
|
|
|
alter table pays
|
|
add check (code2 ~ '^[A-Z]{2}$');
|
|
|
|
alter table pays
|
|
add check (code3 ~ '^[A-Z]{3}$');
|
|
|
|
alter table pays
|
|
add check (code_num ~ '^[0-9]{3}$');
|
|
|
|
create unique index pays_pk
|
|
on pays
|
|
using btree (code2);
|
|
|
|
alter table pays
|
|
add primary key using index pays_pk;
|
|
|
|
\copy pays (code2, code3, code_num, pays, drapeau_unicode, forme_longue) from '/tmp/geo/pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
|
|
-- 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');
|
|
|
|
update pays set nom_spa = (select t.nom from pays_tmp t where pays.code3 = t.code3);
|
|
|
|
truncate table pays_tmp;
|
|
|
|
\copy pays_tmp FROM '/tmp/geo/pays_en.txt' (FORMAT CSV, delimiter E'\t', ENCODING 'UTF8');
|
|
|
|
update pays set nom_eng = (select t.nom from pays_tmp t where pays.code3 = t.code3);
|
|
update pays set nom_eng = 'Taiwan' where code2 = 'TW';
|
|
|
|
drop table pays_tmp;
|
|
-- ----------------------------------------------------------------------
|
|
|
|
-- ----------------------------------------------------------------------
|
|
-- langues
|
|
-- ----------------------------------------------------------------------
|
|
create table langues (
|
|
code3 char(3) not null,
|
|
langue text default null,
|
|
francais text default null
|
|
);
|
|
|
|
comment on table langues is 'ISO 639-3';
|
|
|
|
alter table langues
|
|
add check (code3 ~ '^[a-z]{3}$');
|
|
|
|
create unique index langues_pk
|
|
on langues
|
|
using btree (code3);
|
|
|
|
alter table langues
|
|
add primary key using index langues_pk;
|
|
|
|
create table pays_langues (
|
|
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'
|
|
);
|
|
|
|
alter table pays_langues
|
|
add check (pays_code ~ '^[A-Z]{2}$');
|
|
|
|
alter table pays_langues
|
|
add check (langue_code ~ '^[a-z]{3}$');
|
|
|
|
alter table pays_langues
|
|
add primary key (pays_code, langue_code);
|
|
|
|
\copy langues from '/tmp/geo/langues.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
\copy pays_langues from '/tmp/geo/langues_pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
|
|
-- ----------------------------------------------------------------------
|
|
-- devises
|
|
-- ----------------------------------------------------------------------
|
|
create table devises (
|
|
devise_code text not null,
|
|
num4217 integer default null,
|
|
symbole character varying(5) default null,
|
|
nom text default null,
|
|
format text default null,
|
|
division integer default 0,
|
|
minor text default null,
|
|
minors text default null
|
|
);
|
|
|
|
alter table devises
|
|
add check (devise_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 devises_pk
|
|
on devises
|
|
using btree (devise_code);
|
|
|
|
alter table devises
|
|
add primary key using index devises_pk;
|
|
|
|
\copy devises from '/tmp/geo/devises.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
\copy pays_devises from '/tmp/geo/devises_pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8');
|
|
|
|
select '=============== GEO' as msg;
|
|
|
|
-- pays_langues -> pays
|
|
alter table only pays_langues
|
|
add foreign key (pays_code)
|
|
references pays (code2) match simple
|
|
on update no action
|
|
on delete no action;
|
|
|
|
-- pays_langues -> langues
|
|
alter table only pays_langues
|
|
add foreign key (langue_code)
|
|
references langues (code3) match simple
|
|
on update no action
|
|
on delete no action;
|
|
|
|
-- pays_devises -> pays
|
|
alter table only pays_devises
|
|
add foreign key (pays_code)
|
|
references pays (code2);
|
|
|
|
-- pays_devises -> devises
|
|
alter table only pays_devises
|
|
add foreign key (devise_code)
|
|
references devises (devise_code);
|
|
|
|
select '=============== FIN DES CLES ETRANGERES Geo' as msg;
|
|
-- ----------------------------------------------------------------------
|
|
|
|
-- ----------------------------------------------------------------------
|
|
-- Fournisseurs
|
|
-- ----------------------------------------------------------------------
|
|
|
|
create table fournisseur (
|
|
id int primary key,
|
|
fournisseur text not null
|
|
);
|
|
|
|
|
|
-- ----------------------------------------------------------------------
|
|
-- Produits
|
|
-- ----------------------------------------------------------------------
|
|
create table produit (
|
|
id bigint primary key,
|
|
ean13 EAN13 null,
|
|
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';
|
|
|
|
create table adherent (
|
|
id int primary key,
|
|
nom text,
|
|
prenom text,
|
|
genre smallint,
|
|
naissance date,
|
|
codepostal text
|
|
);
|
|
|
|
create table famille (
|
|
code text primary key,
|
|
famille text,
|
|
code_parent text, -- references famille(code)
|
|
arborescence ext.ltree
|
|
);
|
|
|
|
create table article (
|
|
code text primary key,
|
|
article text,
|
|
famille_code text, -- references famille(code)
|
|
factpoids boolean,
|
|
unitevente int,
|
|
prix decimal,
|
|
suivistock int
|
|
);
|
|
|
|
create table ticket (
|
|
id int primary key,
|
|
date_ticket timestamp,
|
|
adherent_id int, -- references adherent(id)
|
|
mode_rglt int
|
|
);
|
|
|
|
create table ligne (
|
|
id int primary key,
|
|
ticket_id int, --references ticket (id),
|
|
article_code text, -- references article (code)
|
|
prix_unitaire decimal,
|
|
quantite decimal
|
|
);
|
|
|
|
alter table ligne
|
|
add column total decimal generated always as (prix_unitaire * quantite) stored;
|
|
|
|
create table marque (
|
|
id int primary key,
|
|
marque text not null,
|
|
fournisseur_id int
|
|
);
|
|
|
|
create table categorie (
|
|
id int primary key,
|
|
categorie text not null
|
|
);
|
|
|
|
create table region (
|
|
id int primary key,
|
|
region text not null
|
|
);
|
|
|
|
insert into region values
|
|
(1, 'Est'), (2, 'Ouest'), (3, 'Nord'), (4, 'Sud'), (5, 'Centre');
|
|
|
|
CREATE TABLE genres (
|
|
genre_id int primary key,
|
|
genre text
|
|
);
|
|
|
|
INSERT INTO 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');
|