Skip to content

Commit

Permalink
Stall plug detail (#2) (#32)
Browse files Browse the repository at this point in the history
5.1.0 stall and plug details + additional site fields
  • Loading branch information
paulkva authored Mar 24, 2024
1 parent a45c1f6 commit bdf690e
Show file tree
Hide file tree
Showing 38 changed files with 1,541 additions and 138 deletions.
64 changes: 64 additions & 0 deletions database/copy-prod-db-to-test.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
#!/usr/bin/env bash
#====================================================================================
# Script for copying the latest data from the prod database into the local database.
#
#
# REQUIRES:
# sudo apt install postgresql-client
#====================================================================================

# exit script on any error
trap 'exit' ERR


#------------------------------------------------------------------------------------
# dump
#------------------------------------------------------------------------------------
SRC_HOST="localhost"
SRC_PORT="5432"
SRC_USERNAME="supercharge_user"
SRC_DATABASE="postgres"
SRC_SCHEMA="supercharge"
OUT_SQL_DIR="/tmp/migration-dump-prod-$$"

echo "**** Enter PROD password for ${SRC_USERNAME} on ${SRC_HOST}:${SRC_PORT}"
pg_dump \
--host=${SRC_HOST} \
--port=${SRC_PORT} \
--encoding=UTF-8 \
--username=${SRC_USERNAME} \
--dbname=${SRC_DATABASE} \
--schema=${SRC_SCHEMA} \
--blobs \
--format=d \
--verbose \
--quote-all-identifiers \
--jobs=2 \
--file="${OUT_SQL_DIR}"


#------------------------------------------------------------------------------------
# restore
#------------------------------------------------------------------------------------
DST_USERNAME="supercharge_user_test"
DST_HOST="localhost"
DST_PORT="5432"
DST_DATABASE="test"
DST_SCHEMA="supercharge"


echo "ALTER SCHEMA ${DST_SCHEMA} RENAME TO ${DST_SCHEMA}_$$" | psql --username="${DST_USERNAME}" --host="${DST_HOST}" --port="${DST_PORT}" "${DST_DATABASE}"

echo "**** Enter password for ${DST_USERNAME} on TARGET database at ${DST_HOST}:${DST_PORT}"
pg_restore \
--username="${DST_USERNAME}" \
--host="${DST_HOST}" \
--dbname="${DST_DATABASE}" \
--port="${DST_PORT}" \
--format=d \
--verbose \
--jobs=2 \
"${OUT_SQL_DIR}"


echo "done"
97 changes: 69 additions & 28 deletions database/sql/04-tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,7 @@ drop table if exists user_config;
drop table if exists user_reset;
drop table if exists changelog;
drop table if exists site_change;
drop table if exists parking;
drop table if exists site;
drop table if exists address;
drop table if exists country;
Expand All @@ -40,12 +41,18 @@ alter sequence region_region_id_seq restart with 150;
-- -----------------------------------------------------------
create table country
(
country_id serial primary key,
name varchar(100) not null unique,
code varchar(2) not null unique,
region_id int not null,
state_required boolean not null default false,
modified_date timestamptz not null default current_timestamp,
country_id serial primary key,
name varchar(100) not null unique,
code varchar(2) not null unique,
region_id int not null,
state_required boolean not null default false,
modified_date timestamptz not null default current_timestamp,
plugs_tpc boolean not null default true,
plugs_nacs boolean not null default true,
plugs_ccs1 boolean not null default true,
plugs_ccs2 boolean not null default true,
plugs_type2 boolean not null default true,
plugs_gbt boolean not null default true,
foreign key (region_id) references region (region_id)
on update cascade
on delete cascade
Expand Down Expand Up @@ -75,40 +82,74 @@ create table address
);
alter sequence address_address_id_seq restart with 2000000;

-- -----------------------------------------------------------
-- PARKING - lookup table
-- -----------------------------------------------------------
create table parking
(
parking_id serial primary key,
name varchar(100) not null,
description text null
);

-- -----------------------------------------------------------
-- SITE
-- -----------------------------------------------------------
create type site_status_type as enum ('CLOSED_PERM','CLOSED_TEMP', 'PERMIT', 'CONSTRUCTION', 'OPEN');
create type site_status_type as enum ('CLOSED_PERM','CLOSED_TEMP', 'PERMIT', 'CONSTRUCTION', 'OPEN', 'VOTING', 'PLAN', 'EXPANDING');

create table site
(
site_id serial not null,
location_id varchar(300) null default null::character varying,
"name" varchar(100) not null,
status "site_status_type" not null,
opened_date timestamptz null,
hours varchar(100) null default null::character varying,
enabled bool not null default true,
counted bool not null,
address_id int4 not null,
gps_latitude float8 not null,
gps_longitude float8 not null,
elevation_meters int4 not null,
url_discuss varchar(200) null default null::character varying,
stall_count int4 null,
power_kwatt int4 not null default 0,
has_solar_canopy bool not null default false,
has_battery bool not null default false,
developer_notes varchar(1000) null default null::character varying,
modified_date timestamptz not null default now(),
"version" int4 not null default 1,
other_evs bool not null default false,
site_id serial not null,
location_id varchar(300) null default null::character varying,
"name" varchar(100) not null,
status "site_status_type" not null,
opened_date timestamptz null,
hours varchar(100) null default null::character varying,
enabled bool not null default true,
counted bool not null,
address_id int4 not null,
gps_latitude float8 not null,
gps_longitude float8 not null,
elevation_meters int4 not null,
url_discuss varchar(200) null default null::character varying,
stall_count int4 null,
power_kwatt int4 not null default 0,
has_solar_canopy bool not null default false,
has_battery bool not null default false,
developer_notes varchar(1000) null default null::character varying,
modified_date timestamptz not null default now(),
"version" int4 not null default 1,
other_evs bool not null default false, -- TO BE DEPRECATED
stalls_urban int4 null,
stalls_v2 int4 null,
stalls_v3 int4 null,
stalls_v4 int4 null,
stalls_other int4 null,
stalls_accessible int4 null,
stalls_trailer int4 null,
plugs_tpc int4 null,
plugs_nacs int4 null,
plugs_ccs1 int4 null,
plugs_ccs2 int4 null,
plugs_type2 int4 null,
plugs_gbt int4 null,
plugs_other int4 null,
plugs_multi int4 null,
parking_id int4 null,
facility_name varchar(200) null default null::character varying,
facility_hours varchar(100) null default null::character varying,
access_notes varchar(1000) null default null::character varying,
address_notes varchar(1000) null default null::character varying,
plugshare_id int8 null,
osm_id int8 null,
constraint address_id_unique unique (address_id),
constraint name_unique unique (name),
constraint site_id_unique primary key (site_id)
);
alter table site
add constraint site_address_id_fkey foreign key (address_id) references address(address_id) on delete cascade on update cascade;
alter table site
add constraint site_parking_id_fkey foreign key (parking_id) references parking(parking_id) on delete cascade on update cascade;
alter sequence site_site_id_seq restart with 100000;

-- -----------------------------------------------------------
Expand Down
6 changes: 6 additions & 0 deletions database/sql/31-reference-countries.sql
Original file line number Diff line number Diff line change
Expand Up @@ -62,3 +62,9 @@ INSERT INTO country (country_id,"name",code,region_id,state_required,modified_da
INSERT INTO country (country_id,"name",code,region_id,state_required,modified_date) VALUES (160,'Malaysia','MY',102,false,now());
INSERT INTO country (country_id,"name",code,region_id,state_required,modified_date) VALUES (161,'Qatar','QA',102,false,now());
INSERT INTO country (country_id,"name",code,region_id,state_required,modified_date) VALUES (162,'Chile','CL',103,false,now());

-- pre-populate valid plug types per country
UPDATE country SET plugs_gbt = false WHERE name != 'China';
UPDATE country SET plugs_tpc = false, plugs_nacs = false, plugs_ccs1 = false WHERE region_id IN (101, 102) AND name NOT IN ('Japan', 'South Korea', 'Taiwan');
UPDATE country SET plugs_type2 = false, plugs_ccs2 = false WHERE region_id = 100 OR name IN ('Japan', 'South Korea');
UPDATE country SET plugs_ccs1 = false WHERE name IN ('Japan', 'Taiwan');
69 changes: 69 additions & 0 deletions database/sql/32-reference-sites.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7541,3 +7541,72 @@ COPY "supercharge"."site_change" ("site_id", "user_id", "version", "change_date"
-- PostgreSQL database dump complete
--

-- Pre-populate stalls based on max power
UPDATE site SET stalls_urban = stall_count WHERE power_kwatt <= 72;
UPDATE site SET stalls_v2 = stall_count WHERE power_kwatt BETWEEN 73 AND 199;
UPDATE site SET stalls_v3 = stall_count WHERE power_kwatt >= 200; -- a few of these are V4 at the time of release and will have to be updated manually

-- Pre-populate plugs based on geography, max power, and existing other_evs flag

-- All stalls in China are GB/T, except Hong Kong and Macau which are CCS2 (with one weird exception in Macau to be updated manually)
UPDATE site s SET plugs_gbt = stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.name = 'China' AND a.state NOT IN ('Hong Kong', 'Macau');
UPDATE site s SET plugs_ccs2 = stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.name = 'China' AND a.state IN ('Hong Kong', 'Macau');

-- All stalls in Jordan are Type2
UPDATE site s SET plugs_type2 = stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.name = 'Jordan';

-- Taiwan is mostly dual-cable CCS2+TPC but some will have to be updated manually
UPDATE site s SET plugs_ccs2 = s.stall_count, plugs_tpc = s.stall_count, plugs_multi = s.stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.name = 'Taiwan';

-- North America V2 + Urban, and all stalls in Japan + South Korea, are TPC if they're not already marked open to other EVs
UPDATE site s SET plugs_tpc = s.stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND ((s.power_kwatt < 200 AND c.region_id = 100) OR c.name IN ('Japan', 'South Korea')) AND NOT s.other_evs;

-- North America + South Korea stalls that are already marked open to other EVs are all MagicDock (TPC+CCS1)
UPDATE site s SET plugs_tpc = s.stall_count, plugs_ccs1 = s.stall_count, plugs_multi = s.stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND (c.region_id = 100 OR c.name = 'South Korea') AND s.other_evs;

-- North America V3 + V4 stalls are all NACS if they're not already marked open to other EVs
UPDATE site s SET plugs_nacs = s.stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.region_id = 100 AND s.power_kwatt = 250 AND NOT s.other_evs;

-- Europe V2 stalls are dual-cable CCS2+Type2
UPDATE site s SET plugs_ccs2 = s.stall_count, plugs_type2 = s.stall_count, plugs_multi = s.stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.region_id = 101 AND s.power_kwatt BETWEEN 73 AND 199;

-- Presume the rest of the world's V2 stalls have CCS2 plugs
UPDATE site s SET plugs_ccs2 = stall_count
FROM address a, country c
WHERE s.address_id = a.address_id AND a.country_id = c.country_id
AND c.region_id != 100 AND c.name NOT IN ('China', 'Japan', 'Jordan', 'South Korea', 'Taiwan')
AND NOT (c.region_id = 101 AND s.power_kwatt BETWEEN 73 AND 199);

-- Pre-populate parking options
INSERT INTO parking (name, description) VALUES
('Free at all times', 'Unrestricted at all times with no fee to park'),
('Free with validation', 'No fee to park for the first N minutes of parking with proof of purchase from certain merchants'),
('Free initially', 'No fee to park for the first N minutes of parking'),
('Free off-peak', 'No fee to park outside of peak hours/days (e.g. nights, weekends)'),
('Paid - self parking', 'Fee to park at all times'),
('Paid - valet parking', 'Fee to park at all times with valet assistance'),
('Other - see notes', 'Details provided in "Access Notes"');
2 changes: 1 addition & 1 deletion pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@

<groupId>info.supercharge.api</groupId>
<artifactId>supercharge.info-api</artifactId>
<version>5.0.3-SNAPSHOT</version>
<version>5.1.1-SNAPSHOT</version>


<properties>
Expand Down
2 changes: 1 addition & 1 deletion service-dao/pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@
<parent>
<groupId>info.supercharge.api</groupId>
<artifactId>supercharge.info-api</artifactId>
<version>5.0.3-SNAPSHOT</version>
<version>5.1.1-SNAPSHOT</version>
</parent>

<modelVersion>4.0.0</modelVersion>
Expand Down
Loading

0 comments on commit bdf690e

Please sign in to comment.