Skip to content

Commit

Permalink
misc: Change the schema a lot more
Browse files Browse the repository at this point in the history
  • Loading branch information
kyranet committed Jan 19, 2020
1 parent 332d8f8 commit 8c6cfad
Show file tree
Hide file tree
Showing 4 changed files with 70 additions and 47 deletions.
1 change: 1 addition & 0 deletions src/lib/queries/common.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@ export interface CommonQuery {
fetchStarsFromUser(guildID: string, userID: string, minimum: number): Promise<RawStarboardSettings[]>;
fetchTwitchStreamSubscription(streamerID: string): Promise<TwitchStreamSubscriptionSettings | null>;
fetchTwitchStreamsByGuild(guildID: string): Promise<TwitchStreamSubscriptionSettings[]>;
retrieveRandomItem(luck: number): Promise<RawRpgItem>;
insertCommandUseCounter(command: string): Promise<unknown>;
insertDashboardUser(entry: RawDashboardUserSettings): Promise<unknown>;
insertGiveaway(entry: RawGiveawaySettings): Promise<unknown>;
Expand Down
18 changes: 18 additions & 0 deletions src/lib/queries/json.ts
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ import { RawModerationSettings } from '@lib/types/settings/raw/RawModerationSett
import { RawStarboardSettings } from '@lib/types/settings/raw/RawStarboardSettings';
import { RawTwitchStreamSubscriptionSettings } from '@lib/types/settings/raw/RawTwitchStreamSubscriptionSettings';
import { RawUserSettings } from '@lib/types/settings/raw/RawUserSettings';
import { RawRpgItem } from '@lib/types/settings/raw/RawGameSettings';
import { JsonProvider } from '@lib/types/util';
import { Client } from 'discord.js';
import { CommonQuery, LeaderboardEntry, TwitchStreamSubscriptionSettings, UpdatePurgeTwitchStreamReturning, UpsertMemberSettingsReturningDifference } from './common';
Expand Down Expand Up @@ -233,6 +234,23 @@ export class JsonCommonQuery implements CommonQuery {
return values.filter(value => value.guild_ids.includes(guildID));
}

public async retrieveRandomItem(luck: number) {
const entries = (await this.provider.getAll(Databases.RpgItem) as RawRpgItem[])
.sort((a, b) => a.id - b.id);

const count = entries.reduce((acc, entry) => acc + Number(entry.rarity), 0);
const percentage = luck === 0 ? 1 : 1 / luck;
const maximum = Math.random() * count * percentage;

let counter = 0;
for (const entry of entries) {
counter += Number(entry.rarity);
if (counter >= maximum) return entry;
}

return entries[entries.length - 1];
}

public async insertCommandUseCounter(command: string) {
const value = await this.provider.get(Databases.CommandCounter, command) as { id: string; uses: number };
if (value) await this.provider.update(Databases.CommandCounter, command, { uses: value.uses + 1 });
Expand Down
19 changes: 19 additions & 0 deletions src/lib/queries/postgres.ts
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ import { RawTwitchStreamSubscriptionSettings } from '@lib/types/settings/raw/Raw
import { Client } from 'discord.js';
import PostgresProvider from 'src/providers/postgres';
import { CommonQuery, UpdatePurgeTwitchStreamReturning, UpsertMemberSettingsReturningDifference } from './common';
import { RawRpgItem } from '@lib/types/settings/raw/RawGameSettings';

export class PostgresCommonQuery implements CommonQuery {

Expand Down Expand Up @@ -371,6 +372,24 @@ export class PostgresCommonQuery implements CommonQuery {
}));
}

public retrieveRandomItem(luck: number) {
const { provider } = this;
const percentage = luck === 0 ? '' : ` * (1.0 / ${provider.cNumber(luck)})`;
return provider.runOne<RawRpgItem>(/* sql */`
WITH CTE AS (
SELECT RANDOM()${percentage} * (SELECT SUM(rarity) FROM rpg_item) R
)
SELECT "id", "name", "rarity"
FROM (
SELECT rpg_item.*, SUM(rarity) OVER (ORDER BY id) S, R
FROM rpg_item CROSS JOIN CTE
) Q
WHERE S >= R
ORDER BY id
LIMIT 1;
`);
}

