Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

21.1 multi-region #27

Merged
merged 2 commits into from
Apr 27, 2021
Merged
Show file tree
Hide file tree
Changes from 1 commit
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion .env
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
SECRET_KEY = 'key'
DEBUG = 'True'
DB_URI = 'cockroachdb://root@127.0.0.1:<port>/movr'
DB_URI = 'cockroachdb://root@127.0.0.1:26257/movr'
API_KEY = 'API_key'
15 changes: 3 additions & 12 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -74,23 +74,14 @@ The steps below walk you through how to start up an insecure, virtual nine-node
Once the database finishes initializing, you should see a SQL shell prompt:

~~~
root@127.0.0.1:<some_port>/movr>
root@127.0.0.1:26257/movr>
~~~

Keep this terminal window open. Closing it will shut down the virtual cluster.

Also take note of the value for `<some_port>`, as you'll be using that for the next step.

1. Configure environment variables

Because we use `<some_port>` in a few places, let's save the port from the previous step
into a shell environment variable named `MOVR_PORT`:

~~~
export MOVR_PORT=<some_port>
~~~

The MovR application also uses Google Maps Static API, so we'll also store your
The MovR application uses Google Maps Static API, so we'll also store your
Google API Key into an environment variable as well:

~~~
Expand Down Expand Up @@ -168,7 +159,7 @@ For local deployment and development, use [`pipenv`](https://pypi.org/project/pi
This lets the application read values from an environement variable, rather than us needing to hard-code values directly into the source code.

In [Database and Environment Setup](#database-and-environment-setup) section, you ran `./init.sh` which
set the `DB_URI` and `API_KEY` keys in your `.env` file:
set the `DB_URI` and `API_KEY` variables in your `.env` file:

- `DB_URI` is the [SQL connection string](https://en.wikipedia.org/wiki/Connection_string) needed for SQLAlchemy to connect to CockroachDB. Note that SQLAlchemy requires the connection string protocol to be specific to the CockroachDB dialect.
- `API_KEY` should be your Google Static Maps API Key.
Expand Down
151 changes: 59 additions & 92 deletions dbinit.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,130 +4,97 @@ SET sql_safe_updates = false;
DROP DATABASE IF EXISTS movr CASCADE;


CREATE DATABASE movr;
CREATE DATABASE movr PRIMARY REGION "gcp-us-east1" REGIONS "gcp-europe-west1", "gcp-us-west1";
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

the problem with this setup is that users have to ensure they set up the servers correctly, i.e. set --locality=region=<blah> in their flask setup. is that what we want / already have?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yeah ... the README and tutorial specifically instruct the user to specify the localities that match these region names. They are based on the GCP cluster names. On CC, the localities for a multi-region GCP cluster should match these names anyways.



USE movr;


CREATE TABLE IF NOT EXISTS users (
id UUID NOT NULL DEFAULT gen_random_uuid(),
id UUID PRIMARY KEY NOT NULL DEFAULT gen_random_uuid(),
city STRING NOT NULL,
first_name STRING NULL,
last_name STRING NULL,
email STRING NULL,
username STRING NULL,
password_hash STRING NULL,
is_owner BOOL NULL,
CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC),
CONSTRAINT check_city CHECK (city IN ('amsterdam','boston','los angeles','new york','paris','rome','san francisco','seattle','washington dc')),
UNIQUE INDEX users_username_key (username ASC),
FAMILY "primary" (id, city, first_name, last_name, email, username, password_hash, is_owner)
) PARTITION BY LIST (city) (
PARTITION us_west VALUES IN (('seattle'), ('san francisco'), ('los angeles')),
PARTITION us_east VALUES IN (('new york'), ('boston'), ('washington dc')),
PARTITION europe_west VALUES IN (('amsterdam'), ('paris'), ('rome'))
);

ALTER PARTITION europe_west OF INDEX movr.public.users@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-europe-west1]';
ALTER PARTITION us_east OF INDEX movr.public.users@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-us-east1]';
ALTER PARTITION us_west OF INDEX movr.public.users@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-us-west1]'
;
UNIQUE INDEX users_username_key (username ASC)
) LOCALITY REGIONAL BY ROW;


