module Degenz.DbService open System open Npgsql open Npgsql.FSharp open Degenz let connStr = GuildEnvironment.connectionString type StatMod = { mod_type :string ; target_stat : string ; mod_amount : float } NpgsqlConnection.GlobalTypeMapper.MapComposite("stat_mod") |> ignore let readItem isRaffle (reader : RowReader) = let convertStatMod { mod_type = modType ; target_stat = targetStat; mod_amount = modAmount } = let fx = match modType with | "Min" -> Min (int modAmount) | "Max" -> Max (int modAmount) | "RateMultiplier" -> RateMultiplier (modAmount) | "Booster" -> Add (int modAmount) | _ -> Add (int modAmount) let ( _ , stat ) = StatId.TryParse(targetStat) { TargetStat = stat ; Effect = fx } { Item.Id = if isRaffle then reader.string "raffle_id" else reader.string "id" Item.Name = reader.string "name" Item.Description = reader.string "description" Item.IconUrl = reader.string "icon_url" Item.ImageUrl = reader.string "image_url" Item.Type = match reader.string "category" with | "Hack" -> ItemType.Hack | "Shield" -> ItemType.Shield | "Food" -> ItemType.Food | "Accessory" -> ItemType.Accessory | "Jpeg" -> ItemType.Jpeg | "Whitelist" -> ItemType.Whitelist | _ -> ItemType.Misc Item.Attributes = [ reader.intOrNone "buy_price" |> Option.map (fun a -> Buyable (a * 1)) reader.intOrNone "sell_price" |> Option.map (fun a -> Sellable (a * 1)) reader.intOrNone "rate_limit" |> Option.map (fun a -> RateLimitable (a * 1)) reader.intOrNone "expiration" |> Option.map (fun a -> Expireable (a * 1)) reader.floatOrNone "drop_chance" |> Option.map (float >> Droppable) reader.intOrNone "attack_power" |> Option.map Attackable reader.intOrNone "defense_power" |> Option.map Defendable reader.stringOrNone "class_name" |> Option.map Classable reader.intOrNone "max_stack" |> Option.map Stackable if reader.bool "can_trade" then Some Tradeable else None if reader.bool "can_consume" then Some Consumable else None (match reader.fieldValue "mods" with | [||] -> None | mods -> mods |> Array.map convertStatMod |> Array.toList |> Modifiable |> Some) ] |> List.choose id } let getPlayerInventory (did : uint64) = connStr |> Sql.connect |> Sql.parameters [ "did", Sql.string (string did) ] |> Sql.query """ SELECT ii.id,name,description,icon_url,image_url,category,buy_price,sell_price,rate_limit, expiration,drop_chance,can_trade,can_consume,attack_power,defense_power,class_name,max_stack,mods FROM inventory_item JOIN item ii on inventory_item.item_id = ii.id JOIN "user" usr on inventory_item.user_id = usr.id WHERE usr.discord_id = @did; """ |> Sql.executeAsync (readItem false) |> Async.AwaitTask let addToPlayerInventory (did : uint64) (item : Item) = connStr |> Sql.connect |> Sql.parameters [ ( "@did" , Sql.string (string did) ) ; ( "iid" , Sql.string item.Id )] |> Sql.query """ INSERT INTO inventory_item (item_id, user_id) VALUES (@iid, (SELECT id FROM "user" WHERE discord_id = @did)); """ |> Sql.executeNonQueryAsync |> Async.AwaitTask let removeFromPlayerInventory (did : uint64) (item : Item) = connStr |> Sql.connect |> Sql.parameters [ ( "@did" , Sql.string (string did) ) ; ( "iid" , Sql.string item.Id )] |> Sql.query """ DELETE FROM inventory_item WHERE item_id = @iid AND user_id = @did """ |> Sql.executeNonQueryAsync |> Async.AwaitTask let getStoreSymbol (storeId : string) = connStr |> Sql.connect |> Sql.parameters [ "sid", Sql.string storeId ] |> Sql.query """ SELECT store_id FROM store_item WHERE channel_id = @cid """ |> Sql.executeRowAsync (fun read -> read.string "id") |> Async.AwaitTask let getStoreItems (storeId : string) = connStr |> Sql.connect |> Sql.parameters [ "sid", Sql.string storeId ] |> Sql.query """ SELECT store_id,stock,available,limit_stock,i.id,name,description,icon_url,image_url,category,require_role,require_invites,sale_end,rank, buy_price,sell_price,rate_limit,expiration,drop_chance,can_trade,can_consume,attack_power,defense_power,class_name,max_stack,mods FROM store_item JOIN item i on store_item.item_id = i.id WHERE store_id = @sid AND store_item.unlisted = false """ |> Sql.executeAsync (fun reader -> { StoreId = reader.string "store_id" Stock = reader.int "stock" LimitStock = reader.bool "limit_stock" Available = reader.bool "available" Rank = reader.int "rank" SaleEnd = reader.int64OrNone "sale_end" TotalSold = None RequiresInvites = reader.intOrNone "require_invites" RequiresRole = reader.stringOrNone "require_role" |> Option.map uint64 StoreItem.Item = readItem false reader }) |> Async.AwaitTask let getAllActiveStoreItems () = connStr |> Sql.connect |> Sql.query """ SELECT store_id,stock,available,limit_stock,i.id,name,description,icon_url,image_url,category,require_role,require_invites,sale_end,rank, buy_price,sell_price,rate_limit,expiration,drop_chance,can_trade,can_consume,attack_power,defense_power,class_name,max_stack,mods FROM store_item JOIN item i on store_item.item_id = i.id WHERE store_item.unlisted = false """ |> Sql.executeAsync (fun reader -> { StoreId = reader.string "store_id" Stock = reader.int "stock" LimitStock = reader.bool "limit_stock" Available = reader.bool "available" Rank = reader.int "rank" SaleEnd = reader.int64OrNone "sale_end" TotalSold = None RequiresInvites = reader.intOrNone "require_invites" RequiresRole = reader.stringOrNone "require_role" |> Option.map uint64 StoreItem.Item = readItem false reader }) |> Async.AwaitTask let getRafflesWithPurchases storeId = connStr |> Sql.connect |> Sql.parameters [ "sid" , Sql.string storeId ] |> Sql.query """ WITH raffles AS (SELECT store_id,stock,available,limit_stock,i.id AS raffle_id,name,description,icon_url,image_url,category,require_role,require_invites,sale_end,rank, buy_price,sell_price,rate_limit,expiration,drop_chance,can_trade,can_consume,attack_power,defense_power,class_name,max_stack,mods FROM store_item JOIN item i on store_item.item_id = i.id WHERE store_id = @sid AND store_item.unlisted = false) SELECT * FROM raffles FULL JOIN (SELECT item_id, count(*) AS total FROM inventory_item WHERE item_id = ANY (SELECT raffle_id FROM raffles) GROUP BY item_id) total_raffles ON total_raffles.item_id = raffle_id; """ |> Sql.executeAsync (fun reader -> { StoreId = reader.string "store_id" Stock = reader.int "stock" LimitStock = reader.bool "limit_stock" Available = reader.bool "available" Rank = reader.int "rank" SaleEnd = reader.int64OrNone "sale_end" TotalSold = reader.intOrNone "total" RequiresInvites = reader.intOrNone "require_invites" RequiresRole = reader.stringOrNone "require_role" |> Option.map uint64 StoreItem.Item = readItem true reader }) |> Async.AwaitTask let getStoreItemBySymbol (itemSymbol : string) = connStr |> Sql.connect |> Sql.parameters [ "iid", Sql.string itemSymbol ] |> Sql.query """ SELECT store_id,stock,available,limit_stock,i.id,name,description,icon_url,image_url,category,require_role,require_invites,sale_end,rank, buy_price,sell_price,rate_limit,expiration,drop_chance,can_trade,can_consume,attack_power,defense_power,class_name,max_stack,mods FROM store_item JOIN item i on store_item.item_id = i.id WHERE item_id = @iid """ |> Sql.executeRowAsync (fun reader -> { StoreId = reader.string "store_id" Stock = reader.int "stock" LimitStock = reader.bool "limit_stock" Available = reader.bool "available" Rank = reader.int "rank" SaleEnd = reader.int64OrNone "sale_end" TotalSold = None RequiresInvites = reader.intOrNone "require_invites" RequiresRole = reader.stringOrNone "require_role" |> Option.map uint64 StoreItem.Item = readItem false reader }) |> Async.AwaitTask let decrementItemStock (item : Item) = async { try do! connStr |> Sql.connect |> Sql.parameters [ ( "iid" , Sql.string item.Id) ] |> Sql.query """ UPDATE store_item SET stock = GREATEST(stock - 1, 0) WHERE store_item.item_id = @iid """ |> Sql.executeNonQueryAsync |> Async.AwaitTask |> Async.Ignore return true with _ -> return false } let incrementItemStock (amount : int) symbol = connStr |> Sql.connect |> Sql.parameters [ ( "iid" , Sql.string symbol) ; ( "amount" , Sql.int (int amount)) ] |> Sql.query """ UPDATE store_item SET stock = stock + @amount WHERE store_item.item_id = @iid """ |> Sql.executeNonQueryAsync |> Async.AwaitTask |> Async.Ignore let setItemStock (amount : int) symbol = async { try do! connStr |> Sql.connect |> Sql.parameters [ ( "amount" , Sql.int (int amount) ) ; ( "iid" , Sql.string symbol ) ] |> Sql.query """ UPDATE store_item SET stock = @amount WHERE store_item.item_id = (SELECT id FROM item WHERE id = @iid) """ |> Sql.executeNonQueryAsync |> Async.AwaitTask |> Async.Ignore return true with _ -> return false } let getWeapons () = connStr |> Sql.connect |> Sql.query """ SELECT id,name,description,icon_url,image_url,category,buy_price,sell_price,rate_limit,expiration, drop_chance,can_trade,can_consume,attack_power,defense_power,class_name,max_stack,mods FROM item WHERE category = 'Hack' OR category = 'Shield' """ |> Sql.executeAsync (readItem false) |> Async.AwaitTask let consumeItem (did : uint64) (item : Item) = connStr |> Sql.connect |> Sql.parameters [ ( "@did" , Sql.string (string did) ) ; ( "iid" , Sql.string item.Id )] |> Sql.query """ DELETE FROM inventory_item WHERE id IN (SELECT id FROM inventory_item WHERE user_id = (SELECT id FROM "user" WHERE discord_id = @did) AND item_id = @iid LIMIT 1) """ |> Sql.executeNonQueryAsync |> Async.AwaitTask let getPlayerEvents (did : uint64) = connStr |> Sql.connect |> Sql.parameters [ "did", Sql.string (string did) ] |> Sql.query """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) SELECT event_type, success, is_instigator, item_id, cooldown, adversary_id, adversary_name, created_at FROM player_event ,usr WHERE user_id = usr.id and created_at > NOW() at time zone 'utc' - INTERVAL '24 HOURS'; """ |> Sql.executeAsync (fun read -> match read.string "event_type" with | "Hacking" -> Hacking { IsInstigator = read.bool "is_instigator" Success = read.bool "success" Adversary = { Id = read.string "adversary_id" |> uint64 ; Name = read.string "adversary_name" } HackId = read.string "item_id" } | "Shielding" -> Shielding (read.string "item_id") | "Stealing" -> Stealing ( read.bool "is_instigator" , { Id = read.string "adversary_id" |> uint64 ; Name = read.string "adversary_name" } ) | "PlayingSlot" -> PlayingSlot | _ -> Imprison |> fun t -> let date = read.dateTimeOrNone "created_at" |> Option.defaultValue DateTime.UtcNow { Type = t ; Cooldown = read.int "cooldown" * 1 ; Timestamp = date } ) |> Async.AwaitTask let tryFindPlayer (discordId : uint64) = async { try let! user = connStr |> Sql.connect |> Sql.parameters [ "did", Sql.string (string discordId) ] |> Sql.query """ SELECT discord_id, display_name, gbt, in_game, strength, focus, charisma, luck FROM "user" WHERE discord_id = @did """ |> Sql.executeAsync (fun read -> {| DiscordId = read.string "discord_id" |> uint64 Name = read.string "display_name" Bank = read.intOrNone "gbt" |> Option.map ((*) 1) |> Option.defaultValue 0 Strength = read.intOrNone "strength" |> Option.defaultValue 0 Focus = read.intOrNone "focus" |> Option.defaultValue 0 Charisma = read.intOrNone "charisma" |> Option.defaultValue 0 Luck = read.intOrNone "luck" |> Option.defaultValue 0 Active = read.bool "in_game" |}) |> Async.AwaitTask match List.tryHead user with | None -> return None | Some u -> let! events = getPlayerEvents u.DiscordId let! inventory = getPlayerInventory discordId let strength = PlayerStats.calculateActiveStat StatId.Strength u.Strength inventory let focus = PlayerStats.calculateActiveStat StatId.Focus u.Focus inventory let charisma = PlayerStats.calculateActiveStat StatId.Charisma u.Charisma inventory let luck = PlayerStats.calculateActiveStat StatId.Luck u.Luck inventory return Some { DiscordId = u.DiscordId Name = u.Name Inventory = inventory Events = events Stats = { Strength = strength ; Focus = focus ; Charisma = charisma ; Luck = luck } Bank = u.Bank Active = u.Active } with e -> printfn $"Got an error{e.Message}" return None } let updatePlayerCurrency (addAmount : int) (did : uint64) = connStr |> Sql.connect |> Sql.parameters [ "did", Sql.string (string did) "gbt", Sql.int (int addAmount) ] |> Sql.query """ UPDATE "user" SET gbt = GREATEST(gbt + @gbt, 0) WHERE discord_id = @did; """ |> Sql.executeNonQueryAsync |> Async.AwaitTask let addAchievement (did : uint64) (achievement : string) = connStr |> Sql.connect |> Sql.parameters [ ( "did" , Sql.string (string did) ) ( "symbol", Sql.string achievement ) ] |> Sql.query """ WITH ach AS (SELECT id FROM achievement WHERE id = @symbol), usr AS (SELECT id FROM "user" WHERE id = @did) INSERT INTO user_achievements_achievement (user_id, achievement_id) SELECT usr.id, ach.id FROM usr, ach; """ |> Sql.executeNonQueryAsync |> Async.AwaitTask let checkHasAchievement (did : uint64) (achievement : string) = async { let! result = connStr |> Sql.connect |> Sql.parameters [ ( "did" , Sql.string (string did) ) ( "symbol", Sql.string achievement ) ] |> Sql.query """ SELECT achievement_id FROM user_achievements_achievement WHERE user_id = @did AND achievement_id = @symbol; """ |> Sql.executeAsync (fun read -> read.string "achievement_id") |> Async.AwaitTask return List.isEmpty result |> not } let removeShieldEvent (did : uint64) shieldId = connStr |> Sql.connect |> Sql.parameters [ ( "did" , Sql.string (string did) ) ( "shield_id", Sql.string shieldId ) ] |> Sql.query """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) DELETE FROM player_event USING usr WHERE user_id = usr.id and event_type = 'Shielding' and item_id = @shield_id """ |> Sql.executeNonQueryAsync |> Async.AwaitTask let addPlayerEvent (did : uint64) (playerEvent : PlayerEvent) = let sqlParams , query = match playerEvent.Type with | Hacking h -> [ ( "did", Sql.string (string did) ) ( "success" , Sql.bool h.Success ) ( "is_instigator", Sql.bool h.IsInstigator ) ( "item_id", Sql.string h.HackId ) ( "cooldown", Sql.int (int playerEvent.Cooldown) ) ( "adversary_id", Sql.string (string h.Adversary.Id) ) ( "adversary_name", Sql.string (string h.Adversary.Name) ) ] , """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) INSERT INTO player_event (event_type, success, is_instigator, item_id, cooldown, adversary_id, adversary_name, user_id) SELECT 'Hacking', @success, @is_instigator, @item_id, @cooldown, @adversary_id, @adversary_name, usr.id FROM usr """ | Shielding id -> [ ( "did" , Sql.string (string did) ) ( "item_id", Sql.string id ) ( "cooldown", Sql.int (int playerEvent.Cooldown) ) ] , """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) INSERT INTO player_event (event_type, item_id, cooldown, user_id) SELECT 'Shielding', @item_id, @cooldown, usr.id FROM usr """ | Stealing(instigator, victim) -> [ ( "did" , Sql.string (string did) ) ( "is_instigator", Sql.bool instigator ) ( "adversary_id", Sql.string (string victim.Id) ) ( "adversary_name", Sql.string (string victim.Name) ) ( "cooldown", Sql.int (int playerEvent.Cooldown) ) ] , """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) INSERT INTO player_event (event_type, is_instigator, adversary_id, adversary_name, cooldown, user_id) SELECT 'Stealing', @is_instigator, @adversary_id, @adversary_name, @cooldown, usr.id FROM usr """ | PlayingSlot -> [ ( "did" , Sql.string (string did) ) ] , """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) INSERT INTO player_event (event_type, cooldown, user_id) SELECT 'PlayingSlot', 1, usr.id FROM usr """ | Imprison -> [ ( "did" , Sql.string (string did) ) ( "cooldown", Sql.int (int playerEvent.Cooldown) ) ] , """ WITH usr AS (SELECT id FROM "user" WHERE discord_id = @did) INSERT INTO player_event (event_type, cooldown, user_id) SELECT 'Imprison', @cooldown, usr.id FROM usr """ connStr |> Sql.connect |> Sql.parameters sqlParams |> Sql.query query |> Sql.executeNonQueryAsync |> Async.AwaitTask let getRandomHackablePlayers (did : uint64) = connStr |> Sql.connect |> Sql.parameters [ "did", Sql.string (string did) ] |> Sql.query """ SELECT discord_id, display_name FROM "user" WHERE "user".in_game = true AND gbt > 0 AND "user".discord_id != @did ORDER BY random() LIMIT 10 """ |> Sql.executeAsync (fun read -> {| Id = read.string "discord_id" |> uint64 ; Name = read.string "display_name" |}) |> Async.AwaitTask