dnet-applications/apps/dnet-orgs-database-application/bin/src/main/resources/sql/first_import_grid_ac.sql

104 lines
6.0 KiB
SQL

CREATE TEMP TABLE grid_institutes (
grid_id text,
name text,
wikipedia_url text,
email_address text,
established int
);
CREATE TEMP TABLE grid_geonames (
geonames_city_id text,
city text,
nuts_level1_code text,
nuts_level1_name text,
nuts_level2_code text,
nuts_level2_name text,
nuts_level3_code text,
nuts_level3_name text,
geonames_admin1_code text,
geonames_admin1_name text,
geonames_admin1_ascii_name text,
geonames_admin2_code text,
geonames_admin2_name text,
geonames_admin2_ascii_name text
);
CREATE TEMP TABLE grid_addresses (
grid_id text,
line_1 text,
line_2 text,
line_3 text,
lat double precision,
lng double precision,
postcode text,
is_primary boolean,
city text,
state text,
state_code text,
country text,
country_code text,
geonames_city_id int
);
CREATE TEMP TABLE grid_external_ids (
grid_id text,
external_id_type text,
external_id text
);
CREATE TEMP TABLE grid_labels (
grid_id text,
iso639 text,
label text
);
CREATE TEMP TABLE grid_relationships (
grid_id text,
relationship_type text,
related_grid_id text
);
CREATE TEMP TABLE grid_types (
grid_id text,
type text
);
CREATE TEMP TABLE grid_links (
grid_id text,
link text
);
CREATE TEMP TABLE grid_acronyms (
grid_id text,
acronym text
);
CREATE TEMP TABLE grid_aliases (
grid_id text,
alias text
);
COPY grid_institutes (grid_id,name,wikipedia_url,email_address,established) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/institutes.csv' CSV HEADER;
COPY grid_geonames (geonames_city_id,city,nuts_level1_code,nuts_level1_name,nuts_level2_code,nuts_level2_name,nuts_level3_code,nuts_level3_name,geonames_admin1_code,geonames_admin1_name,geonames_admin1_ascii_name,geonames_admin2_code,geonames_admin2_name,geonames_admin2_ascii_name) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/geonames.csv' CSV HEADER;
COPY grid_addresses (grid_id,line_1,line_2,line_3,lat,lng,postcode,is_primary,city,state,state_code,country,country_code,geonames_city_id) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/addresses.csv' CSV HEADER;
COPY grid_external_ids (grid_id,external_id_type,external_id) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/external_ids.csv' CSV HEADER;
COPY grid_labels (grid_id,iso639,label) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/labels.csv' CSV HEADER;
COPY grid_relationships (grid_id,relationship_type,related_grid_id) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/relationships.csv' CSV HEADER;
COPY grid_types (grid_id,type) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/types.csv' CSV HEADER;
COPY grid_links (grid_id,link) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/links.csv' CSV HEADER;
COPY grid_acronyms (grid_id,acronym) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/acronyms.csv' CSV HEADER;
COPY grid_aliases (grid_id,alias) FROM '/Users/michele/Develop/dnet45/dnet-applications/apps/dnet-orgs-database-application/data/grid-2020-06-29/full_tables/aliases.csv' CSV HEADER;
INSERT INTO organizations(id, name, type, lat, lng, city, country, created_by, modified_by) (SELECT 'tmp::'||md5(o.grid_id), o.name, COALESCE(t.type, 'UNKNOWN'), a.lat, a.lng, a.city, a.country_code, 'import:grid.ac', 'import:grid.ac' FROM grid_institutes o LEFT OUTER JOIN grid_addresses a ON (o.grid_id=a.grid_id) LEFT OUTER JOIN grid_types t ON (o.grid_id=t.grid_id)) ON CONFLICT DO NOTHING;
INSERT INTO other_ids (id, otherid, type) (SELECT 'tmp::'||md5(grid_id), grid_id, 'GRID' FROM grid_institutes ) ON CONFLICT DO NOTHING;
INSERT INTO other_ids (id, otherid, type) (SELECT 'tmp::'||md5(grid_id), external_id, external_id_type FROM grid_external_ids ) ON CONFLICT DO NOTHING;
INSERT INTO other_names (id, lang, name) (SELECT 'tmp::'||md5(grid_id), 'en', name FROM grid_institutes ) ON CONFLICT DO NOTHING;
INSERT INTO other_names (id, lang, name) (SELECT 'tmp::'||md5(grid_id), iso639, label FROM grid_labels ) ON CONFLICT DO NOTHING;
INSERT INTO other_names (id, lang, name) (SELECT 'tmp::'||md5(grid_id), 'UNKNOWN', alias FROM grid_aliases ) ON CONFLICT DO NOTHING;
INSERT INTO acronyms (id, acronym) (SELECT 'tmp::'||md5(grid_id), acronym FROM grid_acronyms ) ON CONFLICT DO NOTHING;
INSERT INTO relationships(id1, reltype, id2) (SELECT 'tmp::'||md5(grid_id), relationship_type, 'tmp::'||md5(related_grid_id) FROM grid_relationships) ON CONFLICT DO NOTHING;
INSERT INTO urls (id, url) (SELECT 'tmp::'||md5(grid_id), link FROM grid_links ) ON CONFLICT DO NOTHING;
update organizations set id = DEFAULT;