ALTER TABLE users ADD COLUMN region crdb_internal_region AS (
CASE WHEN city = 'amsterdam' THEN 'gcp-europe-west1'
WHEN city = 'paris' THEN 'gcp-europe-west1'
WHEN city = 'rome' THEN 'gcp-europe-west1'
WHEN city = 'new york' THEN 'gcp-us-east1'
WHEN city = 'boston' THEN 'gcp-us-east1'
WHEN city = 'washington dc' THEN 'gcp-us-east1'
WHEN city = 'san francisco' THEN 'gcp-us-west1'
WHEN city = 'seattle' THEN 'gcp-us-west1'
WHEN city = 'los angeles' THEN 'gcp-us-west1'
ELSE 'gcp-us-east1'
END
) STORED;


CREATE TABLE IF NOT EXISTS vehicles (
id UUID NOT NULL DEFAULT gen_random_uuid(),
id UUID PRIMARY KEY NOT NULL DEFAULT gen_random_uuid(),
city STRING NOT NULL,
type STRING NULL,
owner_id UUID NULL,
date_added DATE NULL,
status STRING NULL,
last_location STRING NULL,
color STRING NULL,
brand STRING NULL,
CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC),
CONSTRAINT check_city CHECK (city IN ('amsterdam','boston','los angeles','new york','paris','rome','san francisco','seattle','washington dc')),
CONSTRAINT fk_city_ref_users FOREIGN KEY (city, owner_id) REFERENCES users(city, id),
INDEX vehicles_auto_index_fk_city_ref_users (city ASC, owner_id ASC, status ASC) PARTITION BY LIST (city) (
PARTITION us_west VALUES IN (('seattle'), ('san francisco'), ('los angeles')),
PARTITION us_east VALUES IN (('new york'), ('boston'), ('washington dc')),
PARTITION europe_west VALUES IN (('amsterdam'), ('paris'), ('rome'))
),
FAMILY "primary" (id, city, type, owner_id, date_added, status, last_location, color, brand)
) PARTITION BY LIST (city) (
PARTITION us_west VALUES IN (('seattle'), ('san francisco'), ('los angeles')),
PARTITION us_east VALUES IN (('new york'), ('boston'), ('washington dc')),
PARTITION europe_west VALUES IN (('amsterdam'), ('paris'), ('rome'))
);

ALTER PARTITION europe_west OF INDEX movr.public.vehicles@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-europe-west1]';
ALTER PARTITION us_east OF INDEX movr.public.vehicles@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-us-east1]';
ALTER PARTITION us_west OF INDEX movr.public.vehicles@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-us-west1]';
ALTER PARTITION europe_west OF INDEX movr.public.vehicles@vehicles_auto_index_fk_city_ref_users CONFIGURE ZONE USING
constraints = '[+region=gcp-europe-west1]';
ALTER PARTITION us_east OF INDEX movr.public.vehicles@vehicles_auto_index_fk_city_ref_users CONFIGURE ZONE USING
constraints = '[+region=gcp-us-east1]';
ALTER PARTITION us_west OF INDEX movr.public.vehicles@vehicles_auto_index_fk_city_ref_users CONFIGURE ZONE USING
constraints = '[+region=gcp-us-west1]'
;
brand STRING NULL,
CONSTRAINT fk_ref_users FOREIGN KEY (owner_id) REFERENCES users(id)
) LOCALITY REGIONAL BY ROW;


ALTER TABLE vehicles ADD COLUMN region crdb_internal_region AS (
CASE WHEN city = 'amsterdam' THEN 'gcp-europe-west1'
WHEN city = 'paris' THEN 'gcp-europe-west1'
WHEN city = 'rome' THEN 'gcp-europe-west1'
WHEN city = 'new york' THEN 'gcp-us-east1'
WHEN city = 'boston' THEN 'gcp-us-east1'
WHEN city = 'washington dc' THEN 'gcp-us-east1'
WHEN city = 'san francisco' THEN 'gcp-us-west1'
WHEN city = 'seattle' THEN 'gcp-us-west1'
WHEN city = 'los angeles' THEN 'gcp-us-west1'
ELSE 'gcp-us-east1'
END
) STORED;


CREATE TABLE rides (
id UUID NOT NULL DEFAULT gen_random_uuid(),
id UUID PRIMARY KEY NOT NULL DEFAULT gen_random_uuid(),
city STRING NOT NULL,
vehicle_id UUID NULL,
rider_id UUID NULL,
rider_city STRING NOT NULL,
start_location STRING NULL,
end_location STRING NULL,
start_time TIMESTAMPTZ NULL,
end_time TIMESTAMPTZ NULL,
length INTERVAL NULL,
CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC),
CONSTRAINT check_city CHECK (city IN ('amsterdam','boston','los angeles','new york','paris','rome','san francisco','seattle','washington dc')),
CONSTRAINT fk_city_ref_users FOREIGN KEY (rider_city, rider_id) REFERENCES users(city, id),
CONSTRAINT fk_vehicle_city_ref_vehicles FOREIGN KEY (city, vehicle_id) REFERENCES vehicles(city, id),
INDEX rides_auto_index_fk_city_ref_users (rider_city ASC, rider_id ASC) PARTITION BY LIST (rider_city) (
PARTITION us_west VALUES IN (('seattle'), ('san francisco'), ('los angeles')),
PARTITION us_east VALUES IN (('new york'), ('boston'), ('washington dc')),
PARTITION europe_west VALUES IN (('amsterdam'), ('paris'), ('rome'))
),
INDEX rides_auto_index_fk_vehicle_city_ref_vehicles (city ASC, vehicle_id ASC) PARTITION BY LIST (city) (
PARTITION us_west VALUES IN (('seattle'), ('san francisco'), ('los angeles')),
PARTITION us_east VALUES IN (('new york'), ('boston'), ('washington dc')),
PARTITION europe_west VALUES IN (('amsterdam'), ('paris'), ('rome'))
),
FAMILY "primary" (id, city, rider_id, rider_city, vehicle_id, start_location, end_location, start_time, end_time, length)
) PARTITION BY LIST (city) (
PARTITION us_west VALUES IN (('seattle'), ('san francisco'), ('los angeles')),
PARTITION us_east VALUES IN (('new york'), ('boston'), ('washington dc')),
PARTITION europe_west VALUES IN (('amsterdam'), ('paris'), ('rome'))
);
ALTER PARTITION europe_west OF INDEX movr.public.rides@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-europe-west1]';
ALTER PARTITION us_east OF INDEX movr.public.rides@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-us-east1]';
ALTER PARTITION us_west OF INDEX movr.public.rides@primary CONFIGURE ZONE USING
constraints = '[+region=gcp-us-west1]';
ALTER PARTITION europe_west OF INDEX movr.public.rides@rides_auto_index_fk_city_ref_users CONFIGURE ZONE USING
constraints = '[+region=gcp-europe-west1]';
ALTER PARTITION us_east OF INDEX movr.public.rides@rides_auto_index_fk_city_ref_users CONFIGURE ZONE USING
constraints = '[+region=gcp-us-east1]';
ALTER PARTITION us_west OF INDEX movr.public.rides@rides_auto_index_fk_city_ref_users CONFIGURE ZONE USING
constraints = '[+region=gcp-us-west1]';
ALTER PARTITION europe_west OF INDEX movr.public.rides@rides_auto_index_fk_vehicle_city_ref_vehicles CONFIGURE ZONE USING
constraints = '[+region=gcp-europe-west1]';
ALTER PARTITION us_east OF INDEX movr.public.rides@rides_auto_index_fk_vehicle_city_ref_vehicles CONFIGURE ZONE USING
constraints = '[+region=gcp-us-east1]';
ALTER PARTITION us_west OF INDEX movr.public.rides@rides_auto_index_fk_vehicle_city_ref_vehicles CONFIGURE ZONE USING
constraints = '[+region=gcp-us-west1]'
;
CONSTRAINT fk_city_ref_users FOREIGN KEY (rider_id) REFERENCES users(id),
CONSTRAINT fk_vehicle_ref_vehicles FOREIGN KEY (vehicle_id) REFERENCES vehicles(id)
);
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

nit: unindent ending );

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

After fixing the table (see comment below), I formatted the document with pgformatter. Should look nicer all over now.



ALTER TABLE rides ADD COLUMN region crdb_internal_region AS (
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

do we ever make this table REGIONAL BY ROW? seems like it is REGIONAL BY TABLE at the moment.
we should do this inline, i.e.

CREATE TABLE users (

   ...,
   region crdb_internal_region  CASE WHEN city = 'amsterdam' THEN 'gcp-europe-west1'
       WHEN city = 'paris' THEN 'gcp-europe-west1'
       WHEN city = 'rome' THEN 'gcp-europe-west1'
       WHEN city = 'new york' THEN 'gcp-us-east1'
       WHEN city = 'boston' THEN 'gcp-us-east1'
       WHEN city = 'washington dc' THEN 'gcp-us-east1'
       WHEN city = 'san francisco' THEN 'gcp-us-west1'
       WHEN city = 'seattle' THEN 'gcp-us-west1'
       WHEN city = 'los angeles' THEN 'gcp-us-west1'
       ELSE 'gcp-us-east1',
     
       ....
) LOCALITY REGIONAL BY ROW; -- optionally REGIONAL BY ROW AS "region"

same with the others

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

My mistake. Fixed for rides.

Also, moved the region column definition to the CREATE TABLE statement for all tables.

CASE WHEN city = 'amsterdam' THEN 'gcp-europe-west1'
WHEN city = 'paris' THEN 'gcp-europe-west1'
WHEN city = 'rome' THEN 'gcp-europe-west1'
WHEN city = 'new york' THEN 'gcp-us-east1'
WHEN city = 'boston' THEN 'gcp-us-east1'
WHEN city = 'washington dc' THEN 'gcp-us-east1'
WHEN city = 'san francisco' THEN 'gcp-us-west1'
WHEN city = 'seattle' THEN 'gcp-us-west1'
WHEN city = 'los angeles' THEN 'gcp-us-west1'
ELSE 'gcp-us-east1'
END
) STORED;


INSERT INTO users (id, city, first_name, last_name, email, username) VALUES
Expand All @@ -136,5 +103,5 @@ INSERT INTO users (id, city, first_name, last_name, email, username) VALUES
INSERT INTO vehicles (id, city, type, owner_id, date_added, status, last_location, color, brand) VALUES
('142b7c9e-6227-4dbb-b188-b1dac57d5521', 'new york', 'scooter', '2804df7c-d8fd-4b1c-9799-b1d44452554b', current_date(),'available', 'Time Square', 'Blue', 'Razor');

INSERT INTO rides(city, rider_id, rider_city, vehicle_id, start_location, end_location, start_time, end_time, length) VALUES
('new york', '2804df7c-d8fd-4b1c-9799-b1d44452554b', 'new york', '142b7c9e-6227-4dbb-b188-b1dac57d5521', 'Cockroach Labs, 23rd Street', 'Time Square', '2020-01-16 21:20:48.224453+00:00', '2020-01-16 21:20:52.045813+00:00', '00:00:03.82136');
INSERT INTO rides(city, rider_id, vehicle_id, start_location, end_location, start_time, end_time, length) VALUES
('new york', '2804df7c-d8fd-4b1c-9799-b1d44452554b', '142b7c9e-6227-4dbb-b188-b1dac57d5521', 'Cockroach Labs, 23rd Street', 'Time Square', '2020-01-16 21:20:48.224453+00:00', '2020-01-16 21:20:52.045813+00:00', '00:00:03.82136');
7 changes: 1 addition & 6 deletions init.sh
Original file line number Diff line number Diff line change
@@ -1,16 +1,11 @@
#!/bin/bash

# Loads dbinit.sql into your running CockroachDB cluster
cockroach sql --insecure --url="postgres://root@127.0.0.1:$MOVR_PORT" < dbinit.sql
cockroach sql --insecure --url="postgres://root@127.0.0.1:26257" < dbinit.sql

# Resets .env file, clearing out any variables that were previously set
git checkout -- .env

# replace <port> with $MOVR_PORT in `.env` for the following env variable:
# DB_URI = 'cockroachdb://root@127.0.0.1:<port>/movr'
# where DB_URI is the SQL connection string needed for SQLAlchemy to connect to CockroachDB.
sed "s/<port>/$MOVR_PORT/" .env > temp

