schema: carte
This commit is contained in:
19
.env.example
19
.env.example
@@ -7,16 +7,9 @@ PGADMIN_PASSWORD=!ChangeMe!
|
|||||||
|
|
||||||
POSTGREST_PASSWORD=!ChangeMe!
|
POSTGREST_PASSWORD=!ChangeMe!
|
||||||
|
|
||||||
# CouchDB
|
# PostgREST
|
||||||
COUCHDB_USER=admin
|
POSTGREST_USER=postgrest
|
||||||
COUCHDB_PASSWORD=!ChangeMe!
|
POSTGREST_PASSWORD=9012
|
||||||
|
POSTGREST_APP_SETTINGS_JWT_EXP=300
|
||||||
# MongoDB
|
POSTGREST_APP_SETTINGS_JWT_SECRET=ABCDEFGHJKLMNOPQRSTUVWXYZ0123456789 #example
|
||||||
MONGODB_USER=admin
|
POSTGREST_JWT_SECRET=uavILHVIPAfWtiQWNleZS5OdJYEMrSLXk6sY4YqO #example
|
||||||
MONGODB_PASSWORD=!ChangeMe!
|
|
||||||
|
|
||||||
# Redis
|
|
||||||
REDIS_PASSWORD=!ChangeMe!
|
|
||||||
|
|
||||||
# Neo4J
|
|
||||||
NEO4J_PASSWORD=!ChangeMe!
|
|
||||||
|
|||||||
19
data/categorie.csv
Normal file
19
data/categorie.csv
Normal file
@@ -0,0 +1,19 @@
|
|||||||
|
id,categorie
|
||||||
|
1,Cereal flakes with fruits
|
||||||
|
2,Cereal clusters with fruits
|
||||||
|
3,Mueslis with nuts
|
||||||
|
4,Chocolate cereals
|
||||||
|
5,Cereal clusters with chocolate
|
||||||
|
6,Mueslis
|
||||||
|
7,Breakfast cereals
|
||||||
|
8,Extruded cereals
|
||||||
|
9,Filled cereals
|
||||||
|
10,Mueslis with chocolate
|
||||||
|
11,Cereals with honey
|
||||||
|
12,Mixed cereal flakes
|
||||||
|
13,Cereal flakes with chocolate
|
||||||
|
14,Cereal flakes
|
||||||
|
15,Corn flakes
|
||||||
|
16,Crunchy mueslis
|
||||||
|
17,Cereals with fruits
|
||||||
|
18,Mueslis with fruits
|
||||||
|
@@ -89,7 +89,7 @@ id,marque,fournisseur
|
|||||||
170,Frosties,4
|
170,Frosties,4
|
||||||
171,Granola,5
|
171,Granola,5
|
||||||
172,Country Crisp,5
|
172,Country Crisp,5
|
||||||
173,Froot Loops,4v
|
173,Froot Loops,4
|
||||||
174,All Bran,4
|
174,All Bran,4
|
||||||
175,Corn Flakes,4
|
175,Corn Flakes,4
|
||||||
176,Miel Pops,4
|
176,Miel Pops,4
|
||||||
|
|||||||
|
@@ -1,4 +1,9 @@
|
|||||||
show server_version;
|
show server_version;
|
||||||
|
|
||||||
|
-- ----------------------------------------------------------------------
|
||||||
|
-- extensions
|
||||||
|
-- ----------------------------------------------------------------------
|
||||||
|
|
||||||
select * from pg_available_extensions;
|
select * from pg_available_extensions;
|
||||||
|
|
||||||
create schema postgis;
|
create schema postgis;
|
||||||
@@ -8,12 +13,14 @@ create extension if not exists pgrouting schema postgis;
|
|||||||
create schema ext;
|
create schema ext;
|
||||||
create extension if not exists ltree schema ext;
|
create extension if not exists ltree schema ext;
|
||||||
create extension if not exists pgcrypto 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 schema pgtap;
|
||||||
create extension if not exists pgtap schema pgtap;
|
create extension if not exists pgtap schema pgtap;
|
||||||
|
|
||||||
-- ----------------------------------------------------------------------
|
-- ----------------------------------------------------------------------
|
||||||
-- pays
|
-- Pays
|
||||||
-- ----------------------------------------------------------------------
|
-- ----------------------------------------------------------------------
|
||||||
create table pays (
|
create table pays (
|
||||||
code2 text not null,
|
code2 text not null,
|
||||||
@@ -186,6 +193,64 @@ alter table only pays_devises
|
|||||||
select '=============== FIN DES CLES ETRANGERES Geo' as msg;
|
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 (
|
create table adherent (
|
||||||
id int primary key,
|
id int primary key,
|
||||||
nom text,
|
nom text,
|
||||||
@@ -232,12 +297,13 @@ alter table ligne
|
|||||||
|
|
||||||
create table marque (
|
create table marque (
|
||||||
id int primary key,
|
id int primary key,
|
||||||
marque text not null
|
marque text not null,
|
||||||
|
fournisseur_id int
|
||||||
);
|
);
|
||||||
|
|
||||||
create table fournisseur (
|
create table categorie (
|
||||||
id int primary key,
|
id int primary key,
|
||||||
fournisseur text not null
|
categorie text not null
|
||||||
);
|
);
|
||||||
|
|
||||||
create table region (
|
create table region (
|
||||||
@@ -246,4 +312,25 @@ create table region (
|
|||||||
);
|
);
|
||||||
|
|
||||||
insert into region values
|
insert into region values
|
||||||
(1, 'Est'), (2, 'Ouest');
|
(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');
|
||||||
|
|||||||
@@ -13,4 +13,5 @@ truncate table fournisseur;
|
|||||||
\COPY ligne FROM '/tmp/ligne.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
\COPY ligne FROM '/tmp/ligne.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
|
||||||
\COPY marque FROM '/tmp/marque.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
\COPY marque FROM '/tmp/marque.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
\COPY fournisseur FROM '/tmp/marque.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
\COPY fournisseur FROM '/tmp/fournisseur.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
\COPY produit FROM '/tmp/produits/cereales_petitdejeuner.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
|||||||
@@ -1,6 +1,8 @@
|
|||||||
|
create schema carte;
|
||||||
|
|
||||||
set SEARCH_PATH to public,postgis;
|
set SEARCH_PATH to public,postgis;
|
||||||
|
|
||||||
create table point (
|
create table carte.point (
|
||||||
id serial primary key,
|
id serial primary key,
|
||||||
nom text not null,
|
nom text not null,
|
||||||
altitude double precision,
|
altitude double precision,
|
||||||
@@ -8,9 +10,9 @@ create table point (
|
|||||||
);
|
);
|
||||||
|
|
||||||
create index idx_point_geom
|
create index idx_point_geom
|
||||||
on point using gist (geom);
|
on carte.point using gist (geom);
|
||||||
|
|
||||||
create table route (
|
create table carte.route (
|
||||||
id serial primary key,
|
id serial primary key,
|
||||||
depart int,
|
depart int,
|
||||||
arrivee int,
|
arrivee int,
|
||||||
@@ -19,41 +21,118 @@ create table route (
|
|||||||
);
|
);
|
||||||
|
|
||||||
create index idx_route_geom
|
create index idx_route_geom
|
||||||
on route using gist (geom);
|
on carte.route using gist (geom);
|
||||||
|
|
||||||
create or replace function maj_longueur()
|
create or replace function maj_longueur()
|
||||||
returns trigger as $$
|
returns trigger as $$
|
||||||
begin
|
begin
|
||||||
new.longueur := postgis.st_length(new.geom) * 1000;
|
new.longueur := postgis.st_length(postgis.st_transform(new.geom, 2154));
|
||||||
return new;
|
return new;
|
||||||
end;
|
end;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
|
|
||||||
create trigger trigger_longueur
|
create trigger trigger_longueur
|
||||||
before insert or update on route
|
before insert or update on carte.route
|
||||||
for each row
|
for each row
|
||||||
execute function maj_longueur();
|
execute function maj_longueur();
|
||||||
|
|
||||||
-- ************************************************************
|
-- ----------------------------------------------------------------------
|
||||||
|
|
||||||
create table route_cout (
|
create table carte.route_cout (
|
||||||
route_id int references route(id),
|
route_id int references carte.route(id),
|
||||||
tag text,
|
tag text,
|
||||||
cout float,
|
cout float,
|
||||||
cout_inverse float,
|
cout_inverse float,
|
||||||
primary key (route_id, tag)
|
primary key (route_id, tag)
|
||||||
);
|
);
|
||||||
|
|
||||||
create table zone (
|
create table carte.zone (
|
||||||
id int primary key,
|
id int primary key,
|
||||||
nom text,
|
nom text,
|
||||||
categorie text,
|
categorie text,
|
||||||
geom postgis.geometry(multipolygon, 4326) -- on choisit srid 4326 (wgs84)
|
geom postgis.geometry(multipolygon, 4326) -- on choisit srid 4326 (wgs84)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- ************************************************************
|
-- ----------------------------------------------------------------------
|
||||||
|
\COPY carte.point FROM '/tmp/point.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
\COPY carte.route(id, depart, arrivee, geom) FROM '/tmp/route.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
\COPY carte.route_cout FROM '/tmp/route_cout.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
\COPY carte.zone FROM '/tmp/zone.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||||
|
-- ----------------------------------------------------------------------
|
||||||
|
|
||||||
\COPY point FROM '/tmp/point.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
-- ----------------------------------------------------------------------
|
||||||
\COPY route(id, depart, arrivee, geom) FROM '/tmp/route.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
-- Mise à jour des coût suivant la pente et la nature de la route
|
||||||
\COPY route_cout FROM '/tmp/route_cout.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
-- cout = longueur × coef_surface × ( 1 + coef_pente)
|
||||||
\COPY zone FROM '/tmp/zone.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
-- Avec un minimum : cout = max(cost, ϵ) pour éviter un coût négatif (< 0) en descente
|
||||||
|
|
||||||
|
WITH calc AS (
|
||||||
|
SELECT
|
||||||
|
r.id,
|
||||||
|
r.depart, r.arrivee,
|
||||||
|
rc.cout, rc.cout_inverse,
|
||||||
|
ST_Length(r.geom::geography) AS length_m,
|
||||||
|
p1.altitude AS alt_depart,
|
||||||
|
p2.altitude AS alt_arrivee,
|
||||||
|
rc.tag,
|
||||||
|
-- pente aller
|
||||||
|
(p2.altitude - p1.altitude) / NULLIF(ST_Length(r.geom::geography), 0) AS slope_forward,
|
||||||
|
-- pente retour
|
||||||
|
(p1.altitude - p2.altitude) / NULLIF(ST_Length(r.geom::geography), 0) AS slope_reverse,
|
||||||
|
CASE
|
||||||
|
WHEN tag = 'rue' THEN 1.0
|
||||||
|
WHEN tag = 'chemin' THEN 1.2
|
||||||
|
WHEN tag = 'sentier' THEN 1.4
|
||||||
|
ELSE 1.5
|
||||||
|
END as coef_surface
|
||||||
|
FROM carte.route r
|
||||||
|
JOIN carte.point p1 ON r.depart = p1.id
|
||||||
|
JOIN carte.point p2 ON r.arrivee = p2.id
|
||||||
|
JOIN carte.route_cout rc ON rc.route_id = r.id
|
||||||
|
),
|
||||||
|
costs AS (
|
||||||
|
SELECT *,
|
||||||
|
length_m * coef_surface *
|
||||||
|
CASE
|
||||||
|
WHEN slope_forward >= 0.10 THEN (1 + slope_forward * 3)
|
||||||
|
WHEN slope_forward >= 0.04 THEN (1 + slope_forward * 2)
|
||||||
|
WHEN slope_forward >= 0 THEN (1 + slope_forward * 1)
|
||||||
|
WHEN slope_forward >= -0.15 THEN (1 + slope_forward * 3)
|
||||||
|
ELSE (1 + abs(slope_forward) * 1) -- pénalité en cas de forte descente
|
||||||
|
end
|
||||||
|
AS new_cost_forward,
|
||||||
|
|
||||||
|
length_m * coef_surface *
|
||||||
|
CASE
|
||||||
|
WHEN slope_reverse >= 0.10 THEN (1 + slope_reverse * 3)
|
||||||
|
WHEN slope_reverse >= 0.04 THEN (1 + slope_reverse * 2)
|
||||||
|
WHEN slope_reverse >= 0 THEN (1 + slope_reverse * 1)
|
||||||
|
WHEN slope_reverse >= -0.15 THEN (1 + slope_reverse * 3)
|
||||||
|
ELSE (1 + abs(slope_reverse) * 1) -- pénalité en cas de forte descente
|
||||||
|
END
|
||||||
|
AS new_cost_reverse
|
||||||
|
FROM calc
|
||||||
|
)
|
||||||
|
UPDATE carte.route_cout rc
|
||||||
|
SET
|
||||||
|
cout = CASE WHEN rc.cout = -1 THEN -1
|
||||||
|
ELSE GREATEST(c.new_cost_forward, 0.01) END,
|
||||||
|
cout_inverse = CASE WHEN rc.cout_inverse = -1 THEN -1
|
||||||
|
ELSE GREATEST(c.new_cost_reverse, 0.01) END
|
||||||
|
FROM costs c
|
||||||
|
WHERE rc.route_id = c.id;
|
||||||
|
|
||||||
|
CREATE OR REPLACE VIEW carte.routes_a_star AS
|
||||||
|
SELECT
|
||||||
|
r.id AS id,
|
||||||
|
r.depart as source,
|
||||||
|
r.arrivee as target,
|
||||||
|
r.longueur,
|
||||||
|
rc.cout AS cost,
|
||||||
|
rc.cout_inverse AS reverse_cost,
|
||||||
|
ST_X(p1.geom) AS x1, ST_Y(p1.geom) AS y1,
|
||||||
|
ST_X(p2.geom) AS x2, ST_Y(p2.geom) AS y2,
|
||||||
|
r.geom
|
||||||
|
FROM carte.route r
|
||||||
|
JOIN carte.route_cout rc ON rc.route_id = r.id
|
||||||
|
JOIN carte.point p1 ON r.depart = p1.id
|
||||||
|
JOIN carte.point p2 ON r.arrivee = p2.id;
|
||||||
|
|||||||
Reference in New Issue
Block a user