622 lines
20 KiB
PL/PgSQL
622 lines
20 KiB
PL/PgSQL
DROP VIEW IF EXISTS organizations_view;
|
|
DROP VIEW IF EXISTS organizations_info_view;
|
|
DROP VIEW IF EXISTS organizations_simple_view;
|
|
DROP VIEW IF EXISTS users_view;
|
|
DROP VIEW IF EXISTS conflict_groups_view;
|
|
DROP VIEW IF EXISTS suggestions_info_by_country_view;
|
|
DROP VIEW IF EXISTS duplicate_groups_view;
|
|
|
|
DROP TABLE IF EXISTS other_ids;
|
|
DROP TABLE IF EXISTS other_names;
|
|
DROP TABLE IF EXISTS acronyms;
|
|
DROP TABLE IF EXISTS relationships;
|
|
DROP TABLE IF EXISTS urls;
|
|
DROP TABLE IF EXISTS oa_duplicates;
|
|
DROP TABLE IF EXISTS oa_conflicts;
|
|
DROP TABLE IF EXISTS organizations;
|
|
DROP TABLE IF EXISTS org_types;
|
|
|
|
DROP TABLE IF EXISTS user_countries;
|
|
DROP TABLE IF EXISTS users;
|
|
|
|
DROP TABLE IF EXISTS user_roles;
|
|
DROP TABLE IF EXISTS countries;
|
|
DROP TABLE IF EXISTS id_types;
|
|
DROP TABLE IF EXISTS languages;
|
|
|
|
DROP SEQUENCE IF EXISTS organizations_id_seq;
|
|
|
|
CREATE TABLE org_types (val text PRIMARY KEY, name text);
|
|
INSERT INTO org_types(val) VALUES ('Archive'), ('Company'), ('Education'), ('Facility'), ('Government'), ('Healthcare'), ('Nonprofit'), ('Other'), ('UNKNOWN');
|
|
UPDATE org_types SET name = val;
|
|
|
|
CREATE TABLE id_types (val text PRIMARY KEY, name text);
|
|
INSERT INTO id_types(val) VALUES ('CNRS'), ('FundRef'), ('HESA'), ('ISNI'), ('LinkedIn'), ('OrgRef'), ('UCAS'), ('UKPRN'), ('Wikidata'), ('GRID'), ('ROR');
|
|
UPDATE id_types SET name = val;
|
|
|
|
CREATE TABLE languages (val text PRIMARY KEY, name text);
|
|
INSERT INTO languages(val) VALUES ('UNKNOWN'),
|
|
('aa'),('af'),('am'),('ar'),('as'),('az'),('ba'),('be'),('bg'),('bn'),('br'),('bs'),('ca'),('ch'),('co'),('cs'),('cy'),('da'),('de'),('dv'),
|
|
('dz'),('el'),('en'),('eo'),('es'),('et'),('eu'),('fa'),('fi'),('fo'),('fr'),('fy'),('ga'),('gd'),('gl'),('gu'),('he'),('hi'),('hr'),('ht'),
|
|
('hu'),('hy'),('id'),('is'),('it'),('iu'),('ja'),('jv'),('ka'),('kk'),('kl'),('km'),('kn'),('ko'),('ku'),('ky'),('la'),('lb'),('lo'),('lt'),
|
|
('lv'),('mg'),('mi'),('mk'),('ml'),('mn'),('mr'),('ms'),('mt'),('my'),('nb'),('ne'),('nl'),('no'),('oc'),('om'),('or'),('pa'),('pl'),('ps'),
|
|
('pt'),('rm'),('ro'),('ru'),('rw'),('sa'),('sd'),('si'),('sk'),('sl'),('sm'),('so'),('sq'),('sr'),('sv'),('sw'),('ta'),('te'),('tg'),('th'),
|
|
('tk'),('tl'),('tr'),('tt'),('ug'),('uk'),('ur'),('uz'),('vi'),('xh'),('yo'),('zh'),('zu');
|
|
UPDATE languages SET name = val;
|
|
|
|
CREATE TABLE countries (val text PRIMARY KEY, name text);
|
|
INSERT INTO countries(val, name) VALUES
|
|
('AD', 'Andorra'),
|
|
('AE', 'United Arab Emirates'),
|
|
('AF', 'Afghanistan'),
|
|
('AG', 'Antigua and Barbuda'),
|
|
('AI', 'Anguilla'),
|
|
('AL', 'Albania'),
|
|
('AM', 'Armenia'),
|
|
('AN', 'Netherlands Antilles'),
|
|
('AO', 'Angola'),
|
|
('AQ', 'Antarctica'),
|
|
('AR', 'Argentina'),
|
|
('AS', 'American Samoa'),
|
|
('AT', 'Austria'),
|
|
('AU', 'Australia'),
|
|
('AW', 'Aruba'),
|
|
('AX', 'Åland Islands'),
|
|
('AZ', 'Azerbaijan'),
|
|
('BA', 'Bosnia and Herzegovina'),
|
|
('BB', 'Barbados'),
|
|
('BD', 'Bangladesh'),
|
|
('BE', 'Belgium'),
|
|
('BF', 'Burkina Faso'),
|
|
('BG', 'Bulgaria'),
|
|
('BH', 'Bahrain'),
|
|
('BI', 'Burundi'),
|
|
('BJ', 'Benin'),
|
|
('BL', 'Saint-Barthélemy'),
|
|
('BM', 'Bermuda'),
|
|
('BN', 'Brunei Darussalam'),
|
|
('BO', 'Bolivia'),
|
|
('BQ', 'Bonaire, Sint Eustatius and Saba'),
|
|
('BR', 'Brazil'),
|
|
('BS', 'Bahamas'),
|
|
('BT', 'Bhutan'),
|
|
('BV', 'Bouvet Island'),
|
|
('BW', 'Botswana'),
|
|
('BY', 'Belarus'),
|
|
('BZ', 'Belize'),
|
|
('CA', 'Canada'),
|
|
('CC', 'Cocos (Keeling) Islands'),
|
|
('CD', 'Congo (Democratic Republic of)'),
|
|
('CF', 'Central African Republic'),
|
|
('CG', 'Congo'),
|
|
('CH', 'Switzerland'),
|
|
('CI', 'Cote d''Ivoire'),
|
|
('CK', 'Cook Islands'),
|
|
('CL', 'Chile'),
|
|
('CM', 'Cameroon'),
|
|
('CN', 'China (People''s Republic of)'),
|
|
('CO', 'Colombia'),
|
|
('CR', 'Costa Rica'),
|
|
('CS', 'Serbia and Montenegro'),
|
|
('CU', 'Cuba'),
|
|
('CV', 'Cape Verde'),
|
|
('CW', 'Curaçao'),
|
|
('CX', 'Christmas Island'),
|
|
('CY', 'Cyprus'),
|
|
('CZ', 'Czech Republic'),
|
|
('DE', 'Germany'),
|
|
('DJ', 'Djibouti'),
|
|
('DK', 'Denmark'),
|
|
('DM', 'Dominica'),
|
|
('DO', 'Dominican Republic'),
|
|
('DZ', 'Algeria'),
|
|
('EC', 'Ecuador'),
|
|
('EE', 'Estonia'),
|
|
('EG', 'Egypt'),
|
|
('EH', 'Western Sahara'),
|
|
('ER', 'Eritrea'),
|
|
('ES', 'Spain'),
|
|
('ET', 'Ethiopia'),
|
|
('EU', 'European Union'),
|
|
('FI', 'Finland'),
|
|
('FJ', 'Fiji'),
|
|
('FK', 'Falkland Islands (Malvinas)'),
|
|
('FM', 'Micronesia, Federated States of'),
|
|
('FO', 'Faroe Islands'),
|
|
('FR', 'France'),
|
|
('GA', 'Gabon'),
|
|
('GB', 'United Kingdom'),
|
|
('GD', 'Grenada'),
|
|
('GE', 'Georgia'),
|
|
('GF', 'French Guiana'),
|
|
('GG', 'Guernsey'),
|
|
('GH', 'Ghana'),
|
|
('GI', 'Gibraltar'),
|
|
('GL', 'Greenland'),
|
|
('GM', 'Gambia'),
|
|
('GN', 'Guinea'),
|
|
('GP', 'Guadeloupe'),
|
|
('GQ', 'Equatorial Guinea'),
|
|
('GR', 'Greece'),
|
|
('GS', 'South Georgia and the South Sandwich Islands'),
|
|
('GT', 'Guatemala'),
|
|
('GU', 'Guam'),
|
|
('GW', 'Guinea-Bissau'),
|
|
('GY', 'Guyana'),
|
|
('HK', 'Hong Kong'),
|
|
('HM', 'Heard Island and McDonald Islands'),
|
|
('HN', 'Honduras'),
|
|
('HR', 'Croatia'),
|
|
('HT', 'Haiti'),
|
|
('HU', 'Hungary'),
|
|
('ID', 'Indonesia'),
|
|
('IE', 'Ireland'),
|
|
('IL', 'Israel'),
|
|
('IM', 'Isle of Man'),
|
|
('IN', 'India'),
|
|
('IO', 'British Indian Ocean Territory'),
|
|
('IQ', 'Iraq'),
|
|
('IR', 'Iran (Islamic Republic of)'),
|
|
('IS', 'Iceland'),
|
|
('IT', 'Italy'),
|
|
('JE', 'Jersey'),
|
|
('JM', 'Jamaica'),
|
|
('JO', 'Jordan'),
|
|
('JP', 'Japan'),
|
|
('KE', 'Kenya'),
|
|
('KG', 'Kyrgyzstan'),
|
|
('KH', 'Cambodia'),
|
|
('KI', 'Kiribati'),
|
|
('KM', 'Comoros'),
|
|
('KN', 'Saint Kitts and Nevis'),
|
|
('KO', 'Kosovo * UN resolution'),
|
|
('KP', 'Korea, Democatric People''s Republic of'),
|
|
('KR', 'Korea (Republic of)'),
|
|
('KW', 'Kuwait'),
|
|
('KY', 'Cayman Islands'),
|
|
('KZ', 'Kazakhstan'),
|
|
('LA', 'Lao (People''s Democratic Republic)'),
|
|
('LB', 'Lebanon'),
|
|
('LC', 'Saint Lucia'),
|
|
('LI', 'Liechtenstein'),
|
|
('LK', 'Sri Lanka'),
|
|
('LR', 'Liberia'),
|
|
('LS', 'Lesotho'),
|
|
('LT', 'Lithuania'),
|
|
('LU', 'Luxembourg'),
|
|
('LV', 'Latvia'),
|
|
('LY', 'Libyan Arab Jamahiriya'),
|
|
('MA', 'Morocco'),
|
|
('MC', 'Monaco'),
|
|
('MD', 'Moldova (Republic of)'),
|
|
('ME', 'Montenegro'),
|
|
('MF', 'Saint Martin (French Part)'),
|
|
('MG', 'Madagascar'),
|
|
('MH', 'Marshall Islands'),
|
|
('MK', 'Former Yugoslav Republic of Macedonia'),
|
|
('ML', 'Mali'),
|
|
('MM', 'Myanmar'),
|
|
('MN', 'Mongolia'),
|
|
('MO', 'Macao'),
|
|
('MP', 'Northern Mariana Islands'),
|
|
('MQ', 'Martinique'),
|
|
('MR', 'Mauritania'),
|
|
('MS', 'Montserrat'),
|
|
('MT', 'Malta'),
|
|
('MU', 'Mauritius'),
|
|
('MV', 'Maldives'),
|
|
('MW', 'Malawi'),
|
|
('MX', 'Mexico'),
|
|
('MY', 'Malaysia'),
|
|
('MZ', 'Mozambique'),
|
|
('NA', 'Namibia'),
|
|
('NC', 'New Caledonia'),
|
|
('NE', 'Niger'),
|
|
('NF', 'Norfolk Island'),
|
|
('NG', 'Nigeria'),
|
|
('NI', 'Nicaragua'),
|
|
('NL', 'Netherlands'),
|
|
('NO', 'Norway'),
|
|
('NP', 'Nepal'),
|
|
('NR', 'Nauru'),
|
|
('NU', 'Niue'),
|
|
('NZ', 'New Zealand'),
|
|
('OC', 'Oceania'),
|
|
('OM', 'Oman'),
|
|
('PA', 'Panama'),
|
|
('PE', 'Peru'),
|
|
('PF', 'French Polynesia'),
|
|
('PG', 'Papua New Guinea'),
|
|
('PH', 'Philippines'),
|
|
('PK', 'Pakistan'),
|
|
('PL', 'Poland'),
|
|
('PM', 'Saint Pierre and Miquelon'),
|
|
('PN', 'Pitcairn'),
|
|
('PR', 'Puerto Rico'),
|
|
('PS', 'Palestinian-administered areas'),
|
|
('PT', 'Portugal'),
|
|
('PW', 'Palau'),
|
|
('PY', 'Paraguay'),
|
|
('QA', 'Qatar'),
|
|
('RE', 'Réunion'),
|
|
('RO', 'Romania'),
|
|
('RS', 'Serbia'),
|
|
('RU', 'Russian Federation'),
|
|
('RW', 'Rwanda'),
|
|
('SA', 'Saudi Arabia'),
|
|
('SB', 'Solomon Islands'),
|
|
('SC', 'Seychelles'),
|
|
('SD', 'Sudan'),
|
|
('SE', 'Sweden'),
|
|
('SG', 'Singapore'),
|
|
('SH', 'Saint Helena, Ascension and Tristan da Cunha'),
|
|
('SI', 'Slovenia'),
|
|
('SJ', 'Svalbard and Jan Mayen'),
|
|
('SK', 'Slovakia'),
|
|
('SL', 'Sierra Leone'),
|
|
('SM', 'San Marino'),
|
|
('SN', 'Senegal'),
|
|
('SO', 'Somalia'),
|
|
('SR', 'Suriname'),
|
|
('SS', 'South Sudan'),
|
|
('ST', 'São Tomé and Príncipe'),
|
|
('SV', 'El Salvador'),
|
|
('SX', 'Sint Maarten (Dutch Part)'),
|
|
('SY', 'Syrian Arab Republic'),
|
|
('SZ', 'Swaziland'),
|
|
('TC', 'Turks and Caicos Islands'),
|
|
('TD', 'Chad'),
|
|
('TF', 'French Southern Territories'),
|
|
('TG', 'Togo'),
|
|
('TH', 'Thailand'),
|
|
('TJ', 'Tajikistan'),
|
|
('TK', 'Tokelau'),
|
|
('TL', 'Timor-Leste'),
|
|
('TM', 'Turkmenistan'),
|
|
('TN', 'Tunisia'),
|
|
('TO', 'Tonga'),
|
|
('TR', 'Turkey'),
|
|
('TT', 'Trinidad and Tobago'),
|
|
('TV', 'Tuvalu'),
|
|
('TW', 'Taiwan'),
|
|
('TZ', 'Tanzania (United Republic of)'),
|
|
('UA', 'Ukraine'),
|
|
('UG', 'Uganda'),
|
|
('UK', 'United Kingdom'),
|
|
('UM', 'United States Minor Outlying Islands'),
|
|
('UNKNOWN', 'UNKNOWN'),
|
|
('US', 'United States'),
|
|
('UY', 'Uruguay'),
|
|
('UZ', 'Uzbekistan'),
|
|
('VA', 'Holy See (Vatican City State)'),
|
|
('VC', 'Saint Vincent and the Grenadines'),
|
|
('VE', 'Venezuela'),
|
|
('VG', 'Virgin Islands (British)'),
|
|
('VI', 'Virgin Islands, U.S.'),
|
|
('VN', 'Viet Nam'),
|
|
('VU', 'Vanuatu'),
|
|
('WF', 'Wallis and Futuna'),
|
|
('WS', 'Samoa'),
|
|
('XK', 'Kosovo * UN resolution'),
|
|
('YE', 'Yemen'),
|
|
('YT', 'Mayotte'),
|
|
('YU', 'Yugoslavia'),
|
|
('ZA', 'South Africa'),
|
|
('ZM', 'Zambia'),
|
|
('ZW', 'Zimbabwe');
|
|
|
|
|
|
CREATE TABLE user_roles(role text PRIMARY KEY);
|
|
INSERT INTO user_roles VALUES ('ADMIN'), ('NATIONAL_ADMIN'), ('USER'), ('PENDING'), ('NOT_AUTHORIZED');
|
|
|
|
CREATE TABLE users (
|
|
email text PRIMARY KEY,
|
|
valid boolean DEFAULT true,
|
|
role text NOT NULL default 'USER' REFERENCES user_roles(role),
|
|
first_access timestamp with time zone DEFAULT now(),
|
|
last_access timestamp with time zone DEFAULT now()
|
|
);
|
|
|
|
CREATE TABLE user_countries (
|
|
email text REFERENCES users(email) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
country text REFERENCES countries(val),
|
|
PRIMARY KEY(email, country)
|
|
);
|
|
|
|
CREATE SEQUENCE organizations_id_seq;
|
|
|
|
CREATE TABLE organizations (
|
|
id text PRIMARY KEY DEFAULT 'openorgs____::'||lpad(nextval('organizations_id_seq')::text,10,'0'),
|
|
name text,
|
|
type text NOT NULL DEFAULT 'UNKNOWN' REFERENCES org_types(val),
|
|
lat double precision,
|
|
lng double precision,
|
|
city text,
|
|
country text REFERENCES countries(val),
|
|
created_by text,
|
|
creation_date timestamp with time zone DEFAULT now(),
|
|
modified_by text,
|
|
modification_date timestamp with time zone DEFAULT now(),
|
|
status text NOT NULL DEFAULT 'suggested'
|
|
);
|
|
CREATE INDEX organizations_type_idx ON organizations(type);
|
|
CREATE INDEX organizations_country_idx ON organizations(country);
|
|
|
|
CREATE TABLE other_ids (
|
|
id text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
otherid text,
|
|
type text REFERENCES id_types(val),
|
|
PRIMARY KEY (id, otherid, type)
|
|
);
|
|
CREATE INDEX other_ids_id_idx ON other_ids(id);
|
|
|
|
CREATE TABLE other_names (
|
|
id text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
name text,
|
|
lang text REFERENCES languages(val),
|
|
PRIMARY KEY (id, name, lang)
|
|
);
|
|
CREATE INDEX other_names_id_idx ON other_names(id);
|
|
|
|
CREATE TABLE acronyms (
|
|
id text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
acronym text,
|
|
PRIMARY KEY (id, acronym)
|
|
);
|
|
CREATE INDEX acronyms_id_idx ON acronyms(id);
|
|
|
|
CREATE TABLE relationships (
|
|
id1 text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
reltype text,
|
|
id2 text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
PRIMARY KEY (id1, reltype, id2)
|
|
);
|
|
CREATE INDEX relationships_id1_idx ON relationships(id1);
|
|
CREATE INDEX relationships_id2_idx ON relationships(id2);
|
|
|
|
CREATE TABLE urls (
|
|
id text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
url text,
|
|
PRIMARY KEY (id, url)
|
|
);
|
|
CREATE INDEX urls_id_idx ON urls(id);
|
|
|
|
CREATE TABLE oa_duplicates (
|
|
local_id text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
oa_original_id text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
oa_name text NOT NULL,
|
|
oa_acronym text,
|
|
oa_country text,
|
|
oa_url text,
|
|
oa_collectedfrom text,
|
|
reltype text NOT NULL DEFAULT 'suggested',
|
|
creation_date timestamp DEFAULT NOW(),
|
|
created_by text,
|
|
modification_date timestamp,
|
|
modified_by text,
|
|
PRIMARY KEY (local_id, oa_original_id)
|
|
);
|
|
CREATE INDEX oa_duplicates_local_id_idx ON oa_duplicates(local_id);
|
|
|
|
|
|
CREATE VIEW oa_duplicates_view AS
|
|
d.local_id as local_id,
|
|
d.oa_original_id as oa_original_id,
|
|
o.name as oa_name,
|
|
array_to_string(array_agg(a.acronym), ', ') as oa_acronym,
|
|
o.country as oa_country,
|
|
array_to_string(array_agg(u.url), ', ') as oa_url,
|
|
d.oa_collectedfrom as oa_collectedfrom,
|
|
d.reltype as reltype,
|
|
d.created_by as created_by
|
|
FROM
|
|
oa_duplicates d
|
|
LEFT OUTER JOIN organizations o ON (o.id = d.oa_original_id)
|
|
LEFT OUTER JOIN acronyms a ON (o.id = a.id)
|
|
LEFT OUTER JOIN urls u ON (o.id = u.id)
|
|
GROUP BY
|
|
d.local_id,
|
|
d.oa_original_id,
|
|
d.created_by,
|
|
o.name,
|
|
o.country,
|
|
d.oa_collectedfrom,
|
|
d.reltype;
|
|
|
|
CREATE TABLE oa_conflicts (
|
|
id1 text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
id2 text REFERENCES organizations(id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
reltype text NOT NULL DEFAULT 'suggested',
|
|
idgroup text,
|
|
creation_date timestamp DEFAULT NOW(),
|
|
created_by text,
|
|
modification_date timestamp,
|
|
modified_by text,
|
|
PRIMARY KEY (id1, id2)
|
|
);
|
|
CREATE INDEX oa_conflicts_id1_idx ON oa_conflicts(id1);
|
|
CREATE INDEX oa_conflicts_id2_idx ON oa_conflicts(id2);
|
|
CREATE INDEX oa_conflicts_idgroup_idx ON oa_conflicts(idgroup);
|
|
|
|
CREATE VIEW organizations_view AS SELECT
|
|
org.id,
|
|
org.name,
|
|
org.type,
|
|
org.lat,
|
|
org.lng,
|
|
org.city,
|
|
org.country,
|
|
org.status,
|
|
COALESCE(jsonb_agg(DISTINCT jsonb_build_object('id', oid.otherid, 'type', oid.type)) FILTER (WHERE oid.otherid IS NOT NULL), '[]') AS other_ids,
|
|
COALESCE(jsonb_agg(DISTINCT jsonb_build_object('name', n.name, 'lang', n.lang)) FILTER (WHERE n.name IS NOT NULL), '[]') AS other_names,
|
|
COALESCE(jsonb_agg(DISTINCT a.acronym) FILTER (WHERE a.acronym IS NOT NULL), '[]') AS acronyms,
|
|
COALESCE(jsonb_agg(DISTINCT u.url) FILTER (WHERE u.url IS NOT NULL), '[]') AS urls,
|
|
COALESCE(jsonb_agg(DISTINCT jsonb_build_object('relatedOrgId', relorg.id, 'relatedOrgName', relorg.name, 'type', r.reltype)) FILTER (WHERE relorg.id IS NOT NULL), '[]') AS relations
|
|
FROM
|
|
organizations org
|
|
LEFT OUTER JOIN other_ids oid ON (org.id = oid.id)
|
|
LEFT OUTER JOIN other_names n ON (org.id = n.id)
|
|
LEFT OUTER JOIN acronyms a ON (org.id = a.id)
|
|
LEFT OUTER JOIN urls u ON (org.id = u.id)
|
|
LEFT OUTER JOIN relationships r ON (org.id = r.id1)
|
|
LEFT OUTER JOIN organizations relorg ON (relorg.id = r.id2)
|
|
GROUP BY
|
|
org.id,
|
|
org.name,
|
|
org.type,
|
|
org.lat,
|
|
org.lng,
|
|
org.city,
|
|
org.country,
|
|
org.status;
|
|
|
|
CREATE VIEW organizations_info_view AS SELECT
|
|
org.id,
|
|
org.name,
|
|
org.created_by,
|
|
org.creation_date,
|
|
org.modified_by,
|
|
org.modification_date,
|
|
count(DISTINCT d.oa_original_id) as n_duplicates,
|
|
count(DISTINCT c.id2) as n_conflicts
|
|
FROM organizations org
|
|
LEFT OUTER JOIN oa_duplicates d ON (org.id = d.local_id AND d.reltype = 'suggested')
|
|
LEFT OUTER JOIN oa_conflicts c ON (org.id = c.id1 AND c.reltype = 'suggested')
|
|
GROUP BY org.id;
|
|
|
|
CREATE VIEW organizations_simple_view AS SELECT
|
|
org.id,
|
|
org.name,
|
|
org.type,
|
|
org.city,
|
|
org.country,
|
|
org.status,
|
|
array_remove(array_agg(DISTINCT a.acronym), NULL) AS acronyms,
|
|
array_remove(array_agg(DISTINCT u.url), NULL) AS urls
|
|
FROM
|
|
organizations org
|
|
LEFT OUTER JOIN acronyms a ON (org.id = a.id)
|
|
LEFT OUTER JOIN urls u ON (org.id = u.id)
|
|
GROUP BY
|
|
org.id,
|
|
org.name,
|
|
org.type,
|
|
org.city,
|
|
org.country,
|
|
org.status;
|
|
|
|
CREATE VIEW users_view AS SELECT
|
|
u.email,
|
|
u.valid,
|
|
u.role,
|
|
u.first_access,
|
|
u.last_access,
|
|
array_remove(array_agg(uc.country), NULL) AS countries
|
|
FROM
|
|
users u
|
|
LEFT OUTER JOIN user_countries uc ON (u.email = uc.email)
|
|
GROUP BY u.email, u.valid, u.role, u.first_access, u.last_access
|
|
ORDER BY u.email;
|
|
|
|
CREATE VIEW suggestions_info_by_country_view AS SELECT c.val AS country,
|
|
coalesce(t1.n_duplicates, 0) AS n_duplicates,
|
|
coalesce(t2.n_conflicts, 0) AS n_conflicts,
|
|
coalesce(t3.n_pending_orgs, 0) AS n_pending_orgs
|
|
FROM countries c
|
|
LEFT OUTER JOIN (SELECT o.country AS country, count(DISTINCT d.local_id) AS n_duplicates FROM oa_duplicates d LEFT OUTER JOIN organizations o ON (d.local_id = o.id) WHERE d.reltype = 'suggested' AND o.status = 'approved' GROUP BY o.country) AS t1 ON (t1.country = c.val)
|
|
LEFT OUTER JOIN (SELECT o.country AS country, count(DISTINCT c.idgroup) AS n_conflicts FROM oa_conflicts c LEFT OUTER JOIN organizations o ON (c.id1 = o.id) WHERE c.reltype = 'suggested' AND o.status = 'approved' GROUP BY o.country) AS t2 ON (t2.country = c.val)
|
|
LEFT OUTER JOIN (SELECT o.country AS country, count(DISTINCT o.id) AS n_pending_orgs FROM organizations o WHERE o.status = 'suggested' GROUP BY o.country) AS t3 ON (t3.country = c.val);
|
|
|
|
CREATE VIEW conflict_groups_view AS SELECT
|
|
c.idgroup AS idgroup,
|
|
o1.id AS id_1,
|
|
o1.name AS name_1,
|
|
o1.type AS type_1,
|
|
o1.city AS city_1,
|
|
o1.country AS country_1,
|
|
o2.id AS id_2,
|
|
o2.name AS name_2,
|
|
o2.type AS type_2,
|
|
o2.city AS city_2,
|
|
o2.country AS country_2
|
|
FROM
|
|
oa_conflicts c
|
|
LEFT OUTER JOIN organizations o1 ON (c.id1 = o1.id)
|
|
LEFT OUTER JOIN organizations o2 ON (c.id2 = o2.id)
|
|
WHERE
|
|
o1.id IS NOT NULL
|
|
AND o2.id IS NOT NULL
|
|
AND o1.status = 'approved'
|
|
AND o2.status = 'approved'
|
|
AND c.idgroup IS NOT NULL
|
|
AND c.reltype = 'suggested';
|
|
|
|
CREATE VIEW duplicate_groups_view AS SELECT
|
|
o.id,
|
|
o.name,
|
|
o.city,
|
|
o.country,
|
|
count(d.*) as n_duplicates
|
|
FROM
|
|
oa_duplicates d
|
|
LEFT OUTER JOIN organizations o ON (o.id = d.local_id)
|
|
WHERE
|
|
d.reltype = 'suggested' AND o.status = 'approved'
|
|
GROUP BY o.id, o.name, o.city, o.country
|
|
ORDER BY o.name;
|
|
|
|
CREATE TABLE org_index_search(id text PRIMARY KEY, txt tsvector);
|
|
CREATE INDEX org_index_search_txt_idx ON org_index_search(txt);
|
|
|
|
CREATE OR REPLACE FUNCTION refresh_index_search() RETURNS bigint AS $$
|
|
DELETE FROM org_index_search;
|
|
WITH d as (
|
|
INSERT INTO org_index_search(id, txt) SELECT
|
|
o.id,
|
|
to_tsvector(o.id||' '||o.name||' '||array_to_string(array_agg(DISTINCT n.name), ' ','')||' '||array_to_string(array_agg(DISTINCT a.acronym), ' ','')||' '||array_to_string(array_agg(DISTINCT u.url), ' ',''))
|
|
FROM organizations o
|
|
LEFT OUTER JOIN other_names n on (o.id = n.id)
|
|
LEFT OUTER JOIN acronyms a on (o.id = a.id)
|
|
LEFT OUTER JOIN urls u on (o.id = u.id)
|
|
GROUP BY o.id, o.name RETURNING *
|
|
) SELECT COUNT(*) FROM d;
|
|
$$ LANGUAGE SQL;
|
|
|
|
SELECT refresh_index_search();
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION delete_index_search() RETURNS trigger LANGUAGE plpgsql AS $$
|
|
BEGIN
|
|
DELETE FROM org_index_search WHERE id = old.id;
|
|
RETURN OLD;
|
|
END;
|
|
$$;
|
|
|
|
CREATE OR REPLACE FUNCTION insert_or_update_index_search_trigger() RETURNS trigger LANGUAGE plpgsql AS $$
|
|
BEGIN
|
|
INSERT INTO org_index_search(id, txt) (SELECT
|
|
o.id,
|
|
to_tsvector(o.id||' '||o.name||' '||array_to_string(array_agg(DISTINCT n.name), ' ','')||' '||array_to_string(array_agg(DISTINCT a.acronym), ' ','')||' '||array_to_string(array_agg(DISTINCT u.url), ' ',''))
|
|
FROM organizations o
|
|
LEFT OUTER JOIN other_names n on (o.id = n.id)
|
|
LEFT OUTER JOIN acronyms a on (o.id = a.id)
|
|
LEFT OUTER JOIN urls u on (o.id = u.id)
|
|
WHERE o.id = new.id
|
|
GROUP BY o.id, o.name)
|
|
ON CONFLICT (id) DO UPDATE SET txt = EXCLUDED.txt;
|
|
RETURN NEW;
|
|
END;
|
|
$$;
|
|
|
|
CREATE TRIGGER insert_or_update_index_search_trigger AFTER INSERT OR UPDATE ON organizations FOR EACH ROW EXECUTE PROCEDURE insert_or_update_index_search_trigger();
|
|
CREATE TRIGGER delete_index_search_trigger BEFORE DELETE ON organizations FOR EACH ROW EXECUTE PROCEDURE delete_index_search();
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|