# replace API_key with $MOVR_MAPS_API in `.env` for the following env variable:
# API_KEY = 'API_key'
# where API_KEY is Google Maps Static API Key needed to generate maps on the Vehicles page.
Expand Down
5 changes: 2 additions & 3 deletions movr/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -62,7 +62,7 @@ class Vehicle(Base):
last_location = Column(String)
color = Column(String)
brand = Column(String)
PrimaryKeyConstraint(city, id)
PrimaryKeyConstraint(id)

def __repr__(self):
return "<Vehicle(city='{0}', id='{1}', type='{2}', status='{3}')>".format(
Expand All @@ -83,14 +83,13 @@ class Ride(Base):
id = Column(UUID)
city = Column(String, ForeignKey('vehicles.city'))
rider_id = Column(UUID, ForeignKey('users.id'))
rider_city = Column(String, ForeignKey('users.city'))
vehicle_id = Column(UUID, ForeignKey('vehicles.id'))
start_location = Column(String)
end_location = Column(String)
start_time = Column(DateTime)
end_time = Column(DateTime)
length = Column(Interval)
PrimaryKeyConstraint(city, id)
PrimaryKeyConstraint(id)

def __repr__(self):
return "<Ride(city='{0}', id='{1}', rider_id='{2}', vehicle_id='{3}')>".format(
Expand Down
33 changes: 11 additions & 22 deletions movr/movr.py
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ class MovR:
"""
Wraps the database connection. The class methods wrap database transactions.
"""

def __init__(self, conn_string):
"""
Establish a connection to the database, creating Engine and Sessionmaker objects.
Expand All @@ -21,32 +22,30 @@ def __init__(self, conn_string):
self.engine = create_engine(conn_string, convert_unicode=True)
self.sessionmaker = sessionmaker(bind=self.engine)

def start_ride(self, city, rider_id, rider_city, vehicle_id):
def start_ride(self, city, rider_id, vehicle_id):
"""
Wraps a `run_transaction` call that starts a ride.

Arguments:
city {String} -- The ride's city.
rider_id {UUID} -- The user's unique ID.
rider_city {String} -- The user's city.
vehicle_id {UUID} -- The vehicle's unique ID.
"""
return run_transaction(
self.sessionmaker, lambda session: start_ride_txn(
session, city, rider_id, rider_city, vehicle_id))
session, city, rider_id, vehicle_id))

def end_ride(self, city, ride_id, location):
def end_ride(self, ride_id, location):
"""
Wraps a `run_transaction` call that ends a ride.

Arguments:
city {String} -- The ride's city.
ride_id {UUID} -- The ride's unique ID.
location {String} -- The vehicle's last location.
"""
return run_transaction(
self.sessionmaker,
lambda session: end_ride_txn(session, city, ride_id, location))
lambda session: end_ride_txn(session, ride_id, location))

def add_user(self, city, first_name, last_name, email, username, password):
"""
Expand All @@ -65,39 +64,29 @@ def add_user(self, city, first_name, last_name, email, username, password):
lambda session: add_user_txn(session, city, first_name, last_name,
email, username, password))

def remove_user(self, city, user_id):
def remove_user(self, user_id):
"""
Wraps a `run_transaction` call that "removes" a user. No rows are deleted by this function.

Arguments:
city {String} -- The user's city.
id {UUID} -- The user's unique ID.
"""
return run_transaction(
self.sessionmaker,
lambda session: remove_user_txn(session, city, user_id))
lambda session: remove_user_txn(session, user_id))

def remove_vehicle(self, city, vehicle_id):
def remove_vehicle(self, vehicle_id):
"""
Wraps a `run_transaction` call that "removes" a vehicle. No rows are deleted by this function.

Arguments:
city {String} -- The vehicle's city.
id {UUID} -- The vehicle's unique ID.
"""
return run_transaction(
self.sessionmaker,
lambda session: remove_vehicle_txn(session, city, vehicle_id))

def add_vehicle(self,
city,
owner_id,
last_location,
type,
color,
brand,
status,
is_owner=False):
lambda session: remove_vehicle_txn(session, vehicle_id))

def add_vehicle(self, city, owner_id, last_location, type, color, brand, status, is_owner=False):
"""
Wraps a `run_transaction` call that adds a vehicle.

Expand Down
Loading