public insertCommandUseCounter(command: string) {
return this.provider.run(/* sql */`
INSERT
Expand Down
79 changes: 32 additions & 47 deletions src/lib/types/settings/raw/RawGameSettings.ts
Original file line number Diff line number Diff line change
@@ -1,30 +1,23 @@
export interface RawRpgItemRank {
id: string;
rarity: number;
}

export interface RawRpgItem {
id: number;
name: string;
maximum_durability: string;
attack: number;
defense: number;
health: number;
attack_percentage: number;
defense_percentage: number;
health_percentage: number;
energy_usage: number;
range: number;
rank: string;
required_energy: number;
maximum_cooldown: number;
rarity: string;
effects: string[];
}

export interface RawRpgClass {
id: number;
name: string;
attack_multiplier: number;
defense_multiplier: number;
energy_multiplier: number;
luck_multiplier: number;
allowed_items: number[];
}

export interface RawRpgGuildRank {
Expand All @@ -49,76 +42,65 @@ export interface RawRpgUser {
id: string;
name: string;
win_count: string;
death_count: string;
guild_id: number;
guild_rank_id: number;
class_id: number;
items: string[];
death_count: string;
crate_common_count: number;
crate_uncommon_count: number;
crate_rare_count: number;
crate_legendary_count: number;
luck: number;
energy: string;
luck: string;
}

export interface RawRpgUserItem {
id: string;
user_id: string;
item_id: number;
durability: string;
cooldown: number;
}

export const SQL_TABLE_SCHEMA = /* sql */`
BEGIN;
CREATE TABLE IF NOT EXISTS rpg_item_ranks (
"id" VARCHAR(50),
"rarity" NUMERIC NOT NULL,
PRIMARY KEY ("id"),
CHECK ("id" <> ''),
CHECK ("rarity" >= 0)
);
CREATE TABLE IF NOT EXISTS rpg_item (
"id" SERIAL,
"name" VARCHAR(50) NOT NULL,
"maximum_durability" BIGINT NOT NULL,
"attack" NUMERIC DEFAULT 0.0 NOT NULL,
"defense" NUMERIC DEFAULT 0.0 NOT NULL,
"health" NUMERIC DEFAULT 0.0 NOT NULL,
"attack_percentage" NUMERIC DEFAULT 1.0 NOT NULL,
"defense_percentage" NUMERIC DEFAULT 1.0 NOT NULL,
"health_percentage" NUMERIC DEFAULT 1.0 NOT NULL,
"energy_usage" NUMERIC NOT NULL,
"range" NUMERIC NOT NULL,
"rank" VARCHAR(50) NOT NULL,
UNIQUE ("name", "rank"),
"name" VARCHAR(50) NOT NULL,
"maximum_durability" BIGINT NOT NULL,
"attack" FLOAT DEFAULT 0.0 NOT NULL,
"defense" FLOAT DEFAULT 0.0 NOT NULL,
"health" FLOAT DEFAULT 0.0 NOT NULL,
"required_energy" FLOAT DEFAULT 0.0 NOT NULL,
"maximum_cooldown" SMALLINT DEFAULT 0 NOT NULL,
"rarity" BIGINT NOT NULL,
"effects" VARCHAR(50) DEFAULT ARRAY[]::VARCHAR[] NOT NULL,
UNIQUE ("name", "rarity"),
PRIMARY KEY ("id"),
FOREIGN KEY ("rank") REFERENCES rpg_item_ranks ("id"),
CHECK ("name" <> ''),
CHECK ("maximum_durability" >= 0),
CHECK ("attack" >= 0),
CHECK ("defense" >= 0),
CHECK ("health" >= 0),
CHECK ("attack_percentage" >= 0),
CHECK ("defense_percentage" >= 0),
CHECK ("health_percentage" >= 0),
CHECK ("energy_usage" >= 0),
CHECK ("range" >= 0)
CHECK ("required_energy" >= 0),
CHECK ("maximum_cooldown" >= 0)
);
CREATE TABLE IF NOT EXISTS rpg_class (
"id" SERIAL,
"name" VARCHAR(20) NOT NULL,
"attack_multiplier" NUMERIC DEFAULT 1.0 NOT NULL,
"defense_multiplier" NUMERIC DEFAULT 1.0 NOT NULL,
"luck_multiplier" NUMERIC DEFAULT 1.0 NOT NULL,
"allowed_items" INTEGER[] DEFAULT ARRAY[]::INTEGER[] NOT NULL,
"name" VARCHAR(20) NOT NULL,
"attack_multiplier" FLOAT DEFAULT 1.0 NOT NULL,
"defense_multiplier" FLOAT DEFAULT 1.0 NOT NULL,
"energy_multiplier" FLOAT DEFAULT 1.0 NOT NULL,
"luck_multiplier" FLOAT DEFAULT 1.0 NOT NULL,
UNIQUE ("name"),
PRIMARY KEY ("id"),
CHECK ("name" <> ''),
CHECK ("attack_multiplier" >= 0),
CHECK ("defense_multiplier" >= 0),
CHECK ("energy_multiplier" >= 0),
CHECK ("luck_multiplier" >= 0)
);
Expand Down Expand Up @@ -155,15 +137,16 @@ export const SQL_TABLE_SCHEMA = /* sql */`
"id" VARCHAR(19) NOT NULL,
"name" VARCHAR(32) NOT NULL,
"win_count" BIGINT DEFAULT 0 NOT NULL,
"death_count" BIGINT DEFAULT 0 NOT NULL,
"guild_id" INTEGER,
"guild_rank_id" INTEGER,
"class_id" INTEGER,
"items" BIGINT[] DEFAULT ARRAY[]::BIGINT[] NOT NULL,
"death_count" BIGINT DEFAULT 0 NOT NULL,
"crate_common_count" INTEGER DEFAULT 0 NOT NULL,
"crate_uncommon_count" INTEGER DEFAULT 0 NOT NULL,
"crate_rare_count" INTEGER DEFAULT 0 NOT NULL,
"crate_legendary_count" INTEGER DEFAULT 0 NOT NULL,
"energy" BIGINT DEFAULT 0 NOT NULL,
"luck" NUMERIC DEFAULT 1.0 NOT NULL,
UNIQUE ("id"),
FOREIGN KEY ("id") REFERENCES users ("id") ON DELETE CASCADE,
Expand All @@ -176,17 +159,19 @@ export const SQL_TABLE_SCHEMA = /* sql */`
CHECK ("crate_uncommon_count" >= 0),
CHECK ("crate_rare_count" >= 0),
CHECK ("crate_legendary_count" >= 0),
CHECK ("energy" >= 0),
CHECK ("luck" >= 0)
);
ALTER TABLE rpg_guilds
ADD CONSTRAINT rpg_guilds_leaderx FOREIGN KEY ("leader") REFERENCES rpg_users ("id") ON DELETE CASCADE;
ADD FOREIGN KEY ("leader") REFERENCES rpg_users ("id") ON DELETE CASCADE;
CREATE TABLE IF NOT EXISTS rpg_user_items (
"id" BIGSERIAL,
"user_id" VARCHAR(19) NOT NULL,
"item_id" INTEGER NOT NULL,
"durability" BIGINT NOT NULL,
"cooldown" SMALLINT NOT NULL,
PRIMARY KEY ("id"),
FOREIGN KEY ("user_id") REFERENCES rpg_users ("id") ON DELETE CASCADE,
FOREIGN KEY ("item_id") REFERENCES rpg_item ("id") ON DELETE CASCADE,
Expand Down

0 comments on commit 8c6cfad

Please sign in to comment.