Commit 09fb5e6e authored by Stephane Crozat's avatar Stephane Crozat

Refonte de la partie SQL

parent 8352dc98
......@@ -3,28 +3,41 @@
@startuml
hide circle
class Student {
class Api {
dbegin : date
code : int
name : text
description : text
duration : [1..5]
size : int
ects : [1..3]
dend() : date
week() : [1..53]
year() : int(4)
semester() : H|E|A|P
}
note left of Api : (dbeging,code) key\n(dbegin,name) key\nduration in days
class User {
utclogin : text {key}
mail : mail {key}
email : mail {key}
surname : text
firstname : text
speciality : text
level : text
}
class Api {
code : integer {key}
name : text
year : year
semester : H|E
dbegin : date
dend : date
}
note right of Api : (name,year,semester) key
User "1..1" -- "0..n" Api : Resp
Student "0..n" - "0..n" Api
(Student, Api) . Subscribe
User "0..n" -- "0..n" Api
(User, Api) . Subscribe
class Subscribe {
subdate : date
confirmed : boolean
}
note bottom of Subscribe : Only one sub confirmed by week
@enduml
BEGIN;
DROP TABLE IF EXISTS subscribe CASCADE;
DROP TABLE IF EXISTS api CASCADE;
DROP TABLE IF EXISTS localuser CASCADE;
DROP TABLE IF EXISTS utcstudent;
CREATE TABLE api (
code INTEGER PRIMARY KEY,
name TEXT NOT NULL,
description TEXT,
year INTEGER NOT NULL,
semester CHAR(1) NOT NULL,
dbegin DATE NOT NULL,
dend DATE NOT NULL,
size INTEGER,
ects INTEGER NOT NULL,
resplogin TEXT NOT NULL,
mail TEXT NOT NULL,
CHECK (code>0),
CHECK (year>2018 AND year<2100),
CHECK (semester IN ('H','E')),
CHECK (dbegin<=dend),
CHECK (size>0),
CHECK (ects>0),
UNIQUE (name,year,semester)
);
/* Table created to collect CAS user surname and firstname */
CREATE TABLE localuser (
utclogin TEXT PRIMARY KEY,
surname TEXT,
firstname TEXT,
email TEXT,
explanation TEXT
);
/* MAJ Apisub H19
ALTER TABLE localuser ADD explanation TEXT;
*/
CREATE TABLE subscribe (
utclogin TEXT NOT NULL REFERENCES localuser(utclogin),
api INTEGER REFERENCES api(code),
subdate DATE NOT NULL,
PRIMARY KEY (utclogin,api)
);
/* MAJ Apisub H19
ALTER TABLE subscribe ADD FOREIGN KEY (utclogin) REFERENCES localuser(utclogin);
*/
/* Table created to retrieve CSV info from DFP */
CREATE TABLE utcstudent (
surname TEXT NOT NULL,
firstname TEXT NOT NULL,
speciality TEXT NOT NULL,
level TEXT NOT NULL
);
/*
\COPY utcstudent (firstname,surname,speciality,level) FROM '/home/stc/inscriptions_A18.csv' WITH CSV HEADER DELIMITER ';' QUOTE '"'
*/
CREATE OR REPLACE FUNCTION unaccent_string(TEXT)
RETURNS TEXT
IMMUTABLE
STRICT
LANGUAGE SQL
AS $$
SELECT translate(
$1,
'âãäåÁÂÃÄÅèééêëÈÉÉÊËìíîïìÌÍÎÏÌóôõöÒÓÔÕÖùúûüÙÚÛÜ',
'aaaaAAAAAeeeeeEEEEEiiiiiIIIIIooooOOOOOuuuuUUUU'
);
$$;
CREATE OR REPLACE VIEW vlocaluser AS
SELECT l.utclogin, u.surname, u.firstname, l.email, MAX(u.speciality) AS speciality, MAX(u.level) AS level,
CASE WHEN COUNT(*)>1 THEN 'duplication' END AS warning,
l.explanation
FROM localuser l
LEFT JOIN utcstudent u ON l.surname=u.surname AND l.firstname=unaccent_string(u.firstname)
GROUP BY l.utclogin, u.surname, u.firstname;
CREATE OR REPLACE VIEW vapi AS
SELECT
ap.code,
CASE WHEN ap.code<10 THEN '000'||ap.code WHEN ap.code>=10 THEN '00'||ap.code END AS normcode,
ap.name, ap.year, ap.semester,
TO_CHAR(ap.dbegin,'TMday FMDD TMmonth') AS dbegin, TO_CHAR(ap.dend,'TMday FMDD TMmonth') AS dend,
ap.resplogin, ap.mail, ap.ects, ap.size,
COUNT(su.utclogin) AS nbsub
FROM api ap LEFT JOIN subscribe su ON ap.code=su.api
GROUP BY ap.code, normcode, ap.name, ap.year, ap.semester, dbegin, dend, ap.size, ap.ects, ap.mail
ORDER BY ap.year, ap.semester, ap.dbegin, ap.dend, ap.code;
CREATE OR REPLACE VIEW vsubscription AS
SELECT ap.*, TO_CHAR(su.subdate,'DD/MM/YYYY') AS subdate, su.utclogin AS sublogin, lo.*
FROM subscribe su
JOIN vapi ap ON ap.code=su.api
LEFT JOIN vlocaluser lo ON su.utclogin=lo.utclogin
ORDER BY ap.year, ap.semester, ap.dbegin, ap.dend, ap.code, lo.firstname, lo.surname, su.utclogin;
CREATE OR REPLACE VIEW vsubscription_anonymous AS
SELECT normcode, name, dbegin, dend, size, nbsub, speciality, level
FROM vsubscription;
/**
Tables liées à l'administration de la base
**/
CREATE TABLE admins (
utclogin TEXT PRIMARY KEY
);
INSERT INTO admins VALUES ('crozatst');
INSERT INTO admins VALUES ('dore');
CREATE TABLE config (
closed BOOLEAN NOT NULL,
openbegin DATE NOT NULL,
openend DATE NOT NULL
);
INSERT INTO config VALUES ('FALSE', TO_DATE('20180101','YYYYMMDD'), TO_DATE('20191231','YYYYMMDD'));
CREATE OR REPLACE VIEW vconfig AS
SELECT
TO_CHAR(openbegin,'TMday FMDD TMmonth FMYYYY') AS openbegin,
TO_CHAR(openend,'TMday FMDD TMmonth FMYYYY') AS openend,
NOT(closed) AND CURRENT_DATE >= openbegin AND CURRENT_DATE <= openend AS isactive
FROM config;
COMMIT;
BEGIN;
DROP TABLE IF EXISTS admins;
DROP TABLE IF EXISTS config CASCADE;
CREATE TABLE admins (
utclogin TEXT PRIMARY KEY
);
INSERT INTO admins VALUES ('crozatst');
INSERT INTO admins VALUES ('dore');
CREATE TABLE config (
closed BOOLEAN NOT NULL,
openbegin DATE NOT NULL,
openend DATE NOT NULL
);
INSERT INTO config VALUES ('FALSE', TO_DATE('20180101','YYYYMMDD'), TO_DATE('20191231','YYYYMMDD'));
CREATE OR REPLACE VIEW vconfig AS
SELECT
TO_CHAR(openbegin,'TMday FMDD TMmonth FMYYYY') AS openbegin,
TO_CHAR(openend,'TMday FMDD TMmonth FMYYYY') AS openend,
NOT(closed) AND CURRENT_DATE >= openbegin AND CURRENT_DATE <= openend AS isactive
FROM config;
COMMIT;
/** Test dataset **/
DELETE FROM api;
DELETE FROM localuser;
INSERT INTO localuser (utclogin) VALUES ('crozatst');
INSERT INTO api VALUES (
1,'Poésie et ingénierie','Lorem ipsum dolor sit amet',2019,'H',TO_DATE('20190121','yyyymmdd'),TO_DATE('20190125','yyyymmdd'),24,2,'stc@utc.fr'
TO_DATE('20190121','yyyymmdd'),1,'Poésie et ingénierie','Lorem ipsum dolor sit amet',5,24,2,'crozatst'
);
INSERT INTO api VALUES (
2,'Cloud big data blockchain IA','At vero eos et accusamus',2019,'H',TO_DATE('20190125','yyyymmdd'),TO_DATE('20190131','yyyymmdd'),12,3,'stc@utc.fr'
TO_DATE('20190125','yyyymmdd'),2,'Cloud big data blockchain IA','At vero eos et accusamus',3,12,1,'crozatst'
);
SELECT * FROM vapi;
SELECT * FROM vlocaluser;
SELECT * FROM vsubscription;
SELECT * FROM vsubscription_anonymous;
SELECT * FROM vapi_count;
CREATE OR REPLACE FUNCTION unaccent_string(TEXT)
RETURNS TEXT
AS $$
SELECT translate(
$1,
'âãäåÁÂÃÄÅèééêëÈÉÉÊËìíîïìÌÍÎÏÌóôõöÒÓÔÕÖùúûüÙÚÛÜ',
'aaaaAAAAAeeeeeEEEEEiiiiiIIIIIooooOOOOOuuuuUUUU'
);
$$ LANGUAGE SQL;
/** TODO **/
CREATE OR REPLACE FUNCTION
semester(DATE)
RETURNS CHAR(1)
AS $$
BEGIN
RETURN 'E';
END;
$$ LANGUAGE PLPGSQL;
BEGIN;
DROP TABLE IF EXISTS subscribe CASCADE;
DROP TABLE IF EXISTS api CASCADE;
DROP TABLE IF EXISTS localuser CASCADE;
DROP TABLE IF EXISTS utcstudent;
CREATE TABLE localuser (
utclogin TEXT PRIMARY KEY,
email TEXT,
surname TEXT,
firstname TEXT,
speciality TEXT,
level TEXT
);
CREATE TABLE api (
dbegin DATE NOT NULL,
code INTEGER NOT NULL,
name TEXT NOT NULL,
description TEXT,
duration INTEGER,
size INTEGER,
ects INTEGER NOT NULL,
resplogin TEXT NOT NULL,
CHECK (code>0),
CHECK (duration BETWEEN 1 AND 5),
CHECK (size>0),
CHECK (ects BETWEEN 1 AND 3),
FOREIGN KEY (resplogin) REFERENCES localuser (utclogin),
PRIMARY KEY (dbegin, code),
UNIQUE (dbegin, name),
UNIQUE (dbegin, description)
);
CREATE TABLE subscribe (
utclogin TEXT NOT NULL,
dbegin DATE NOT NULL,
code INTEGER NOT NULL,
subdate DATE NOT NULL,
confirmed BOOLEAN NOT NULL DEFAULT FALSE,
FOREIGN KEY (utclogin) REFERENCES localuser(utclogin),
FOREIGN KEY (dbegin,code) REFERENCES api(dbegin,code),
PRIMARY KEY (utclogin,dbegin,code)
);
/* Table created to retrieve CSV info from DFP (À supprimer) */
CREATE TABLE utcstudent (
surname TEXT NOT NULL,
firstname TEXT NOT NULL,
speciality TEXT NOT NULL,
level TEXT NOT NULL
);
COMMIT;
BEGIN;
CREATE OR REPLACE VIEW vapi AS
SELECT
*,
TO_CHAR(dbegin,'TMday FMDD TMmonth') AS normdbegin,
CASE WHEN code<10 THEN '000'||code WHEN code>=10 THEN '00'||code END AS normcode,
TO_CHAR(dbegin + duration-1,'TMday FMDD TMmonth') AS normdend,
TO_CHAR(dbegin, 'ww') AS week,
TO_CHAR(dbegin, 'yyyy') AS year,
semester(dbegin) AS semester
FROM api
ORDER BY dbegin, code;
CREATE OR REPLACE VIEW vlocaluser AS
SELECT l.utclogin, u.surname, u.firstname, l.email, MAX(u.speciality) AS speciality, MAX(u.level) AS level,
CASE WHEN COUNT(*)>1 THEN 'duplication' END AS warning
FROM localuser l
LEFT JOIN utcstudent u ON l.surname=u.surname AND l.firstname=unaccent_string(u.firstname)
GROUP BY l.utclogin, u.surname, u.firstname;
CREATE OR REPLACE VIEW vsubscription AS
SELECT
ap.*,
TO_CHAR(su.subdate,'DD/MM/YYYY') AS subdate,
su.utclogin AS sublogin,
lo.*
FROM subscribe su
JOIN vapi ap ON ap.dbegin=su.dbegin AND ap.code=su.code
LEFT JOIN vlocaluser lo ON su.utclogin=lo.utclogin
ORDER BY ap.dbegin, ap.code, lo.firstname, lo.surname, lo.utclogin;
CREATE OR REPLACE VIEW vsubscription_anonymous AS
SELECT normcode, name, normdbegin, normdend, size, speciality, level
FROM vsubscription;
CREATE OR REPLACE VIEW vapi_count AS
SELECT
dbegin,
code,
COUNT(utclogin) AS nbsub
FROM vsubscription
GROUP BY dbegin, code;
COMMIT;
#!/bin/bash
sqlfiles='/media/stc/data/git/apisub/sql'
psql -f "$sqlfiles/apisub_functions.sql"
psql -f "$sqlfiles/apisub_admin.sql"
psql -f "$sqlfiles/apisub_tables.sql"
psql -f "$sqlfiles/apisub_views.sql"
psql -f "$sqlfiles/apisub_dataset.sql"
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment