Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
49 commits
Select commit Hold shift + click to select a range
b9ff3e8
Add database project including initial schema and postgres nvironment
May 29, 2020
b2eced5
Add connection pooling and use TestContainers for integration tests a…
May 29, 2020
ec93fdb
Apply feedback and expand
May 29, 2020
3b575d4
Add title
May 29, 2020
7988a45
Add games room skill level
May 29, 2020
e29d7b7
Add attribute table
May 29, 2020
64607d7
Change p_owner to p_display_name
May 29, 2020
babf292
Add create_item, create_attribute procedures
May 29, 2020
02464f6
Turn default appearance values into required procedure parameters for…
May 29, 2020
da12a6d
Add comment about reserved keyword 'position'
May 29, 2020
54f2e6f
Use CIText for email
May 29, 2020
54277e8
Remove character limits
May 29, 2020
6738931
Update all limitless varchars to text
May 29, 2020
e85e261
Update ConnectionConfig to simply rely on a URL instead of separate h…
May 29, 2020
0e368c3
Rename ConnectionPool#hikariPool to ConnectionPool#createHikariPool
May 29, 2020
4482f54
Update appearance table to borrow the player_id as its primary key
May 29, 2020
3dd9385
Remove duplicate create_account procedure
May 29, 2020
17a841c
Add energy units field
May 29, 2020
0b5a1b5
Remove all drops, add attributes as jsonb to item, add get_skills, ge…
May 29, 2020
b15f348
Add get_player function, get_appearance
May 29, 2020
390ac79
Inventory_type -> Inventory_id
May 29, 2020
b60dcbd
Rename password -> password_hash, remove attributes field from item t…
May 30, 2020
4ee6b29
Add last_login field, remove extra calls from create_player
May 30, 2020
46b263f
Remove email field from returned table in get_account
May 30, 2020
ba11b2c
Turn title into a separate table
May 30, 2020
15b47dc
Add account related domain types
May 30, 2020
0a45ae9
Move positional coords right into the player table, apply some clean ups
May 30, 2020
3341dac
Add player loading, account domain types
May 30, 2020
8771571
Rename ACCOUNT_FETCH_QUERY -> GET_ACCOUNT_QUERY
May 30, 2020
cc00840
Add thieving skill
May 30, 2020
fa4ed80
Add player saving
May 30, 2020
92bc7f4
Add in support for different types of attributes
May 30, 2020
e1f48cb
Slightly clean up JdbcPlayerSerializer
May 30, 2020
6b6c3b6
Remove energy units and games room skill level from player table
May 30, 2020
45bc21d
Update JdbcPlayerSerializer#putAttributes to not persist transient at…
May 30, 2020
a5e72c1
Update password in PlayerCredentials to password hash after password …
May 31, 2020
2ee7eda
Undo the getRunEnergy() return type change
May 31, 2020
d78334a
Use Guava's MoreObjects for toString()
Jun 8, 2020
02fa934
Remove value wrappers
Jun 8, 2020
a0a00fe
Remove entire database package
Jun 8, 2020
11a43cc
Update JdbcPlayerSerializer to consume a DataSource
Jun 8, 2020
3d54000
Rename Skill#getCount to Skill#count
Jun 8, 2020
7e1429e
Remove redundant database module, move schema and associated files to…
Jun 8, 2020
63b5b09
Update comments
Jun 8, 2020
0df0d56
Fix test to not rely on Docker and instead accept JDBC url
Jun 8, 2020
46f9def
Remove testcontainers dependency
Jun 8, 2020
560876c
Wrap operations in JdbcPlayerSerializer#savePlayer in a transaction
Jun 8, 2020
f73367b
Update getRunEnergy() to return a long
Jun 8, 2020
2e5c258
Move sql functions to ApolloQueries.kt
Jun 8, 2020
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: 2 additions & 0 deletions game/build.gradle
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,8 @@ dependencies {
compile group: 'org.jetbrains.kotlinx', name: 'kotlinx-coroutines-jdk8', version: kotlinxCoroutinesVersion
compile group: 'org.jetbrains.kotlinx', name: 'kotlinx-coroutines-core', version: kotlinxCoroutinesVersion

implementation group: 'com.zaxxer', name: 'HikariCP', version: '3.4.5'
implementation group: 'org.postgresql', name: 'postgresql', version: '42.2.12'
implementation group: 'com.google.guava', name: 'guava', version: guavaVersion
implementation group: 'io.github.classgraph', name: 'classgraph', version: classGraphVersion
implementation group: 'com.lambdaworks', name: 'scrypt', version: scryptVersion
Expand Down
5 changes: 5 additions & 0 deletions game/data/sql/Dockerfile
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
# Tell Docker to pull a Postgres 11 image running on Alpine
FROM postgres:11-alpine

# And then copy over the apollo.sql script into the container's entrypoint
COPY apollo.sql /docker-entrypoint-initdb.d/init.sql
13 changes: 13 additions & 0 deletions game/data/sql/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
# Apollo - SQL Database

For local development, a PostgreSQL database can be started using Docker and Docker-Compose, with the following command:

```
docker-compose up
```

You can modify the [apollo.sql](./apollo.sql) script to add dummy data to your database. Note however that you are required to delete the associated volume after modifying the script to make it work:

```
docker volume rm database_data
```
365 changes: 365 additions & 0 deletions game/data/sql/apollo.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,365 @@
CREATE EXTENSION citext;

CREATE TYPE rank AS ENUM ('player', 'moderator', 'administrator');
CREATE TYPE gender AS ENUM ('male', 'female');

CREATE TYPE attribute_type AS ENUM ('long', 'boolean', 'string', 'double');

CREATE TYPE skill AS ENUM (
'attack',
'strength',
'defence',
'hitpoints',
'ranged',
'prayer',
'magic',
'cooking',
'fishing',
'woodcutting',
'firemaking',
'mining',
'smithing',
'agility',
'herblore',
'thieving',
'crafting',
'fletching',
'runecraft',
'slayer',
'farming',
'hunter',
'construction'
);

CREATE TABLE account
(
id serial PRIMARY KEY,
email citext NOT NULL,
password_hash text NOT NULL,
rank rank NOT NULL
);

CREATE TABLE player
(
id serial PRIMARY KEY,
display_name text NOT NULL,
last_login timestamp,
x smallint NOT NULL CHECK (x >= 0 AND x <= 16384),
y smallint NOT NULL CHECK (y >= 0 AND y <= 16384),
height smallint NOT NULL CHECK (height >= 0 AND height <= 3),
account_id integer references account (id)
);

CREATE UNIQUE INDEX player_display_name_index ON player (display_name);

CREATE TABLE appearance
(
gender gender NOT NULL,
styles smallint ARRAY[7] NOT NULL,
colours smallint ARRAY[5] NOT NULL,
player_id integer references player (id),
PRIMARY KEY (player_id)
);

CREATE TABLE title
(
left_part text,
center_part text,
right_part text,
player_id integer references player (id),
PRIMARY KEY (player_id)
);

CREATE TABLE item
(
inventory_id smallint CHECK (inventory_id >= 0),
slot smallint CHECK (slot >= 0),
item_id integer CHECK (item_id >= 0),
quantity integer CHECK (quantity >= 0),
player_id integer references player (id),
PRIMARY KEY (inventory_id, slot, player_id)
);

CREATE TABLE attribute
(
name text NOT NULL,
attr_type attribute_type NOT NULL,
value text NOT NULL,
player_id integer references player (id),
PRIMARY KEY (player_id, name)
);

CREATE TABLE stat
(
skill skill NOT NULL,
stat smallint CHECK (stat >= 0 AND stat <= 127),
experience integer CHECK (experience >= 0 AND experience <= 200000000),
player_id integer REFERENCES player (id),
PRIMARY KEY (player_id, skill, stat)
);

CREATE PROCEDURE create_appearance(p_display_name text, p_gender gender, p_styles integer[7],
p_colours integer[5])
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO appearance (gender, styles, colours, player_id)
VALUES (p_gender, p_styles, p_colours, (SELECT id FROM player WHERE display_name = p_display_name));

COMMIT;
END ;
$$;

CREATE PROCEDURE create_title(p_display_name text, p_left_part text, p_center_part text, p_right_part text)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO title (left_part, center_part, right_part, player_id)
VALUES (p_left_part, p_center_part, p_right_part, (SELECT id FROM player WHERE display_name = p_display_name));

COMMIT;
END ;
$$;

CREATE PROCEDURE create_attribute(p_display_name text, p_attr_type attribute_type, p_name varchar, p_value text)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO attribute (attr_type, name, value, player_id)
VALUES (p_attr_type, p_name, p_value, (SELECT id FROM player WHERE display_name = p_display_name));

COMMIT;
END ;
$$;

CREATE PROCEDURE create_item(p_display_name text, p_inv_id integer, p_slot integer, p_item_id integer,
p_quantity integer)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO item (inventory_id, slot, item_id, quantity, player_id)
VALUES (p_inv_id, p_slot, p_item_id, p_quantity, (SELECT id FROM player WHERE display_name = p_display_name));

COMMIT;
END ;
$$;

CREATE PROCEDURE create_stat(p_skill skill, p_stat integer, p_experience integer, p_display_name text)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO stat (skill, stat, experience, player_id)
VALUES (p_skill, p_stat, p_experience, (SELECT id FROM player WHERE display_name = p_display_name));

COMMIT;
END;
$$;

CREATE PROCEDURE create_account(p_email varchar, p_password_hash varchar, p_rank rank)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO account (email, password_hash, rank)
VALUES (p_email, p_password_hash, p_rank);

COMMIT;
END;
$$;

CREATE PROCEDURE create_player(p_email citext, p_display_name text, p_x integer, p_y integer,
p_height integer)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO player (display_name, x, y, height, account_id)
VALUES (p_display_name, p_x, p_y, p_height, (SELECT id FROM account WHERE email = p_email));

COMMIT;
END;
$$;

CREATE PROCEDURE set_player(p_email citext, p_display_name text, p_last_login timestamp, p_x integer,
p_y integer, p_height integer)
LANGUAGE plpgsql
AS
$$
BEGIN
UPDATE player AS p
SET display_name = p_display_name,
last_login = p_last_login,
x = p_x,
y = p_y,
height = p_height
WHERE p.account_id = (SELECT id FROM account WHERE email = p_email);

COMMIT;
END;
$$;

CREATE PROCEDURE set_account(p_email citext, p_rank rank)
LANGUAGE plpgsql
AS
$$
BEGIN
UPDATE account AS a
SET rank = p_rank
WHERE email = p_email;

COMMIT;
END;
$$;

CREATE PROCEDURE set_appearance(p_display_name text, p_gender gender, p_styles integer[7],
p_colours integer[5])
LANGUAGE plpgsql
AS
$$
BEGIN
UPDATE appearance AS a
SET gender = p_gender,
styles = p_styles,
colours = p_colours
WHERE a.player_id = (SELECT id FROM player WHERE display_name = p_display_name);

COMMIT;
END;
$$;

CREATE PROCEDURE set_title(p_display_name text, p_left_part text, p_center_part text, p_right_part text)
LANGUAGE plpgsql
AS
$$
BEGIN
UPDATE title
SET left_part = p_left_part,
center_part = p_center_part,
right_part = p_right_part
WHERE player_id = (SELECT id FROM player WHERE display_name = p_display_name);

COMMIT;
END;
$$;

CREATE PROCEDURE set_item(p_display_name text, p_inv_id integer, p_slot integer, p_item_id integer,
p_quantity integer)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO item (inventory_id, slot, item_id, quantity, player_id)
VALUES (p_inv_id, p_slot, p_item_id, p_quantity, (SELECT id FROM player WHERE display_name = p_display_name))
ON CONFLICT (inventory_id, slot, player_id) DO UPDATE SET item_id = p_item_id, quantity = p_quantity;

COMMIT;
END ;
$$;

CREATE PROCEDURE set_stat(p_skill skill, p_stat integer, p_experience integer, p_display_name text)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO stat (skill, stat, experience, player_id)
VALUES (p_skill, p_stat, p_experience, (SELECT id FROM player WHERE display_name = p_display_name))
ON CONFLICT (player_id, skill, stat) DO UPDATE SET stat = p_stat, experience = p_experience;

COMMIT;
END;
$$;

CREATE PROCEDURE set_attribute(p_display_name text, p_attr_type attribute_type, p_name varchar, p_value text)
LANGUAGE plpgsql
AS
$$
BEGIN
INSERT INTO attribute (attr_type, name, value, player_id)
VALUES (p_attr_type, p_name, p_value, (SELECT id FROM player WHERE display_name = p_display_name))
ON CONFLICT (player_id, name) DO UPDATE SET value = p_value;

COMMIT;
END ;
$$;

CREATE PROCEDURE delete_item(p_display_name text, p_inv_id integer, p_slot integer)
LANGUAGE plpgsql
AS
$$
BEGIN
DELETE
FROM item
WHERE inventory_id = p_inv_id
AND slot = p_slot
AND player_id = (SELECT id FROM player WHERE display_name = p_display_name);

COMMIT;
END ;
$$;

CALL create_account('Sino'::citext, '$s0$e0801$U7iSxE4PoOGAg3wUkJkC2w==$WGCDBrNsBNosBEG8Uucz0YWZMv+T4NBJnQZRhcLCr6s=',
'administrator');
CALL create_player('Sino'::citext, 'Sino', 3254, 3420, 0);

CALL create_account('Sfix'::citext, '$s0$e0801$U7iSxE4PoOGAg3wUkJkC2w==$WGCDBrNsBNosBEG8Uucz0YWZMv+T4NBJnQZRhcLCr6s=',
'administrator');
CALL create_player('Sfix'::citext, 'Sfix', 3222, 3222, 0);

CALL create_title('Sino', '', '', '');
CALL create_title('Sfix', '', '', '');

CALL create_appearance('Sino', 'male', '{ 0, 10, 18, 26, 33, 36, 42 }', '{ 0, 0, 0, 0, 0 }');
CALL create_appearance('Sfix', 'male', '{ 0, 10, 18, 26, 33, 36, 42 }', '{ 0, 0, 0, 0, 0 }');

CALL create_stat('attack', 1, 0, 'Sino');
CALL create_stat('strength', 1, 0, 'Sino');
CALL create_stat('defence', 1, 0, 'Sino');
CALL create_stat('hitpoints', 10, 1183, 'Sino');
CALL create_stat('ranged', 1, 0, 'Sino');
CALL create_stat('prayer', 1, 0, 'Sino');
CALL create_stat('magic', 1, 0, 'Sino');
CALL create_stat('cooking', 1, 0, 'Sino');
CALL create_stat('fishing', 1, 0, 'Sino');
CALL create_stat('woodcutting', 1, 0, 'Sino');
CALL create_stat('firemaking', 1, 0, 'Sino');
CALL create_stat('mining', 1, 0, 'Sino');
CALL create_stat('smithing', 1, 0, 'Sino');
CALL create_stat('thieving', 1, 0, 'Sino');
CALL create_stat('agility', 1, 0, 'Sino');
CALL create_stat('herblore', 1, 0, 'Sino');
CALL create_stat('crafting', 1, 0, 'Sino');
CALL create_stat('fletching', 1, 0, 'Sino');
CALL create_stat('runecraft', 1, 0, 'Sino');
CALL create_stat('slayer', 1, 0, 'Sino');
CALL create_stat('farming', 1, 0, 'Sino');
CALL create_stat('hunter', 1, 0, 'Sino');
CALL create_stat('construction', 1, 0, 'Sino');

CALL create_stat('attack', 1, 0, 'Sfix');
CALL create_stat('strength', 1, 0, 'Sfix');
CALL create_stat('defence', 1, 0, 'Sfix');
CALL create_stat('hitpoints', 10, 1183, 'Sfix');
CALL create_stat('ranged', 1, 0, 'Sfix');
CALL create_stat('prayer', 1, 0, 'Sfix');
CALL create_stat('magic', 1, 0, 'Sfix');
CALL create_stat('cooking', 1, 0, 'Sfix');
CALL create_stat('fishing', 1, 0, 'Sfix');
CALL create_stat('woodcutting', 1, 0, 'Sfix');
CALL create_stat('firemaking', 1, 0, 'Sfix');
CALL create_stat('mining', 1, 0, 'Sfix');
CALL create_stat('smithing', 1, 0, 'Sfix');
CALL create_stat('thieving', 1, 0, 'Sfix');
CALL create_stat('agility', 1, 0, 'Sfix');
CALL create_stat('herblore', 1, 0, 'Sfix');
CALL create_stat('crafting', 1, 0, 'Sfix');
CALL create_stat('fletching', 1, 0, 'Sfix');
CALL create_stat('runecraft', 1, 0, 'Sfix');
CALL create_stat('slayer', 1, 0, 'Sfix');
CALL create_stat('farming', 1, 0, 'Sfix');
CALL create_stat('hunter', 1, 0, 'Sfix');
CALL create_stat('construction', 1, 0, 'Sfix');
Loading