apisub.sql 1.61 KB
Newer Older
Stephane Crozat's avatar
Stephane Crozat committed
1
DROP TABLE IF EXISTS subscribe CASCADE;
2
DROP TABLE IF EXISTS api CASCADE;
Stephane Crozat's avatar
Stephane Crozat committed
3
4
5
6

CREATE TABLE api (
  code INTEGER PRIMARY KEY,
  name TEXT NOT NULL,
Stephane Crozat's avatar
Fix #2  
Stephane Crozat committed
7
  description TEXT,
Stephane Crozat's avatar
Stephane Crozat committed
8
9
  year INTEGER NOT NULL,
  semester CHAR(1) NOT NULL,
10
11
  dbegin DATE NOT NULL,
  dend DATE NOT NULL,
12
13
  size INTEGER,
  ects INTEGER NOT NULL,
14
  mail TEXT NOT NULL,
Stephane Crozat's avatar
Stephane Crozat committed
15
16
17
  CHECK (code>0),
  CHECK (year>2018 AND year<2100),
  CHECK (semester IN ('H','E')),
18
  CHECK (dbegin<=dend),
19
20
  CHECK (size>0),
  CHECK (ects>0),
Stephane Crozat's avatar
Stephane Crozat committed
21
22
23
24
25
26
27
28
29
30
  UNIQUE (name,year,semester)
);

CREATE TABLE subscribe (
  utclogin TEXT NOT NULL,
  api INTEGER REFERENCES api(code),
  subdate DATE NOT NULL,
  PRIMARY KEY (utclogin,api)
);

31
/** Test dataset
Stephane Crozat's avatar
Stephane Crozat committed
32
INSERT INTO api VALUES (
33
  1,'Poésie et ingénierie',2019,'H',TO_DATE('20190121','yyyymmdd'),TO_DATE('20190125','yyyymmdd'),24,2,'stc@utc.fr'
Stephane Crozat's avatar
Stephane Crozat committed
34
35
);
INSERT INTO api VALUES (
36
  2,'Cloud big data blockchain IA',2019,'H',TO_DATE('20190125','yyyymmdd'),TO_DATE('20190131','yyyymmdd'),12,3,'stc@utc.fr'
Stephane Crozat's avatar
Stephane Crozat committed
37
38
39
40
);
INSERT INTO subscribe VALUES (
  'crozatst',1,TO_DATE('20181018','YYYYMMDD')
);
41
**/
Stephane Crozat's avatar
Stephane Crozat committed
42

43
CREATE OR REPLACE VIEW vApi AS
44
45
SELECT
ap.code,
46
CASE WHEN ap.code<10 THEN '000'||ap.code WHEN ap.code>=10 THEN '00'||ap.code END AS normcode,
47
48
ap.name, ap.year, ap.semester,
TO_CHAR(ap.dbegin,'TMday FMDD TMmonth') AS dbegin, TO_CHAR(ap.dend,'TMday FMDD TMmonth') AS dend,
49
ap.size, ap.ects, ap.mail
50
51
52
FROM api ap
ORDER BY ap.year, ap.semester, ap.dbegin, ap.dend, ap.code;

Stephane Crozat's avatar
Stephane Crozat committed
53
CREATE OR REPLACE VIEW vSubscription AS
54
55
56
SELECT ap.*, TO_CHAR(su.subdate,'DD/MM/YYYY') AS subdate, su.utclogin
FROM subscribe su JOIN vApi ap ON ap.code=su.api
ORDER BY ap.year, ap.semester, ap.dbegin, ap.dend, ap.code, su.utclogin;