diff --git a/game/build.gradle b/game/build.gradle index 1a451eb99..f75eed4e4 100644 --- a/game/build.gradle +++ b/game/build.gradle @@ -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 diff --git a/game/data/sql/Dockerfile b/game/data/sql/Dockerfile new file mode 100644 index 000000000..0829cf8d9 --- /dev/null +++ b/game/data/sql/Dockerfile @@ -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 \ No newline at end of file diff --git a/game/data/sql/README.md b/game/data/sql/README.md new file mode 100644 index 000000000..c92290561 --- /dev/null +++ b/game/data/sql/README.md @@ -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 +``` \ No newline at end of file diff --git a/game/data/sql/apollo.sql b/game/data/sql/apollo.sql new file mode 100644 index 000000000..4e26d0243 --- /dev/null +++ b/game/data/sql/apollo.sql @@ -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'); diff --git a/game/data/sql/docker-compose.yml b/game/data/sql/docker-compose.yml new file mode 100644 index 000000000..e2b1dea71 --- /dev/null +++ b/game/data/sql/docker-compose.yml @@ -0,0 +1,18 @@ +version: '3.0' +volumes: + data: + driver: local + +services: + db: + container_name: db + build: . + restart: always + environment: + - POSTGRES_USER=postgres + - POSTGRES_PASSWORD=postgres + - POSTGRES_DB=apollo + ports: + - 5432:5432 + volumes: + - data:/var/lib/postgresql/data \ No newline at end of file diff --git a/game/src/main/java/org/apollo/game/account/Account.java b/game/src/main/java/org/apollo/game/account/Account.java new file mode 100644 index 000000000..674e658f2 --- /dev/null +++ b/game/src/main/java/org/apollo/game/account/Account.java @@ -0,0 +1,42 @@ +package org.apollo.game.account; + +import org.apollo.game.model.entity.setting.PrivilegeLevel; + +/** + * An account of a user which the user's player characters are tied to. + * @author Sino + */ +public final class Account { + public static Account of(String email, String passwordHash, PrivilegeLevel rank) { + return new Account(email, passwordHash, rank); + } + + private final String email; + + private final String passwordHash; + + private final PrivilegeLevel rank; + + private Account(String email, String passwordHash, PrivilegeLevel rank) { + this.email = email; + this.passwordHash = passwordHash; + this.rank = rank; + } + + public String getEmail() { + return email; + } + + public String getPasswordHash() { + return passwordHash; + } + + public PrivilegeLevel getRank() { + return rank; + } + + @Override + public String toString() { + return "Account{email=" + email + ", passwordHash=" + passwordHash + ", rank=" + rank + "}"; + } +} diff --git a/game/src/main/java/org/apollo/game/io/player/JdbcPlayerSerializer.java b/game/src/main/java/org/apollo/game/io/player/JdbcPlayerSerializer.java index 4893aef0a..c0e46fb1a 100644 --- a/game/src/main/java/org/apollo/game/io/player/JdbcPlayerSerializer.java +++ b/game/src/main/java/org/apollo/game/io/player/JdbcPlayerSerializer.java @@ -1,33 +1,487 @@ package org.apollo.game.io.player; +import com.google.common.collect.ImmutableBiMap; +import com.google.common.collect.ImmutableList; +import com.google.common.collect.ImmutableMap; +import com.lambdaworks.crypto.SCryptUtil; +import org.apollo.game.account.Account; +import org.apollo.game.model.Appearance; +import org.apollo.game.model.Item; +import org.apollo.game.model.Position; import org.apollo.game.model.World; import org.apollo.game.model.entity.Player; +import org.apollo.game.model.entity.Skill; +import org.apollo.game.model.entity.SkillSet; +import org.apollo.game.model.entity.attr.*; +import org.apollo.game.model.entity.setting.Gender; +import org.apollo.game.model.entity.setting.PrivilegeLevel; +import org.apollo.game.model.inv.Inventory; +import org.apollo.game.model.inv.SlottedItem; +import org.apollo.net.codec.login.LoginConstants; import org.apollo.util.security.PlayerCredentials; +import javax.sql.DataSource; +import java.sql.*; +import java.time.LocalDateTime; +import java.util.Map; + +import static java.util.Objects.requireNonNull; +import static org.apollo.game.io.player.ApolloQueriesKt.*; + /** * A {@link PlayerSerializer} that utilises {@code JDBC} to communicate with an SQL database containing player data. * * @author Major + * @author Sino */ public final class JdbcPlayerSerializer extends PlayerSerializer { + /** + * Maps skill id to the enum value that is known by the database + * and back. + */ + private static final ImmutableBiMap SKILL_ENUMS = ImmutableBiMap.builder() + .put(Skill.ATTACK, "attack") + .put(Skill.STRENGTH, "strength") + .put(Skill.DEFENCE, "defence") + .put(Skill.HITPOINTS, "hitpoints") + .put(Skill.RANGED, "ranged") + .put(Skill.PRAYER, "prayer") + .put(Skill.MAGIC, "magic") + .put(Skill.COOKING, "cooking") + .put(Skill.FISHING, "fishing") + .put(Skill.WOODCUTTING, "woodcutting") + .put(Skill.FIREMAKING, "firemaking") + .put(Skill.FLETCHING, "fletching") + .put(Skill.FARMING, "farming") + .put(Skill.SLAYER, "slayer") + .put(Skill.AGILITY, "agility") + .put(Skill.CRAFTING, "crafting") + .put(Skill.HERBLORE, "herblore") + .put(Skill.THIEVING, "thieving") + .put(Skill.MINING, "mining") + .put(Skill.SMITHING, "smithing") + .put(Skill.RUNECRAFT, "runecraft") + .build(); + + /** + * Maps {@link PrivilegeLevel} to the enum value that is known by the + * database and back. + */ + private static final ImmutableBiMap RANK_ENUMS = ImmutableBiMap.builder() + .put(PrivilegeLevel.STANDARD, "player") + .put(PrivilegeLevel.MODERATOR, "moderator") + .put(PrivilegeLevel.ADMINISTRATOR, "administrator") + .build(); /** - * Creates the JdbcPlayerSerializer. + * Maps {@link AttributeType}s to the enum value that is known by the + * database and back. + */ + private static final ImmutableBiMap ATTRIBUTE_TYPE_ENUMS = ImmutableBiMap.builder() + .put(AttributeType.STRING, "string") + .put(AttributeType.BOOLEAN, "boolean") + .put(AttributeType.DOUBLE, "double") + .put(AttributeType.LONG, "long") + .build(); + + /** + * The associated queries that are ran by this serializer. + */ + private static final String + SET_ACCOUNT_QUERY = "CALL set_account(?::citext, ?::rank)", + SET_PLAYER_QUERY = "CALL set_player(?::citext, ?::text, ?, ?, ?, ?)", + SET_APPEARANCE_QUERY = "CALL set_appearance(?::text, ?::gender, ?, ?)", + SET_STAT_QUERY = "CALL set_stat(?::skill, ?, ?, ?::text)", + SET_ATTRIBUTE_QUERY = "CALL set_attribute(?::text, ?::attribute_type, ?::varchar, ?::text)", + SET_ITEM_QUERY = "CALL set_item(?::text, ?, ?, ?, ?)", + DELETE_ITEM_QUERY = "CALL delete_item(?::text, ?, ?)"; + + /** + * The config id's of known inventories. + */ + private static final int ITEM_BAG_ID = 93, + WORN_EQUIPMENT_ID = 94, + BANK_ID = 95; + + /** + * A factory method to construct a new {@link JdbcPlayerSerializer}. * - * @param world The {@link World} to place the {@link Player}s in. + * @param world The game world to feed to {@link Player} instances. + * @param dataSource The source to get information from and to put + * information into. + * @return The {@link JdbcPlayerSerializer}. */ - public JdbcPlayerSerializer(World world) { + public static JdbcPlayerSerializer create(World world, DataSource dataSource) { + return new JdbcPlayerSerializer(world, dataSource); + } + + /** + * The source to get information from and to put information into. + */ + private final DataSource dataSource; + + /** + * Creates the {@link JdbcPlayerSerializer}. + * + * @param world The {@link World} to place the {@link Player}s in. + * @param dataSource The source to get information from and to put information into. + */ + private JdbcPlayerSerializer(World world, DataSource dataSource) { super(world); + + this.dataSource = dataSource; } @Override public void savePlayer(Player player) throws Exception { - throw new UnsupportedOperationException("JDBC saving is not supported at this time."); + Connection connection = null; + Savepoint savepoint = null; + + try { + connection = dataSource.getConnection(); + connection.setAutoCommit(false); + + savepoint = connection.setSavepoint(); + + String email = player.getCredentials().getUsername(); + String displayName = player.getCredentials().getUsername(); + + putRank(connection, email, player.getPrivilegeLevel()); + putPlayer(connection, email, player); + putAppearance(connection, displayName, player.getAppearance()); + putStats(connection, displayName, player.getSkillSet()); + + putInventory(connection, displayName, ITEM_BAG_ID, player.getInventory()); + putInventory(connection, displayName, WORN_EQUIPMENT_ID, player.getEquipment()); + putInventory(connection, displayName, BANK_ID, player.getBank()); + + putAttributes(connection, displayName, player.getAttributes()); + + connection.commit(); + connection.setAutoCommit(true); + } catch (SQLException e) { + e.printStackTrace(); + connection.rollback(savepoint); + } + } + + private void putRank(Connection connection, String email, PrivilegeLevel rank) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(SET_ACCOUNT_QUERY)) { + stmt.setString(1, email); + stmt.setString(2, requireNonNull(RANK_ENUMS.get(rank))); + stmt.executeUpdate(); + } + } + + private void putPlayer(Connection connection, String email, Player player) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(SET_PLAYER_QUERY)) { + stmt.setString(1, email); + stmt.setString(2, player.getCredentials().getUsername()); + stmt.setTimestamp(3, Timestamp.valueOf(LocalDateTime.now())); + stmt.setInt(4, player.getPosition().getX()); + stmt.setInt(5, player.getPosition().getY()); + stmt.setInt(6, player.getPosition().getHeight()); + stmt.executeUpdate(); + } + } + + private void putAppearance(Connection connection, String displayName, Appearance appearance) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(SET_APPEARANCE_QUERY)) { + stmt.setString(1, displayName); + stmt.setString(2, appearance.getGender().name().toLowerCase()); + stmt.setObject(3, appearance.getStyle()); + stmt.setObject(4, appearance.getColors()); + stmt.execute(); + } + } + + private void putStats(Connection connection, String displayName, SkillSet skills) throws SQLException { + for (int i = 0; i < Skill.count(); i++) { + Skill skill = skills.getSkill(i); + + try (PreparedStatement stmt = connection.prepareStatement(SET_STAT_QUERY)) { + stmt.setString(1, requireNonNull(SKILL_ENUMS.get(i))); + stmt.setInt(2, skill.getCurrentLevel()); + stmt.setInt(3, (int) skill.getExperience()); + stmt.setString(4, displayName); + stmt.executeUpdate(); + } + } + } + + private void putAttributes(Connection connection, String displayName, Map> attributes) throws SQLException { + for (String key : attributes.keySet()) { + AttributeDefinition definition = AttributeMap.getDefinition(key); + if (definition.getPersistence() == AttributePersistence.TRANSIENT) { + continue; + } + + Attribute attribute = attributes.get(key); + + try (PreparedStatement stmt = connection.prepareStatement(SET_ATTRIBUTE_QUERY)) { + stmt.setString(1, displayName); + stmt.setString(2, requireNonNull(ATTRIBUTE_TYPE_ENUMS.get(attribute.getType()))); + stmt.setString(3, key); + stmt.setString(4, String.valueOf(attribute.getValue())); + stmt.execute(); + } + } + } + + private void putInventory(Connection connection, String displayName, int inventoryId, Inventory inventory) throws SQLException { + for (int i = 0; i < inventory.capacity(); i++) { + Item item = inventory.get(i); + if (item == null) { + deleteItem(connection, displayName, inventoryId, i); + } else { + putItem(connection, displayName, inventoryId, i, item); + } + } + } + + private void putItem(Connection connection, String displayName, int inventoryId, int slot, Item item) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(SET_ITEM_QUERY)) { + stmt.setString(1, displayName); + stmt.setInt(2, inventoryId); + stmt.setInt(3, slot); + stmt.setInt(4, item.getId()); + stmt.setInt(5, item.getAmount()); + stmt.execute(); + } + } + + private void deleteItem(Connection connection, String displayName, int inventoryId, int slot) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(DELETE_ITEM_QUERY)) { + stmt.setString(1, displayName); + stmt.setInt(2, inventoryId); + stmt.setInt(3, slot); + stmt.execute(); + } } @Override public PlayerLoaderResponse loadPlayer(PlayerCredentials credentials) throws Exception { - throw new UnsupportedOperationException("JDBC loading is not supported at this time."); + try (Connection connection = dataSource.getConnection()) { + Account account = getAccount(connection, credentials.getUsername()); + if (account == null) { + return new PlayerLoaderResponse(LoginConstants.STATUS_INVALID_CREDENTIALS); + } + + String passwordInput = credentials.getPassword(); + String passwordHash = account.getPasswordHash(); + + if (!SCryptUtil.check(passwordInput, passwordHash)) { + return new PlayerLoaderResponse(LoginConstants.STATUS_INVALID_CREDENTIALS); + } + + credentials.setPassword(passwordHash); + + Player player = getPlayer(connection, credentials); + if (player == null) { + return new PlayerLoaderResponse(LoginConstants.STATUS_COULD_NOT_COMPLETE); + } + + player.setPrivilegeLevel(account.getRank()); + player.setAppearance(requireNonNull(getAppearance(connection, credentials.getUsername()))); + + loadItemsIntoPlayer(connection, credentials.getUsername(), player); + loadStatsIntoPlayer(connection, credentials.getUsername(), player); + loadAttributesIntoPlayer(connection, credentials.getUsername(), player); + + return new PlayerLoaderResponse(LoginConstants.STATUS_OK, player); + } + } + + private void loadItemsIntoPlayer(Connection connection, String displayName, Player player) throws SQLException { + ImmutableList items = getItems(connection, displayName); + for (SlottedInventoryItem sii : items) { + Inventory inventory; + if (sii.getInventoryId() == ITEM_BAG_ID) { + inventory = player.getInventory(); + } else if (sii.getInventoryId() == WORN_EQUIPMENT_ID) { + inventory = player.getEquipment(); + } else if (sii.getInventoryId() == BANK_ID) { + inventory = player.getBank(); + } else { + // TODO add dynamic support for different types of inventories + // relying on inventory config id's + continue; + } + + inventory.stopFiringEvents(); + + try { + inventory.set(sii.getItem().getSlot(), sii.getItem().getItem()); + } finally { + inventory.startFiringEvents(); + } + } + } + + private void loadStatsIntoPlayer(Connection connection, String displayName, Player player) throws SQLException { + ImmutableList skills = getStats(connection, displayName); + + // TODO database currently supports hunter and construction as well and 317 doesn't + player.getSkillSet().stopFiringEvents(); + try { + for (int i = 0; i < Skill.count(); i++) { + player.getSkillSet().setSkill(i, skills.get(i)); + } + } finally { + player.getSkillSet().calculateCombatLevel(); + player.getSkillSet().startFiringEvents(); + } } + private void loadAttributesIntoPlayer(Connection connection, String displayName, Player player) throws SQLException { + ImmutableMap> attributes = getAttributes(connection, displayName); + for (String name : attributes.keySet()) { + player.setAttribute(name, attributes.get(name)); + } + } + + private Account getAccount(Connection connection, String email) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(GET_ACCOUNT_QUERY)) { + stmt.setString(1, email); + + ResultSet results = stmt.executeQuery(); + if (!results.next()) { + return null; + } + + String passwordHash = results.getString("password_hash"); + PrivilegeLevel rank = requireNonNull(RANK_ENUMS.inverse().get(results.getString("rank"))); + + return Account.of(email, passwordHash, rank); + } + } + + private Player getPlayer(Connection connection, PlayerCredentials credentials) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(GET_PLAYER_QUERY)) { + stmt.setString(1, credentials.getUsername()); + + ResultSet results = stmt.executeQuery(); + if (!results.next()) { + return null; + } + + Timestamp timestamp = results.getTimestamp("last_login"); + if (timestamp != null) { + // TODO convert + } + + int x = results.getShort("x"); + int y = results.getShort("y"); + int height = results.getShort("height"); + + Position position = new Position(x, y, height); + Player plr = new Player(world, credentials, position); + + return plr; + } + } + + private Appearance getAppearance(Connection connection, String displayName) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(GET_APPEARANCE_QUERY)) { + stmt.setString(1, displayName); + + ResultSet results = stmt.executeQuery(); + if (!results.next()) { + return null; + } + + Gender gender = Gender.MALE; + if ("woman".equals(results.getString("gender"))) { + gender = Gender.FEMALE; + } + + Short[] styleSet = (Short[]) results.getArray("styles").getArray(); + Short[] colourSet = (Short[]) results.getArray("colours").getArray(); + + int[] styles = new int[7]; + for (int i = 0; i < styles.length; i++) { + styles[i] = styleSet[i]; + } + + int[] colours = new int[5]; + for (int i = 0; i < colours.length; i++) { + colours[i] = colourSet[i]; + } + + return new Appearance(gender, styles, colours); + } + } + + private ImmutableList getStats(Connection connection, String displayName) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(GET_STATS_QUERY)) { + stmt.setString(1, displayName); + + ImmutableList.Builder bldr = ImmutableList.builder(); + + ResultSet results = stmt.executeQuery(); + while (results.next()) { + int stat = results.getInt("stat"); + int experience = results.getInt("experience"); + + bldr.add(new Skill(experience, stat, SkillSet.getLevelForExperience(experience))); + } + + return bldr.build(); + } + } + + private ImmutableMap> getAttributes(Connection connection, String displayName) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(GET_ATTRIBUTES_QUERY)) { + stmt.setString(1, displayName); + + ImmutableMap.Builder> bldr = ImmutableMap.builder(); + + ResultSet results = stmt.executeQuery(); + while (results.next()) { + AttributeType type = requireNonNull(ATTRIBUTE_TYPE_ENUMS.inverse().get(results.getString("attr_type"))); + + String name = results.getString("name"); + String value = results.getString("value"); + + Attribute attribute; + if (type == AttributeType.BOOLEAN) { + attribute = new BooleanAttribute(Boolean.parseBoolean(value)); + } else if (type == AttributeType.DOUBLE) { + attribute = new NumericalAttribute(Double.parseDouble(value)); + } else if (type == AttributeType.LONG) { + attribute = new NumericalAttribute(Long.parseLong(value)); + } else if (type == AttributeType.STRING) { + attribute = new StringAttribute(value); + } else { + throw new RuntimeException("Unsupported attribute type of " + type); + } + + bldr.put(name, attribute); + } + + return bldr.build(); + } + } + + private ImmutableList getItems(Connection connection, String displayName) throws SQLException { + try (PreparedStatement stmt = connection.prepareStatement(GET_ITEMS_QUERY)) { + stmt.setString(1, displayName); + + ImmutableList.Builder bldr = ImmutableList.builder(); + + ResultSet results = stmt.executeQuery(); + while (results.next()) { + int itemId = results.getInt("item_id"); + int inventoryId = results.getInt("inventory_id"); + + int slot = results.getInt("slot"); + int quantity = results.getInt("quantity"); + + Item item = new Item(itemId, quantity); + bldr.add(new SlottedInventoryItem(inventoryId, new SlottedItem(slot, item))); + } + + return bldr.build(); + } + } } \ No newline at end of file diff --git a/game/src/main/java/org/apollo/game/io/player/SlottedInventoryItem.java b/game/src/main/java/org/apollo/game/io/player/SlottedInventoryItem.java new file mode 100644 index 000000000..ef4f2718d --- /dev/null +++ b/game/src/main/java/org/apollo/game/io/player/SlottedInventoryItem.java @@ -0,0 +1,38 @@ +package org.apollo.game.io.player; + +import com.google.common.base.MoreObjects; +import org.apollo.game.model.inv.SlottedItem; + +/** + * A temporary-and intermediary data access object that holds information + * about an item inside a specific inventory's slot, to insert into a player's + * inventory. + * + * @author Sino + */ +final class SlottedInventoryItem { + private final int inventoryId; + + private final SlottedItem item; + + SlottedInventoryItem(int inventoryId, SlottedItem item) { + this.inventoryId = inventoryId; + this.item = item; + } + + int getInventoryId() { + return inventoryId; + } + + SlottedItem getItem() { + return item; + } + + @Override + public String toString() { + return MoreObjects.toStringHelper(this) + .add("inventoryId", inventoryId) + .add("item", item) + .toString(); + } +} diff --git a/game/src/main/java/org/apollo/game/model/entity/Player.java b/game/src/main/java/org/apollo/game/model/entity/Player.java index 76c06db95..4dd5eb6ac 100644 --- a/game/src/main/java/org/apollo/game/model/entity/Player.java +++ b/game/src/main/java/org/apollo/game/model/entity/Player.java @@ -468,8 +468,8 @@ public PrivilegeLevel getPrivilegeLevel() { * * @return The run energy. */ - public int getRunEnergy() { - Attribute energy = attributes.get("run_energy"); + public long getRunEnergy() { + Attribute energy = attributes.get("run_energy"); return energy.getValue(); } diff --git a/game/src/main/java/org/apollo/game/model/entity/Skill.java b/game/src/main/java/org/apollo/game/model/entity/Skill.java index a2a6fc9a1..6c6df3fba 100644 --- a/game/src/main/java/org/apollo/game/model/entity/Skill.java +++ b/game/src/main/java/org/apollo/game/model/entity/Skill.java @@ -129,6 +129,14 @@ public static String getName(int id) { return SKILL_NAMES[id]; } + /** + * Returns the amount of currently supported skill types. + * @return The amount of currently supported skill types. + */ + public static int count() { + return SKILL_NAMES.length; + } + /** * Whether the skill affects the combat level or not. * diff --git a/game/src/main/kotlin/org/apollo/game/io/player/ApolloQueries.kt b/game/src/main/kotlin/org/apollo/game/io/player/ApolloQueries.kt new file mode 100644 index 000000000..5c3c5b3a2 --- /dev/null +++ b/game/src/main/kotlin/org/apollo/game/io/player/ApolloQueries.kt @@ -0,0 +1,57 @@ +package org.apollo.game.io.player + +const val GET_ACCOUNT_QUERY = """ + SELECT a.password_hash, a.rank + FROM account AS a + WHERE a.email = ? + LIMIT 1; +""" + +const val GET_PLAYER_QUERY = """ + SELECT p.last_login, p.x, p.y, p.height + FROM player AS p + WHERE p.display_name = ? + LIMIT 1; +""" + +const val GET_APPEARANCE_QUERY = """ + SELECT a.gender, a.styles, a.colours + FROM appearance AS a + INNER JOIN player AS p + ON p.id = a.player_id + WHERE p.display_name = ? + LIMIT 1; +""" + +const val GET_ATTRIBUTES_QUERY = """ + SELECT a.attr_type, a.name, a.value + FROM attribute AS a + INNER JOIN player AS p + ON p.id = a.player_id + WHERE p.display_name = ?; +""" + +const val GET_STATS_QUERY = """ + SELECT s.skill, s.stat, s.experience + FROM stat AS s + INNER JOIN player AS p + ON p.id = s.player_id + WHERE p.display_name = ?; +""" + +const val GET_TITLE_QUERY = """ + SELECT t.left_part, t.center_part, t.right_part + FROM title AS t + INNER JOIN player AS p + ON p.id = t.player_id + WHERE p.display_name = ? + LIMIT 1; +""" + +const val GET_ITEMS_QUERY = """ + SELECT i.slot, i.item_id, i.quantity, i.inventory_id + FROM item AS i + INNER JOIN player AS p + ON p.id = i.player_id + WHERE p.display_name = ?; +""" \ No newline at end of file diff --git a/game/src/test/java/org/apollo/game/io/player/JdbcPlayerSerializerTest.java b/game/src/test/java/org/apollo/game/io/player/JdbcPlayerSerializerTest.java new file mode 100644 index 000000000..0c2e0972c --- /dev/null +++ b/game/src/test/java/org/apollo/game/io/player/JdbcPlayerSerializerTest.java @@ -0,0 +1,105 @@ +package org.apollo.game.io.player; + +import com.zaxxer.hikari.HikariConfig; +import com.zaxxer.hikari.HikariDataSource; +import org.apollo.game.model.Position; +import org.apollo.game.model.World; +import org.apollo.game.model.entity.Player; +import org.apollo.game.model.entity.attr.*; +import org.apollo.net.codec.login.LoginConstants; +import org.apollo.util.security.PlayerCredentials; +import org.junit.jupiter.api.BeforeAll; +import org.junit.jupiter.api.Test; + +import javax.sql.DataSource; + +import static org.apollo.game.model.entity.attr.AttributeMap.define; +import static org.junit.jupiter.api.Assertions.*; + +public final class JdbcPlayerSerializerTest { + private static HikariConfig config; + + @BeforeAll + public static void setup() { + String jdbcURL = System.getenv("POSTGRES_JDBC_URL"); + + assertNotNull(jdbcURL); + assertTrue(jdbcURL.length() > 0); + + config = new HikariConfig(); + config.setJdbcUrl(jdbcURL); + + define("my_double", new AttributeDefinition<>(0D, AttributePersistence.PERSISTENT, AttributeType.DOUBLE)); + define("my_long", new AttributeDefinition<>(0L, AttributePersistence.PERSISTENT, AttributeType.LONG)); + define("my_bool", new AttributeDefinition<>(false, AttributePersistence.PERSISTENT, AttributeType.BOOLEAN)); + define("my_string", new AttributeDefinition<>("", AttributePersistence.PERSISTENT, AttributeType.STRING)); + } + + @Test + public void serializerShouldDeserializeAPlayerFromTheDatabase() throws Exception { + World world = new World(); + + DataSource dataSource = new HikariDataSource(config); + JdbcPlayerSerializer serializer = JdbcPlayerSerializer.create(world, dataSource); + + PlayerCredentials credentials = new PlayerCredentials("Sino", "hello123", 0, 0, ""); + PlayerLoaderResponse response = serializer.loadPlayer(credentials); + + assertEquals(LoginConstants.STATUS_OK, response.getStatus()); + assertTrue(response.getPlayer().isPresent()); + } + + @Test + public void serializerShouldReturnInvalidCredentialsIfPasswordsMismatch() throws Exception { + World world = new World(); + + DataSource dataSource = new HikariDataSource(config); + JdbcPlayerSerializer serializer = JdbcPlayerSerializer.create(world, dataSource); + + PlayerCredentials credentials = new PlayerCredentials("Sino", "hello321", 0, 0, ""); + PlayerLoaderResponse response = serializer.loadPlayer(credentials); + + assertEquals(LoginConstants.STATUS_INVALID_CREDENTIALS, response.getStatus()); + assertFalse(response.getPlayer().isPresent()); + } + + @Test + public void serializerShouldReturnInvalidCredentialsIfAccountDoesntExistInTheDatabase() throws Exception { + World world = new World(); + + DataSource dataSource = new HikariDataSource(config); + JdbcPlayerSerializer serializer = JdbcPlayerSerializer.create(world, dataSource); + + PlayerCredentials credentials = new PlayerCredentials("Sini", "Hello123", 0, 0, ""); + PlayerLoaderResponse response = serializer.loadPlayer(credentials); + + assertEquals(LoginConstants.STATUS_INVALID_CREDENTIALS, response.getStatus()); + assertFalse(response.getPlayer().isPresent()); + } + + @Test + public void serializerShouldSerializeAPlayerIntoTheDatabase() throws Exception { + World world = new World(); + + DataSource dataSource = new HikariDataSource(config); + JdbcPlayerSerializer serializer = JdbcPlayerSerializer.create(world, dataSource); + + PlayerCredentials credentials = new PlayerCredentials("Sino", "hello123", 0, 0, ""); + Player player = new Player(world, credentials, new Position(3093, 3493, 0)); + + player.setAttribute("my_double", new NumericalAttribute(1.0D)); + player.setAttribute("my_long", new NumericalAttribute(500L)); + player.setAttribute("my_bool", new BooleanAttribute(true)); + player.setAttribute("my_string", new StringAttribute("Hello World")); + + serializer.savePlayer(player); + + PlayerLoaderResponse response = serializer.loadPlayer(credentials); + assertEquals(LoginConstants.STATUS_OK, response.getStatus()); + + Position pos = response.getPlayer().get().getPosition(); + assertEquals(player.getPosition().getX(), pos.getX()); + assertEquals(player.getPosition().getY(), pos.getY()); + assertEquals(player.getPosition().getHeight(), pos.getHeight()); + } +}