Commit 4f53c2b8 authored by Romain Loth's avatar Romain Loth

DB planned changes for new labs/institutions structure

parent 996180dc
...@@ -102,8 +102,8 @@ Uploaded images are in `data/shared_user_img`. ...@@ -102,8 +102,8 @@ Uploaded images are in `data/shared_user_img`.
- a unique external doors_uid (the user id for the entire lab) - a unique external doors_uid (the user id for the entire lab)
- a unique email - a unique email
- we have four related tables - we have four related tables
- `affiliations` for labs and institutions - `orgs` for labs and institutions
- (directly pointed by an **affiliation_id** in scholars table) - and sch_org for scholars <=> organisms mapping
- `keywords` - `keywords`
- and `sch_kw` for scholars <=> keywords mapping - and `sch_kw` for scholars <=> keywords mapping
- `hashtags` - `hashtags`
...@@ -123,8 +123,10 @@ SELECT ...@@ -123,8 +123,10 @@ SELECT
scholars.*, scholars.*,
affiliations.*, affiliations.*,
FROM scholars FROM scholars
LEFT JOIN affiliations LEFT JOIN sch_org
ON affiliation_id = affid ON luid = sch_org.uid
JOIN orgs
ON orgs.orgid = sch_org.orgid
-- ================================== -- ==================================
...@@ -136,7 +138,7 @@ SELECT ...@@ -136,7 +138,7 @@ SELECT
GROUP_CONCAT(kwstr) AS keywords_list GROUP_CONCAT(kwstr) AS keywords_list
FROM scholars FROM scholars
JOIN sch_kw JOIN sch_kw
ON doors_uid = uid ON luid = uid
JOIN keywords JOIN keywords
ON sch_kw.kwid = keywords.kwid ON sch_kw.kwid = keywords.kwid
GROUP BY uid ; GROUP BY uid ;
......
...@@ -26,7 +26,6 @@ CREATE TABLE scholars ( ...@@ -26,7 +26,6 @@ CREATE TABLE scholars (
middle_name varchar(30), middle_name varchar(30),
last_name varchar(50) not null, last_name varchar(50) not null,
initials varchar(7) not null, initials varchar(7) not null,
affiliation_id int(15) not null,
position varchar(120), -- eg Director position varchar(120), -- eg Director
hon_title varchar(30), -- eg Doctor hon_title varchar(30), -- eg Doctor
interests_text varchar(3500), interests_text varchar(3500),
...@@ -42,25 +41,72 @@ CREATE TABLE scholars ( ...@@ -42,25 +41,72 @@ CREATE TABLE scholars (
future_reserved varchar(30), -- eg for an imported id or temp status future_reserved varchar(30), -- eg for an imported id or temp status
INDEX duid_index_sch (doors_uid), INDEX duid_index_sch (doors_uid),
INDEX affs_index_sch (affiliation_id),
INDEX country_index_sch (country), INDEX country_index_sch (country),
INDEX rstatus_index_sch (record_status) INDEX rstatus_index_sch (record_status)
) ; ) ;
-- affiliations: institutions and labs
CREATE TABLE affiliations(
affid int(15) not null auto_increment, CREATE TABLE locs(
org varchar(120), locname varchar(120),
org_type varchar(50), lat float(6,4),
team_lab varchar(120) not null, lng float(7,4), -- 4 decimals for lat & lng <=> 100m resol
PRIMARY KEY (locname)
) ;
-- table for all organization classes (team, lab, large institution)
CREATE TABLE orgs(
orgid int(15) not null auto_increment,
name varchar(120), -- full name
acro varchar(20), -- acronym or short name
class varchar(25), -- "team|lab|inst"
-- like the calibre of the organization
lab_code varchar(25), -- ex "UPS 3611" or "UMR 9221" (iff lab)
inst_type varchar(50), -- ex "public org|private org" (iff inst)
locname varchar(120) null, -- ex "Paris, France" or "France"
-- (key to more info in table locs)
url varchar(180), -- the organisation's homepage
contact_email varchar(255), -- if some email
contact_name varchar(80), -- if some administrative contact person
timestamp timestamp,
-- address... (...) -- address elements POSS NOT IMPLEMENTED
reserved varchar(30), reserved varchar(30),
reserved varchar(30),
PRIMARY KEY (affid), -- generated column, often useful for autocompletes etc
UNIQUE KEY full_affiliation (org, team_lab, org_city, org_type) -- ex "Instituto de Fisica de Cantabria (IFCA), Santander, Spain"
tostring varchar(800) AS (CONCAT(
name, ' (', acro, ')',
IF(locname IS NOT NULL ,
CONCAT(', ', locname),
'')
)),
PRIMARY KEY (orgid),
UNIQUE KEY full_org (name, acro, locname)
-- POSS FOREIGN KEY locname REFERENCES locs(locname)
-- (useful when we use the locs more in the app)
) ;
-- relationship scholars <n=n> organizations
CREATE TABLE sch_org(
uid int(15) not null,
orgid int(15) not null,
PRIMARY KEY (uid, orgid),
FOREIGN KEY (uid) REFERENCES scholars(luid) ON DELETE CASCADE,
FOREIGN KEY (orgid) REFERENCES orgs(orgid)
); );
-- POSS: relationship organizations <=> keywords
-- POSS: relationship organizations <=> organizations
-- keyword/subject terms -- keyword/subject terms
CREATE TABLE keywords( CREATE TABLE keywords(
......
...@@ -19,7 +19,6 @@ CREATE TABLE scholars ( ...@@ -19,7 +19,6 @@ CREATE TABLE scholars (
middle_name varchar(30), middle_name varchar(30),
last_name varchar(50) not null, last_name varchar(50) not null,
initials varchar(7) not null, initials varchar(7) not null,
affiliation_id int(15) not null,
position varchar(120), -- eg Director position varchar(120), -- eg Director
hon_title varchar(30), -- eg Doctor hon_title varchar(30), -- eg Doctor
interests_text varchar(3500), interests_text varchar(3500),
...@@ -35,25 +34,70 @@ CREATE TABLE scholars ( ...@@ -35,25 +34,70 @@ CREATE TABLE scholars (
future_reserved varchar(30), -- eg for an imported id or temp status future_reserved varchar(30), -- eg for an imported id or temp status
INDEX duid_index_sch (doors_uid), INDEX duid_index_sch (doors_uid),
INDEX affs_index_sch (affiliation_id),
INDEX country_index_sch (country), INDEX country_index_sch (country),
INDEX rstatus_index_sch (record_status) INDEX rstatus_index_sch (record_status)
) ; ) ;
-- affiliations: institutions and labs
CREATE TABLE affiliations( CREATE TABLE locs(
affid int(15) not null auto_increment, locname varchar(120),
org varchar(120), lat float(6,4),
org_type varchar(50), lng float(7,4), -- 4 decimals for lat & lng <=> 100m resol
team_lab varchar(120) not null, PRIMARY KEY (locname)
) ;
-- table for all organization classes (team, lab, large institution)
CREATE TABLE orgs(
orgid int(15) not null auto_increment,
name varchar(120), -- full name
acro varchar(20), -- acronym or short name
class varchar(25), -- "team|lab|inst"
-- like the calibre of the organization
lab_code varchar(25), -- ex "UPS 3611" or "UMR 9221" (iff lab)
inst_type varchar(50), -- ex "public org|private org" (iff inst)
locname varchar(120) null, -- ex "Paris, France" or "France"
-- (key to more info in table locs)
url varchar(180), -- the organisation's homepage
contact_email varchar(255), -- if some email
contact_name varchar(80), -- if some administrative contact person
timestamp timestamp,
-- address... (...) -- address elements POSS NOT IMPLEMENTED
reserved varchar(30), reserved varchar(30),
reserved varchar(30),
PRIMARY KEY (affid), -- generated column, often useful for autocompletes etc
UNIQUE KEY full_affiliation (org, team_lab, org_city, org_type) -- ex "Instituto de Fisica de Cantabria (IFCA), Santander, Spain"
tostring varchar(800) AS (CONCAT(
name, ' (', acro, ')',
IF(locname IS NOT NULL ,
CONCAT(', ', locname),
'')
)),
PRIMARY KEY (orgid),
UNIQUE KEY full_org (name, acro, locname)
-- POSS FOREIGN KEY locname REFERENCES locs(locname)
-- (useful when we use the locs more in the app)
) ;
-- relationship scholars <n=n> organizations
CREATE TABLE sch_org(
uid int(15) not null,
orgid int(15) not null,
PRIMARY KEY (uid, orgid),
FOREIGN KEY (uid) REFERENCES scholars(luid) ON DELETE CASCADE,
FOREIGN KEY (orgid) REFERENCES orgs(orgid)
); );
-- POSS: relationship organizations <=> keywords
-- POSS: relationship organizations <=> organizations
-- keyword/subject terms -- keyword/subject terms
CREATE TABLE keywords( CREATE TABLE keywords(
......
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