renommer postgresql entry point
This commit is contained in:
23
postgresql-entrypoint-initdb.d/10_postgrest.sql
Normal file
23
postgresql-entrypoint-initdb.d/10_postgrest.sql
Normal file
@@ -0,0 +1,23 @@
|
||||
create role postgrest nosuperuser nocreatedb nocreaterole noinherit noreplication nobypassrls
|
||||
login password '9012';
|
||||
|
||||
-- postgrest est le rôle utilisé par l'application pour se connecter à la base.
|
||||
-- Il doit être configuré pour avoir un accès très limité.
|
||||
-- Il s'agit d'un caméléon dont la tâche est de « devenir » un autre utilisateur pour servir des requêtes HTTP authentifiées.
|
||||
|
||||
-- Roles sans login. Il faut se connecter d'abord avec l'utilisateur postgrest.
|
||||
-- Puis celui-ci usurpe une des identités suivantes suivant le role présent dans le JWT.
|
||||
-- Lorsqu'une demande contient un JWT valide avec une revendication de rôle,
|
||||
-- PostgREST passera au rôle de base de données avec ce nom pendant la durée de la demande HTTP avec la commande :
|
||||
-- SET LOCAL ROLE adherent;
|
||||
create role anonyme nologin;
|
||||
create role adherent nologin;
|
||||
|
||||
-- L'utilisateur postgrest peut se connecter en tant que ...
|
||||
grant anonyme to postgrest;
|
||||
grant adherent to postgrest;
|
||||
|
||||
grant usage on schema public to anonyme;
|
||||
|
||||
alter default privileges in schema public
|
||||
grant select on tables to anonyme;
|
||||
1
postgresql-entrypoint-initdb.d/11_postgraphile.sql
Normal file
1
postgresql-entrypoint-initdb.d/11_postgraphile.sql
Normal file
@@ -0,0 +1 @@
|
||||
create role postgraphile inherit login password 'motdepasse';
|
||||
69
postgresql-entrypoint-initdb.d/1_initdb.sql
Normal file
69
postgresql-entrypoint-initdb.d/1_initdb.sql
Normal file
@@ -0,0 +1,69 @@
|
||||
select * from pg_available_extensions;
|
||||
|
||||
create extension if not exists ltree;
|
||||
create extension if not exists pgtap;
|
||||
create extension if not exists postgis;
|
||||
create extension if not exists pgrouting;
|
||||
create extension if not exists pgcrypto;
|
||||
|
||||
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 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
|
||||
);
|
||||
|
||||
create table fournisseur (
|
||||
id int primary key,
|
||||
fournisseur text not null
|
||||
);
|
||||
|
||||
create table region (
|
||||
id int primary key,
|
||||
region text not null
|
||||
);
|
||||
|
||||
insert into region values
|
||||
(1, 'Est'), (2, 'Ouest');
|
||||
16
postgresql-entrypoint-initdb.d/2_seed.sql
Normal file
16
postgresql-entrypoint-initdb.d/2_seed.sql
Normal file
@@ -0,0 +1,16 @@
|
||||
truncate table adherent;
|
||||
truncate table famille;
|
||||
truncate table article;
|
||||
truncate table ticket;
|
||||
truncate table ligne;
|
||||
truncate table marque;
|
||||
truncate table fournisseur;
|
||||
|
||||
\COPY adherent FROM '/tmp/adherent.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY famille FROM '/tmp/famille.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY article FROM '/tmp/article.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY ticket FROM '/tmp/ticket.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 fournisseur FROM '/tmp/marque.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
31
postgresql-entrypoint-initdb.d/3_views.sql
Normal file
31
postgresql-entrypoint-initdb.d/3_views.sql
Normal file
@@ -0,0 +1,31 @@
|
||||
create view nb_total_familles as
|
||||
select count(*) as nb_total_familles from famille;
|
||||
|
||||
create view nb_total_articles as
|
||||
select count(*) as nb_total_articles from article;
|
||||
|
||||
create view nb_total_tickets as
|
||||
select count(*) as nb_total_tickets from ticket;
|
||||
|
||||
create view nb_total_adherents as
|
||||
select count(*) as nb_total_adherents from adherent;
|
||||
|
||||
create materialized view detail_ticket as
|
||||
select t.id as ticket_id, t.date_ticket, t.mode_rglt,
|
||||
h.id as adherent_id, h.codepostal, h.genre,
|
||||
round(sum(l.total), 2) as total
|
||||
from ticket t
|
||||
join ligne l on l.ticket_id = t.id
|
||||
join adherent h on h.id = t.adherent_id
|
||||
group by t.id, h.id;
|
||||
|
||||
create materialized view detail_vente as
|
||||
select t.id as ticket_id, t.date_ticket, t.mode_rglt,
|
||||
h.id as adherent_id, h.codepostal, h.genre,
|
||||
l.article_code, a.famille_code,
|
||||
round(sum(l.total), 2) as total
|
||||
from ticket t
|
||||
join ligne l on l.ticket_id = t.id
|
||||
join adherent h on h.id = t.adherent_id
|
||||
join article a on a.code = l.article_code
|
||||
group by t.id, h.id, l.article_code, a.famille_code;
|
||||
28
postgresql-entrypoint-initdb.d/4_pgtap.sql
Normal file
28
postgresql-entrypoint-initdb.d/4_pgtap.sql
Normal file
@@ -0,0 +1,28 @@
|
||||
SELECT plan(4);
|
||||
|
||||
SELECT is(
|
||||
(SELECT nb_total_familles FROM nb_total_familles),
|
||||
137::bigint,
|
||||
'La table famille contient 137 enregistrements'
|
||||
);
|
||||
|
||||
SELECT is(
|
||||
(SELECT nb_total_articles FROM nb_total_articles),
|
||||
1099::bigint,
|
||||
'La table article contient 1099 enregistrements'
|
||||
);
|
||||
|
||||
SELECT is(
|
||||
(SELECT nb_total_adherents FROM nb_total_adherents),
|
||||
2439::bigint,
|
||||
'La table adherent contient 2439 enregistrements'
|
||||
);
|
||||
|
||||
SELECT is(
|
||||
(SELECT nb_total_tickets FROM nb_total_tickets),
|
||||
101616::bigint,
|
||||
'La table ticket contient 101 616 enregistrements'
|
||||
);
|
||||
|
||||
-- Termine le test
|
||||
SELECT * FROM finish();
|
||||
49
postgresql-entrypoint-initdb.d/5_nestedsets.sql
Normal file
49
postgresql-entrypoint-initdb.d/5_nestedsets.sql
Normal file
@@ -0,0 +1,49 @@
|
||||
alter table famille
|
||||
add column gauche int,
|
||||
add column droite int;
|
||||
|
||||
-- fonction auxiliaire récursive : reçoit le compteur 'n', retourne le compteur mis à jour
|
||||
CREATE OR REPLACE FUNCTION set_bounds(p_code text, n INT)
|
||||
RETURNS INT AS $$
|
||||
DECLARE
|
||||
child RECORD;
|
||||
BEGIN
|
||||
-- left
|
||||
UPDATE famille SET gauche = n WHERE code = p_code;
|
||||
n := n + 1;
|
||||
|
||||
-- parcours des enfants
|
||||
FOR child IN
|
||||
SELECT code FROM famille WHERE code_parent = p_code ORDER BY code
|
||||
LOOP
|
||||
n := set_bounds(child.code, n);
|
||||
END LOOP;
|
||||
|
||||
-- right
|
||||
UPDATE famille SET droite = n WHERE code = p_code;
|
||||
n := n + 1;
|
||||
|
||||
RETURN n;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- fonction principale : initialise et lance la reconstruction
|
||||
CREATE OR REPLACE FUNCTION rebuild_nested_sets()
|
||||
RETURNS VOID AS $$
|
||||
DECLARE
|
||||
root RECORD;
|
||||
n INT := 1;
|
||||
BEGIN
|
||||
-- remise à zéro (optionnel)
|
||||
UPDATE famille SET gauche = NULL, droite = NULL;
|
||||
|
||||
-- pour chaque racine
|
||||
FOR root IN
|
||||
SELECT code FROM famille WHERE code_parent IS NULL ORDER BY code
|
||||
LOOP
|
||||
n := set_bounds(root.code, n);
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
SELECT rebuild_nested_sets();
|
||||
1
postgresql-entrypoint-initdb.d/6_end.sql
Normal file
1
postgresql-entrypoint-initdb.d/6_end.sql
Normal file
@@ -0,0 +1 @@
|
||||
\dx
|
||||
39
postgresql-entrypoint-initdb.d/7_metabase.sql
Normal file
39
postgresql-entrypoint-initdb.d/7_metabase.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
-- Metabase
|
||||
|
||||
create role metabase_user with
|
||||
login
|
||||
nosuperuser
|
||||
nocreatedb
|
||||
nocreaterole
|
||||
noinherit
|
||||
noreplication
|
||||
connection limit -1
|
||||
password 'supermotdepasse';
|
||||
|
||||
create database metabase with
|
||||
owner metabase_user;
|
||||
|
||||
grant connect
|
||||
on database sql
|
||||
to metabase_user;
|
||||
|
||||
grant usage
|
||||
on schema public
|
||||
to metabase_user;
|
||||
|
||||
grant select
|
||||
on table famille, article
|
||||
to metabase_user;
|
||||
|
||||
-- Pour toutes les tables du schéma public
|
||||
grant select
|
||||
on all tables
|
||||
in schema public
|
||||
to metabase_user;
|
||||
|
||||
-- Privilège par défaut pour que chaque nouvelle table créée dans public donnera automatiquement le droit SELECT à metabase.
|
||||
alter default privileges
|
||||
in schema public
|
||||
grant select
|
||||
on tables
|
||||
to metabase_user;
|
||||
39
postgresql-entrypoint-initdb.d/8_superset.sql
Normal file
39
postgresql-entrypoint-initdb.d/8_superset.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
-- Apache Superset
|
||||
|
||||
create role superset_user with
|
||||
login
|
||||
nosuperuser
|
||||
nocreatedb
|
||||
nocreaterole
|
||||
noinherit
|
||||
noreplication
|
||||
connection limit -1
|
||||
password 'supermotdepasse';
|
||||
|
||||
create database superset with
|
||||
owner superset_user;
|
||||
|
||||
grant connect
|
||||
on database sql
|
||||
to superset_user;
|
||||
|
||||
grant usage
|
||||
on schema public
|
||||
to superset_user;
|
||||
|
||||
grant select
|
||||
on table famille, article
|
||||
to superset_user;
|
||||
|
||||
-- Pour toutes les tables du schéma public
|
||||
grant select
|
||||
on all tables
|
||||
in schema public
|
||||
to superset_user;
|
||||
|
||||
-- Privilège par défaut pour que chaque nouvelle table créée dans public donnera automatiquement le droit SELECT à superset_user.
|
||||
alter default privileges
|
||||
in schema public
|
||||
grant select
|
||||
on tables
|
||||
to superset_user;
|
||||
30
postgresql-entrypoint-initdb.d/9_json.sql
Normal file
30
postgresql-entrypoint-initdb.d/9_json.sql
Normal file
@@ -0,0 +1,30 @@
|
||||
create table item (
|
||||
id integer primary key,
|
||||
data jsonb
|
||||
);
|
||||
|
||||
DO $$
|
||||
DECLARE
|
||||
f TEXT;
|
||||
BEGIN
|
||||
FOR f IN SELECT pg_catalog.pg_ls_dir('/tmp/json')
|
||||
LOOP
|
||||
IF right(f, 5) = '.json' THEN
|
||||
BEGIN
|
||||
RAISE NOTICE 'Import du fichier : %', f;
|
||||
|
||||
INSERT INTO item (id, data)
|
||||
VALUES (
|
||||
replace(f, '.json','')::bigint,
|
||||
pg_read_file('/tmp/json/' || f)::jsonb
|
||||
)
|
||||
ON CONFLICT (id) DO UPDATE
|
||||
SET data = EXCLUDED.data;
|
||||
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
RAISE WARNING 'Erreur lors de l''import du fichier % : %', f, SQLERRM;
|
||||
END;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
Reference in New Issue
Block a user