Porting database from SQLite to PostgreSQL

- New Postgres table schemas
- Using Stored Procedures with transactions that validate business logic
- User Ids now use UUID
- Updated and simplified all endpoints to call the stored procedures

Notes: There are still a few things missing that broke because of the migration,
in particular, because we moved a lot of the business logic into the database,
we now require that certain data that lived in the game-config.json to be
present in the database as well, to prevent cheating and truly have a single
source of truth.
This commit is contained in:
Joseph Ferano 2023-03-30 14:13:30 +07:00
parent 63a92b90da
commit 9b753cf103
33 changed files with 1283 additions and 405 deletions

2
.gitignore vendored
View File

@ -39,3 +39,5 @@ next-env.d.ts
.vscode
database.db
.env
/sql/create-users.sql

View File

@ -12,6 +12,18 @@ yarn dev
pnpm dev
```
## Dotenv
Fill the following out:
```dotenv
DB_USER=
DB_PASSWORD=
DB_HOST=
DB_PORT=
DB_DATABASE=
```
## API Endpoints
POST `/user/login` check if user exists

View File

@ -1,6 +1,9 @@
{
"resources": ["Sollux", "Shadowstone", "Azurium", "Novafor", "Nebulance"],
"moons": {
"name": "Caelusium",
"description" : "Caelusium is a medium-sized moon with a diverse landscape. Its craters contain a wealth of common resources, making it an ideal starting location for beginners. The moon's relatively mild weather conditions and stable surface offer a friendly environment for establishing mining operations.",
"image": "moon_1.jpg",
"price": 100,
"resourceChance": 1.0,
"resourceMinStartAmount": 50,
@ -19,11 +22,11 @@
"claimAmount": 10,
"completionTimeInMins": 1,
"upgrades": [
{ "tier": 1, "price": 200, "claimBoost": 10 },
{ "tier": 2, "price": 300, "claimBoost": 20 },
{ "tier": 3, "price": 400, "claimBoost": 30 },
{ "tier": 4, "price": 500, "claimBoost": 40 },
{ "tier": 5, "price": 600, "claimBoost": 50 }
{ "tier": 1, "price": 50, "claimBoost": 10 },
{ "tier": 2, "price": 75, "claimBoost": 20 },
{ "tier": 3, "price": 100, "claimBoost": 30 },
{ "tier": 4, "price": 125, "claimBoost": 40 },
{ "tier": 5, "price": 150, "claimBoost": 50 }
]
},
{
@ -31,7 +34,7 @@
"name": "Lunar Regolith Extractor LRE-3000",
"description": "The LRE-3000 is a high-efficiency drill designed for extracting regolith, the lunar soil composed of small rocks, dust, and other materials. This drill utilizes a unique auger system to bore into the moon's surface and collect regolith for further processing, ensuring minimal waste and maximum resource extraction.",
"image": "/assets/drill_2.jpg",
"price": 400,
"price": 100,
"claimAmount": 75,
"completionTimeInMins": 5,
"upgrades": [
@ -47,7 +50,7 @@
"name": "Electrostatic Dust Excavator EDE-700",
"description": "The EDE-700 is a specialized excavator designed to collect fine lunar dust, which is rich in valuable elements such as helium-3, a potential fuel for future fusion reactors. The machine uses an electrostatic system to attract and capture dust particles, allowing for efficient collection and reduced risk of hazardous dust exposure for operators.",
"image": "/assets/drill_3.jpg",
"price": 1000,
"price": 500,
"claimAmount": 100,
"completionTimeInMins": 30,
"upgrades": [

9
db.ts
View File

@ -1,7 +1,16 @@
import sqlite3 from "sqlite3";
import { open } from "sqlite";
import { Pool } from "pg";
export const dbConnection = open({
filename: "database.db",
driver: sqlite3.Database,
});
export const postgresConnection = new Pool({
user: process.env.DB_USER,
password: process.env.DB_PASSWORD,
host: process.env.DB_HOST,
port: +process.env.DB_PORT!,
database: process.env.DB_DATABASE,
});

266
package-lock.json generated
View File

@ -16,13 +16,16 @@
"eslint": "8.33.0",
"eslint-config-next": "13.1.6",
"next": "13.1.6",
"pg": "^8.10.0",
"react": "18.2.0",
"react-dom": "18.2.0",
"react-icons": "^4.8.0",
"sqlite": "^4.1.2",
"sqlite3": "^5.1.4",
"typescript": "4.9.5"
},
"devDependencies": {
"@types/pg": "^8.6.6",
"autoprefixer": "^10.4.13",
"postcss": "^8.4.21",
"tailwindcss": "^3.2.6"
@ -534,6 +537,17 @@
"resolved": "https://registry.npmjs.org/@types/node/-/node-18.13.0.tgz",
"integrity": "sha512-gC3TazRzGoOnoKAhUx+Q0t8S9Tzs74z7m0ipwGpSqQrleP14hKxP4/JUeEQcD3W1/aIpnWl8pHowI7WokuZpXg=="
},
"node_modules/@types/pg": {
"version": "8.6.6",
"resolved": "https://registry.npmjs.org/@types/pg/-/pg-8.6.6.tgz",
"integrity": "sha512-O2xNmXebtwVekJDD+02udOncjVcMZQuTEQEMpKJ0ZRf5E7/9JJX3izhKUcUifBkyKpljyUM6BTgy2trmviKlpw==",
"dev": true,
"dependencies": {
"@types/node": "*",
"pg-protocol": "*",
"pg-types": "^2.2.0"
}
},
"node_modules/@types/prop-types": {
"version": "15.7.5",
"resolved": "https://registry.npmjs.org/@types/prop-types/-/prop-types-15.7.5.tgz",
@ -1137,6 +1151,14 @@
"ieee754": "^1.2.1"
}
},
"node_modules/buffer-writer": {
"version": "2.0.0",
"resolved": "https://registry.npmjs.org/buffer-writer/-/buffer-writer-2.0.0.tgz",
"integrity": "sha512-a7ZpuTZU1TRtnwyCNW3I5dc0wWNC3VR9S++Ewyk2HHZdrO3CQJqSpd+95Us590V6AL7JqUAH2IwZ/398PmNFgw==",
"engines": {
"node": ">=4"
}
},
"node_modules/bufferutil": {
"version": "4.0.7",
"resolved": "https://registry.npmjs.org/bufferutil/-/bufferutil-4.0.7.tgz",
@ -3943,6 +3965,11 @@
"url": "https://github.com/sponsors/sindresorhus"
}
},
"node_modules/packet-reader": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/packet-reader/-/packet-reader-1.0.0.tgz",
"integrity": "sha512-HAKu/fG3HpHFO0AA8WE8q2g+gBJaZ9MG7fcKk+IJPLTGAD6Psw4443l+9DGRbOIh3/aXr7Phy0TjilYivJo5XQ=="
},
"node_modules/parent-module": {
"version": "1.0.1",
"resolved": "https://registry.npmjs.org/parent-module/-/parent-module-1.0.1.tgz",
@ -3991,6 +4018,80 @@
"node": ">=8"
}
},
"node_modules/pg": {
"version": "8.10.0",
"resolved": "https://registry.npmjs.org/pg/-/pg-8.10.0.tgz",
"integrity": "sha512-ke7o7qSTMb47iwzOSaZMfeR7xToFdkE71ifIipOAAaLIM0DYzfOAXlgFFmYUIE2BcJtvnVlGCID84ZzCegE8CQ==",
"dependencies": {
"buffer-writer": "2.0.0",
"packet-reader": "1.0.0",
"pg-connection-string": "^2.5.0",
"pg-pool": "^3.6.0",
"pg-protocol": "^1.6.0",
"pg-types": "^2.1.0",
"pgpass": "1.x"
},
"engines": {
"node": ">= 8.0.0"
},
"peerDependencies": {
"pg-native": ">=3.0.1"
},
"peerDependenciesMeta": {
"pg-native": {
"optional": true
}
}
},
"node_modules/pg-connection-string": {
"version": "2.5.0",
"resolved": "https://registry.npmjs.org/pg-connection-string/-/pg-connection-string-2.5.0.tgz",
"integrity": "sha512-r5o/V/ORTA6TmUnyWZR9nCj1klXCO2CEKNRlVuJptZe85QuhFayC7WeMic7ndayT5IRIR0S0xFxFi2ousartlQ=="
},
"node_modules/pg-int8": {
"version": "1.0.1",
"resolved": "https://registry.npmjs.org/pg-int8/-/pg-int8-1.0.1.tgz",
"integrity": "sha512-WCtabS6t3c8SkpDBUlb1kjOs7l66xsGdKpIPZsg4wR+B3+u9UAum2odSsF9tnvxg80h4ZxLWMy4pRjOsFIqQpw==",
"engines": {
"node": ">=4.0.0"
}
},
"node_modules/pg-pool": {
"version": "3.6.0",
"resolved": "https://registry.npmjs.org/pg-pool/-/pg-pool-3.6.0.tgz",
"integrity": "sha512-clFRf2ksqd+F497kWFyM21tMjeikn60oGDmqMT8UBrynEwVEX/5R5xd2sdvdo1cZCFlguORNpVuqxIj+aK4cfQ==",
"peerDependencies": {
"pg": ">=8.0"
}
},
"node_modules/pg-protocol": {
"version": "1.6.0",
"resolved": "https://registry.npmjs.org/pg-protocol/-/pg-protocol-1.6.0.tgz",
"integrity": "sha512-M+PDm637OY5WM307051+bsDia5Xej6d9IR4GwJse1qA1DIhiKlksvrneZOYQq42OM+spubpcNYEo2FcKQrDk+Q=="
},
"node_modules/pg-types": {
"version": "2.2.0",
"resolved": "https://registry.npmjs.org/pg-types/-/pg-types-2.2.0.tgz",
"integrity": "sha512-qTAAlrEsl8s4OiEQY69wDvcMIdQN6wdz5ojQiOy6YRMuynxenON0O5oCpJI6lshc6scgAY8qvJ2On/p+CXY0GA==",
"dependencies": {
"pg-int8": "1.0.1",
"postgres-array": "~2.0.0",
"postgres-bytea": "~1.0.0",
"postgres-date": "~1.0.4",
"postgres-interval": "^1.1.0"
},
"engines": {
"node": ">=4"
}
},
"node_modules/pgpass": {
"version": "1.0.5",
"resolved": "https://registry.npmjs.org/pgpass/-/pgpass-1.0.5.tgz",
"integrity": "sha512-FdW9r/jQZhSeohs1Z3sI1yxFQNFvMcnmfuj4WBMUTxOrAyLMaTcE1aAMBiTlbMNaXvBCQuVi0R7hd8udDSP7ug==",
"dependencies": {
"split2": "^4.1.0"
}
},
"node_modules/picocolors": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/picocolors/-/picocolors-1.0.0.tgz",
@ -4143,6 +4244,41 @@
"integrity": "sha512-1NNCs6uurfkVbeXG4S8JFT9t19m45ICnif8zWLd5oPSZ50QnwMfK+H3jv408d4jw/7Bttv5axS5IiHoLaVNHeQ==",
"dev": true
},
"node_modules/postgres-array": {
"version": "2.0.0",
"resolved": "https://registry.npmjs.org/postgres-array/-/postgres-array-2.0.0.tgz",
"integrity": "sha512-VpZrUqU5A69eQyW2c5CA1jtLecCsN2U/bD6VilrFDWq5+5UIEVO7nazS3TEcHf1zuPYO/sqGvUvW62g86RXZuA==",
"engines": {
"node": ">=4"
}
},
"node_modules/postgres-bytea": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/postgres-bytea/-/postgres-bytea-1.0.0.tgz",
"integrity": "sha512-xy3pmLuQqRBZBXDULy7KbaitYqLcmxigw14Q5sj8QBVLqEwXfeybIKVWiqAXTlcvdvb0+xkOtDbfQMOf4lST1w==",
"engines": {
"node": ">=0.10.0"
}
},
"node_modules/postgres-date": {
"version": "1.0.7",
"resolved": "https://registry.npmjs.org/postgres-date/-/postgres-date-1.0.7.tgz",
"integrity": "sha512-suDmjLVQg78nMK2UZ454hAG+OAW+HQPZ6n++TNDUX+L0+uUlLywnoxJKDou51Zm+zTCjrCl0Nq6J9C5hP9vK/Q==",
"engines": {
"node": ">=0.10.0"
}
},
"node_modules/postgres-interval": {
"version": "1.2.0",
"resolved": "https://registry.npmjs.org/postgres-interval/-/postgres-interval-1.2.0.tgz",
"integrity": "sha512-9ZhXKM/rw350N1ovuWHbGxnGh/SNJ4cnxHiM0rxE4VN41wsg8P8zWn9hv/buK00RP4WvlOyr/RBDiptyxVbkZQ==",
"dependencies": {
"xtend": "^4.0.0"
},
"engines": {
"node": ">=0.10.0"
}
},
"node_modules/prelude-ls": {
"version": "1.2.1",
"resolved": "https://registry.npmjs.org/prelude-ls/-/prelude-ls-1.2.1.tgz",
@ -4242,6 +4378,14 @@
"react": "^18.2.0"
}
},
"node_modules/react-icons": {
"version": "4.8.0",
"resolved": "https://registry.npmjs.org/react-icons/-/react-icons-4.8.0.tgz",
"integrity": "sha512-N6+kOLcihDiAnj5Czu637waJqSnwlMNROzVZMhfX68V/9bu9qHaMIJC4UdozWoOk57gahFCNHwVvWzm0MTzRjg==",
"peerDependencies": {
"react": "*"
}
},
"node_modules/react-is": {
"version": "16.13.1",
"resolved": "https://registry.npmjs.org/react-is/-/react-is-16.13.1.tgz",
@ -4586,6 +4730,14 @@
"node": ">=0.10.0"
}
},
"node_modules/split2": {
"version": "4.1.0",
"resolved": "https://registry.npmjs.org/split2/-/split2-4.1.0.tgz",
"integrity": "sha512-VBiJxFkxiXRlUIeyMQi8s4hgvKCSjtknJv/LVYbrgALPwf5zSKmEwV9Lst25AkvMDnvxODugjdl6KZgwKM1WYQ==",
"engines": {
"node": ">= 10.x"
}
},
"node_modules/sqlite": {
"version": "4.1.2",
"resolved": "https://registry.npmjs.org/sqlite/-/sqlite-4.1.2.tgz",
@ -5208,7 +5360,6 @@
"version": "4.0.2",
"resolved": "https://registry.npmjs.org/xtend/-/xtend-4.0.2.tgz",
"integrity": "sha512-LKYU1iAXJXUgAXn9URjiu+MWhyUXHsvfp7mcuYm9dSUKK0/CjtrUwFAxD82/mCWbtLsGjFIad0wIsod4zrTAEQ==",
"dev": true,
"engines": {
"node": ">=0.4"
}
@ -5552,6 +5703,17 @@
"resolved": "https://registry.npmjs.org/@types/node/-/node-18.13.0.tgz",
"integrity": "sha512-gC3TazRzGoOnoKAhUx+Q0t8S9Tzs74z7m0ipwGpSqQrleP14hKxP4/JUeEQcD3W1/aIpnWl8pHowI7WokuZpXg=="
},
"@types/pg": {
"version": "8.6.6",
"resolved": "https://registry.npmjs.org/@types/pg/-/pg-8.6.6.tgz",
"integrity": "sha512-O2xNmXebtwVekJDD+02udOncjVcMZQuTEQEMpKJ0ZRf5E7/9JJX3izhKUcUifBkyKpljyUM6BTgy2trmviKlpw==",
"dev": true,
"requires": {
"@types/node": "*",
"pg-protocol": "*",
"pg-types": "^2.2.0"
}
},
"@types/prop-types": {
"version": "15.7.5",
"resolved": "https://registry.npmjs.org/@types/prop-types/-/prop-types-15.7.5.tgz",
@ -5961,6 +6123,11 @@
"ieee754": "^1.2.1"
}
},
"buffer-writer": {
"version": "2.0.0",
"resolved": "https://registry.npmjs.org/buffer-writer/-/buffer-writer-2.0.0.tgz",
"integrity": "sha512-a7ZpuTZU1TRtnwyCNW3I5dc0wWNC3VR9S++Ewyk2HHZdrO3CQJqSpd+95Us590V6AL7JqUAH2IwZ/398PmNFgw=="
},
"bufferutil": {
"version": "4.0.7",
"resolved": "https://registry.npmjs.org/bufferutil/-/bufferutil-4.0.7.tgz",
@ -7974,6 +8141,11 @@
"aggregate-error": "^3.0.0"
}
},
"packet-reader": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/packet-reader/-/packet-reader-1.0.0.tgz",
"integrity": "sha512-HAKu/fG3HpHFO0AA8WE8q2g+gBJaZ9MG7fcKk+IJPLTGAD6Psw4443l+9DGRbOIh3/aXr7Phy0TjilYivJo5XQ=="
},
"parent-module": {
"version": "1.0.1",
"resolved": "https://registry.npmjs.org/parent-module/-/parent-module-1.0.1.tgz",
@ -8007,6 +8179,61 @@
"resolved": "https://registry.npmjs.org/path-type/-/path-type-4.0.0.tgz",
"integrity": "sha512-gDKb8aZMDeD/tZWs9P6+q0J9Mwkdl6xMV8TjnGP3qJVJ06bdMgkbBlLU8IdfOsIsFz2BW1rNVT3XuNEl8zPAvw=="
},
"pg": {
"version": "8.10.0",
"resolved": "https://registry.npmjs.org/pg/-/pg-8.10.0.tgz",
"integrity": "sha512-ke7o7qSTMb47iwzOSaZMfeR7xToFdkE71ifIipOAAaLIM0DYzfOAXlgFFmYUIE2BcJtvnVlGCID84ZzCegE8CQ==",
"requires": {
"buffer-writer": "2.0.0",
"packet-reader": "1.0.0",
"pg-connection-string": "^2.5.0",
"pg-pool": "^3.6.0",
"pg-protocol": "^1.6.0",
"pg-types": "^2.1.0",
"pgpass": "1.x"
}
},
"pg-connection-string": {
"version": "2.5.0",
"resolved": "https://registry.npmjs.org/pg-connection-string/-/pg-connection-string-2.5.0.tgz",
"integrity": "sha512-r5o/V/ORTA6TmUnyWZR9nCj1klXCO2CEKNRlVuJptZe85QuhFayC7WeMic7ndayT5IRIR0S0xFxFi2ousartlQ=="
},
"pg-int8": {
"version": "1.0.1",
"resolved": "https://registry.npmjs.org/pg-int8/-/pg-int8-1.0.1.tgz",
"integrity": "sha512-WCtabS6t3c8SkpDBUlb1kjOs7l66xsGdKpIPZsg4wR+B3+u9UAum2odSsF9tnvxg80h4ZxLWMy4pRjOsFIqQpw=="
},
"pg-pool": {
"version": "3.6.0",
"resolved": "https://registry.npmjs.org/pg-pool/-/pg-pool-3.6.0.tgz",
"integrity": "sha512-clFRf2ksqd+F497kWFyM21tMjeikn60oGDmqMT8UBrynEwVEX/5R5xd2sdvdo1cZCFlguORNpVuqxIj+aK4cfQ==",
"requires": {}
},
"pg-protocol": {
"version": "1.6.0",
"resolved": "https://registry.npmjs.org/pg-protocol/-/pg-protocol-1.6.0.tgz",
"integrity": "sha512-M+PDm637OY5WM307051+bsDia5Xej6d9IR4GwJse1qA1DIhiKlksvrneZOYQq42OM+spubpcNYEo2FcKQrDk+Q=="
},
"pg-types": {
"version": "2.2.0",
"resolved": "https://registry.npmjs.org/pg-types/-/pg-types-2.2.0.tgz",
"integrity": "sha512-qTAAlrEsl8s4OiEQY69wDvcMIdQN6wdz5ojQiOy6YRMuynxenON0O5oCpJI6lshc6scgAY8qvJ2On/p+CXY0GA==",
"requires": {
"pg-int8": "1.0.1",
"postgres-array": "~2.0.0",
"postgres-bytea": "~1.0.0",
"postgres-date": "~1.0.4",
"postgres-interval": "^1.1.0"
}
},
"pgpass": {
"version": "1.0.5",
"resolved": "https://registry.npmjs.org/pgpass/-/pgpass-1.0.5.tgz",
"integrity": "sha512-FdW9r/jQZhSeohs1Z3sI1yxFQNFvMcnmfuj4WBMUTxOrAyLMaTcE1aAMBiTlbMNaXvBCQuVi0R7hd8udDSP7ug==",
"requires": {
"split2": "^4.1.0"
}
},
"picocolors": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/picocolors/-/picocolors-1.0.0.tgz",
@ -8089,6 +8316,29 @@
"integrity": "sha512-1NNCs6uurfkVbeXG4S8JFT9t19m45ICnif8zWLd5oPSZ50QnwMfK+H3jv408d4jw/7Bttv5axS5IiHoLaVNHeQ==",
"dev": true
},
"postgres-array": {
"version": "2.0.0",
"resolved": "https://registry.npmjs.org/postgres-array/-/postgres-array-2.0.0.tgz",
"integrity": "sha512-VpZrUqU5A69eQyW2c5CA1jtLecCsN2U/bD6VilrFDWq5+5UIEVO7nazS3TEcHf1zuPYO/sqGvUvW62g86RXZuA=="
},
"postgres-bytea": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/postgres-bytea/-/postgres-bytea-1.0.0.tgz",
"integrity": "sha512-xy3pmLuQqRBZBXDULy7KbaitYqLcmxigw14Q5sj8QBVLqEwXfeybIKVWiqAXTlcvdvb0+xkOtDbfQMOf4lST1w=="
},
"postgres-date": {
"version": "1.0.7",
"resolved": "https://registry.npmjs.org/postgres-date/-/postgres-date-1.0.7.tgz",
"integrity": "sha512-suDmjLVQg78nMK2UZ454hAG+OAW+HQPZ6n++TNDUX+L0+uUlLywnoxJKDou51Zm+zTCjrCl0Nq6J9C5hP9vK/Q=="
},
"postgres-interval": {
"version": "1.2.0",
"resolved": "https://registry.npmjs.org/postgres-interval/-/postgres-interval-1.2.0.tgz",
"integrity": "sha512-9ZhXKM/rw350N1ovuWHbGxnGh/SNJ4cnxHiM0rxE4VN41wsg8P8zWn9hv/buK00RP4WvlOyr/RBDiptyxVbkZQ==",
"requires": {
"xtend": "^4.0.0"
}
},
"prelude-ls": {
"version": "1.2.1",
"resolved": "https://registry.npmjs.org/prelude-ls/-/prelude-ls-1.2.1.tgz",
@ -8153,6 +8403,12 @@
"scheduler": "^0.23.0"
}
},
"react-icons": {
"version": "4.8.0",
"resolved": "https://registry.npmjs.org/react-icons/-/react-icons-4.8.0.tgz",
"integrity": "sha512-N6+kOLcihDiAnj5Czu637waJqSnwlMNROzVZMhfX68V/9bu9qHaMIJC4UdozWoOk57gahFCNHwVvWzm0MTzRjg==",
"requires": {}
},
"react-is": {
"version": "16.13.1",
"resolved": "https://registry.npmjs.org/react-is/-/react-is-16.13.1.tgz",
@ -8376,6 +8632,11 @@
"resolved": "https://registry.npmjs.org/source-map-js/-/source-map-js-1.0.2.tgz",
"integrity": "sha512-R0XvVJ9WusLiqTCEiGCmICCMplcCkIwwR11mOSD9CR5u+IXYdiseeEuXCVAjS54zqwkLcPNnmU4OeJ6tUrWhDw=="
},
"split2": {
"version": "4.1.0",
"resolved": "https://registry.npmjs.org/split2/-/split2-4.1.0.tgz",
"integrity": "sha512-VBiJxFkxiXRlUIeyMQi8s4hgvKCSjtknJv/LVYbrgALPwf5zSKmEwV9Lst25AkvMDnvxODugjdl6KZgwKM1WYQ=="
},
"sqlite": {
"version": "4.1.2",
"resolved": "https://registry.npmjs.org/sqlite/-/sqlite-4.1.2.tgz",
@ -8825,8 +9086,7 @@
"xtend": {
"version": "4.0.2",
"resolved": "https://registry.npmjs.org/xtend/-/xtend-4.0.2.tgz",
"integrity": "sha512-LKYU1iAXJXUgAXn9URjiu+MWhyUXHsvfp7mcuYm9dSUKK0/CjtrUwFAxD82/mCWbtLsGjFIad0wIsod4zrTAEQ==",
"dev": true
"integrity": "sha512-LKYU1iAXJXUgAXn9URjiu+MWhyUXHsvfp7mcuYm9dSUKK0/CjtrUwFAxD82/mCWbtLsGjFIad0wIsod4zrTAEQ=="
},
"yallist": {
"version": "4.0.0",

View File

@ -17,13 +17,16 @@
"eslint": "8.33.0",
"eslint-config-next": "13.1.6",
"next": "13.1.6",
"pg": "^8.10.0",
"react": "18.2.0",
"react-dom": "18.2.0",
"react-icons": "^4.8.0",
"sqlite": "^4.1.2",
"sqlite3": "^5.1.4",
"typescript": "4.9.5"
},
"devDependencies": {
"@types/pg": "^8.6.6",
"autoprefixer": "^10.4.13",
"postcss": "^8.4.21",
"tailwindcss": "^3.2.6"

BIN
public/assets/moon_1.png Normal file

Binary file not shown.

After

Width:  |  Height:  |  Size: 1.3 MiB

View File

@ -1,41 +1,7 @@
INSERT INTO users(name) VALUES
('Joe'),
('Emil'),
('Niko'),
('Plug'),
('Upgrade');
GRANT USAGE ON SCHEMA public TO devs;
GRANT USAGE ON ALL SEQUENCES IN SCHEMA public TO devs;
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO devs;
INSERT INTO resource(name)
VALUES ('Sollux'), ('Shadowstone'), ('Azurium'), ('Novafor'), ('Nebulance');
INSERT INTO bank_account(user_id, balance) VALUES (1, 500);
INSERT INTO resource_account(user_id, resname, balance) VALUES
(1, 'Sollux', 100),
(1, 'Shadowstone', 100),
(1, 'Azurium', 100),
(1, 'Novafor', 100),
(1, 'Nebulance', 100);
INSERT INTO staking_source(name, description, user_id, address) VALUES
('Selene''s Eye',
'Selene''s Eye is a large and mysterious moon, named for its distinctive appearance - a bright, glowing eye that seems to stare out from the void of space',
1,
'0x1234568');
INSERT INTO resource_well(source_id, resname, supply) VALUES
(1, 'Sollux', 200),
(1, 'Shadowstone', 175),
(1, 'Azurium', 0),
(1, 'Novafor', 25),
(1, 'Nebulance', 10);
INSERT INTO inventory_item(user_id, store_item_id) VALUES
(1, 'item1'),
(1, 'item2');
-- INSERT INTO staking_event(user_id, well_id, inventory_item_id, duration_in_mins, stake_amount) VALUES
-- (1, 1, 1, 5, 50),
-- (1, 3, 2, 5, 50);
-- INSERT INTO claim_event(staking_event_id, claim_amount) VALUES
-- (2, 50);

327
sql/procedures.sql Normal file
View File

@ -0,0 +1,327 @@
CREATE OR REPLACE FUNCTION create_user(
p_name VARCHAR,
-- p_discord_id NUMERIC(20,0),
p_wallet VARCHAR(64),
p_user_id UUID DEFAULT NULL
) RETURNS UUID
AS $$
DECLARE
new_uuid UUID;
res_id INTEGER;
BEGIN
IF p_user_id IS NULL THEN
INSERT INTO users(name, wallet) VALUES (p_name, p_wallet)
RETURNING id INTO new_uuid;
ELSE
new_uuid := p_user_id;
INSERT INTO users(id, name, wallet) VALUES (p_user_id, p_name, p_wallet);
END IF;
INSERT INTO bank_account(user_id, balance) VALUES (new_uuid, 500);
INSERT INTO resource_account (resource_id, user_id, balance)
SELECT resource.id, new_uuid, 50
FROM resource
LEFT JOIN LATERAL (VALUES (id)) AS subquery(value) ON TRUE;
RETURN new_uuid;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_accounts(user_id UUID)
RETURNS TABLE (
id INTEGER,
"primaryBalance" INTEGER,
"resourceAccounts" JSON
)
AS $$
BEGIN
RETURN QUERY
SELECT
bank_account.id,
bank_account.balance,
json_agg(
json_build_object(
'id', resource_account.id,
'resourceType', resource.name,
'balance', resource_account.balance)
ORDER BY resource.name)
FROM bank_account
JOIN resource_account ON bank_account.user_id = resource_account.user_id
JOIN resource ON resource.id = resource_account.resource_id
WHERE bank_account.user_id = $1
GROUP BY bank_account.id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_staking_sources(user_id UUID)
RETURNS TABLE (
id INTEGER,
name varchar,
description varchar,
resourceWells JSON,
activeStakes JSON
)
AS $$
BEGIN
RETURN QUERY
SELECT
staking_source.id as id,
staking_source.name,
staking_source.description,
json_agg(
json_build_object(
'id', resource_well.id,
'resourceType', resource.name,
'supply', resource_well.supply
)
) as "resourceWells",
COALESCE (json_agg(
json_build_object(
'id', se.id,
'resourceType', resource.name,
'inventoryItemId', se.inventory_item_id,
'durationInMins', se.duration_in_mins,
'stakeAmount', se.stake_amount,
'startTime', se.created_at
)
) FILTER (WHERE se.id IS NOT NULL), '[]'::json) as "activeStakes"
FROM staking_source
INNER JOIN resource_well ON resource_well.source_id = staking_source.id
INNER JOIN resource ON resource.id = resource_well.resource_id
LEFT JOIN (
SELECT staking_event.id, staking_event.well_id, staking_event.created_at,
duration_in_mins, stake_amount, inventory_item_id
FROM staking_event
LEFT JOIN claim_event ON claim_event.staking_event_id = staking_event.id
WHERE claim_event.staking_event_id IS NULL
) se ON se.well_id = resource_well.id
WHERE staking_source.user_id = $1
GROUP BY staking_source.id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION create_staking_source(
p_user_id UUID,
p_name VARCHAR,
p_description VARCHAR,
p_address VARCHAR,
p_cost INTEGER,
p_min_res INTEGER,
p_max_res INTEGER
) RETURNS INTEGER
AS $$
DECLARE
new_source_id INTEGER;
resource_ids INTEGER[];
res_id INTEGER;
BEGIN
UPDATE bank_account SET balance = balance - p_cost WHERE user_id = p_user_id;
INSERT INTO staking_source(user_id, name, description, address)
VALUES (p_user_id, p_name, p_description, p_address)
RETURNING id INTO new_source_id;
SELECT array_agg(id) FROM resource INTO resource_ids;
FOREACH res_id IN ARRAY resource_ids
LOOP
WITH random_supply AS (
SELECT FLOOR(RANDOM() * (p_max_res - p_min_res) + p_min_res) AS supply
)
INSERT INTO resource_well (source_id, resource_id, supply)
SELECT new_source_id, res_id, random_supply.supply
FROM random_supply;
END LOOP;
RETURN new_source_id AS result;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION purchase_item(
p_user_id UUID,
p_price INTEGER,
p_store_item_id TEXT
) RETURNS INTEGER
AS $$
DECLARE
new_item_id INTEGER;
BEGIN
UPDATE bank_account SET balance = balance - p_price WHERE user_id = p_user_id;
INSERT INTO inventory_item (user_id, store_item_id) VALUES (p_user_id, p_store_item_id)
RETURNING id INTO new_item_id;
RETURN new_item_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION upgrade_item(
p_user_id UUID,
p_item_id INTEGER,
p_price INTEGER
) RETURNS INTEGER
AS $$
DECLARE
upgrade_event_id INTEGER;
item_insert_id INTEGER;
BEGIN
UPDATE bank_account SET balance = balance - p_price WHERE user_id = p_user_id;
UPDATE inventory_item SET tier = tier + 1
WHERE inventory_item.id = p_item_id AND inventory_item.user_id = p_user_id
RETURNING id INTO item_insert_id;
IF item_insert_id IS NULL THEN
RAISE EXCEPTION 'No matching row found in inventory_item';
END IF;
INSERT INTO upgrade_event(inventory_item_id) VALUES (p_item_id) RETURNING id INTO upgrade_event_id;
RETURN upgrade_event_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION stake(
p_user_id UUID,
p_well_id INTEGER,
p_inventory_item_id INTEGER,
p_duration INTEGER,
p_stake_amount INTEGER
) RETURNS INTEGER
AS $$
DECLARE
staking_event_id INTEGER;
actual_duration INTEGER;
stake_end_time TIMESTAMP;
inv_id INTEGER;
stake_id INTEGER;
stake_created_at TIMESTAMP;
BEGIN
SELECT
inventory_item.id AS inv_id,
staking_event.id AS stake_id,
staking_event.created_at AS stake_created_at,
duration_in_mins
FROM inventory_item
LEFT JOIN staking_event
ON staking_event.inventory_item_id = inv_id
WHERE inventory_item.id = p_inventory_item_id AND inventory_item.user_id = p_user_id
ORDER BY stake_created_at DESC LIMIT 1
INTO inv_id, stake_id, stake_created_at, actual_duration;
IF inv_id IS NULL THEN
RAISE EXCEPTION SQLSTATE '90001'
USING MESSAGE = 'Unable to find an inventory item that belongs to the user';
END IF;
IF actual_duration IS NULL THEN
actual_duration := p_duration;
END IF;
stake_end_time := stake_created_at + (actual_duration * INTERVAL '1 MINUTE');
IF stake_id IS NOT NULL AND NOW() AT TIME ZONE 'UTC' < stake_end_time THEN
RAISE EXCEPTION SQLSTATE '90001'
USING MESSAGE = 'Unable to find an inventory item that is owned and not actively staked';
END IF;
INSERT INTO staking_event(user_id, well_id, inventory_item_id, duration_in_mins, stake_amount)
VALUES (p_user_id, p_well_id, p_inventory_item_id, actual_duration, p_stake_amount)
RETURNING id INTO staking_event_id;
RETURN staking_event_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_all_stakes(p_user_id UUID)
RETURNS TABLE (
id INTEGER,
"sourceId" INTEGER,
"wellId" INTEGER,
"inventoryItemId" INTEGER,
"resourceType" VARCHAR,
"stakeAmount" INTEGER,
"stakeTime" TIMESTAMP WITH TIME ZONE,
"durationInMins" INTEGER,
unclaimed BOOL
)
AS $$
BEGIN
RETURN QUERY
SELECT
staking_event.id,
staking_source.id AS sourceId,
resource_well.id AS wellId,
inventory_item_id AS inventoryItemId,
resource.name AS resourceType,
stake_amount AS stakeAmount,
staking_event.created_at AS stakeTime,
duration_in_mins AS durationInMins,
CASE WHEN claim_event.staking_event_id IS NULL THEN true ELSE false END AS unclaimed
FROM staking_event
INNER JOIN resource_well ON well_id = resource_well.id
INNER JOIN resource ON resource.id = resource_well.resource_id
INNER JOIN staking_source ON source_id = staking_source.id
LEFT JOIN claim_event ON staking_event.id = claim_event.staking_event_id
WHERE staking_event.user_id = p_user_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION claim(p_user_id UUID, p_stake_id INTEGER)
RETURNS INTEGER
AS $$
DECLARE
stake RECORD;
claim_event_id INTEGER;
stake_end_time TIMESTAMP;
resource_supply INTEGER;
final_supply INTEGER;
BEGIN
SELECT
staking_event.id,
resource.id AS res_id,
staking_event.user_id,
well_id,
inventory_item_id,
duration_in_mins,
stake_amount,
created_at
INTO stake FROM staking_event
JOIN resource_well ON resource_well.id = well_id
JOIN resource ON resource.id = resource_well.resource_id
WHERE staking_event.id = p_stake_id AND staking_event.user_id = p_user_id;
IF stake IS NULL THEN
RAISE EXCEPTION SQLSTATE '90001'
USING MESSAGE = 'Staking event not found';
END IF;
IF (SELECT id FROM claim_event WHERE staking_event_id = stake.id) IS NOT NULL THEN
RAISE EXCEPTION SQLSTATE '90001'
USING MESSAGE = 'Stake already claimed';
END IF;
stake_end_time := stake.created_at + (stake.duration_in_mins * INTERVAL '1 MINUTE');
IF NOW() AT TIME ZONE 'UTC' < stake_end_time THEN
RAISE EXCEPTION SQLSTATE '90001'
USING MESSAGE = 'Stake has not finished, cannot claim';
END IF;
SELECT supply FROM resource_well WHERE id = stake.well_id INTO resource_supply;
final_supply := CASE WHEN resource_supply > stake.stake_amount
THEN stake.stake_amount
ELSE resource_supply
END;
UPDATE resource_account SET balance = balance + final_supply
WHERE user_id = p_user_id AND resource_id = stake.res_id;
UPDATE resource_well SET supply = supply - final_supply
WHERE resource_id = stake.res_id;
INSERT INTO claim_event(staking_event_id, claim_amount) VALUES (stake.id, final_supply)
RETURNING id INTO claim_event_id;
RETURN claim_event_id;
END;
$$ LANGUAGE plpgsql;

89
sql/queries-psql.sql Normal file
View File

@ -0,0 +1,89 @@
select * from users;
select * from resource;
select * from resource_account;
select * from bank_account;
select * from resource_account
join users on resource_account.user_id = users.id
join resource on resource.id = resource_account.resource_id
where users.name = 'Harry';
select * from bank_account where user_id = 'c40ef029-9c31-4bf8-8bb4-d6f63caeb351';
delete from users where id = 'c40ef029-9c31-4bf8-8bb4-d6f63caeb351';
select * from get_accounts( 'c40ef029-9c31-4bf8-8bb4-d6f63caeb351');
update bank_account set balance = 1200 from users where bank_account.user_id = users.id AND name = 'Joe';
select * from inventory_item;
select * from upgrade_event;
delete from upgrade_event;
update inventory_item set tier = 0;
select * from staking_event;
update staking_event set created_at = '2023-03-30 05:05:39.696926+00';
select * from claim_event;
delete from claim_event;
-- Grab a user's bank account plus their resource accounts
EXPLAIN ANALYZE
SELECT
bank_account.id as bank_account_id,
bank_account.balance as primary_balance,
json_agg(json_build_object('resourceType', resource.name, 'balance', resource_account.balance)) as resource_accounts
FROM bank_account
JOIN resource_account ON bank_account.user_id = resource_account.user_id
JOIN resource ON resource.id = resource_account.resource_id
JOIN users ON bank_account.user_id = users.id
WHERE users.name = 'Joe'
GROUP BY bank_account.id;
-- Grab a user's bank account plus their resource accounts
EXPLAIN ANALYZE
SELECT
bank_account.id as bank_account_id,
bank_account.balance as primary_balance,
resname as resourceType,
resource_account.balance,
resource_account.id as resId
FROM bank_account
JOIN resource_account ON 1 = resource_account.user_id
WHERE bank_account.user_id = 1;
-- Grab a staking source with all its resource wells and active stakes
SELECT
staking_source.id as id, name, description,
json_agg(
json_build_object(
'id', resource_well.id, 'resouceType', resource_well.resname, 'supply', supply )) as "resourceWells",
json_agg(
json_build_object(
'id', staking_event.id, 'resouceType', resource_well.resname, 'startTime', staking_event.created_at)) as "activeStakes"
FROM staking_source
INNER JOIN resource_well ON resource_well.source_id = staking_source.id
INNER JOIN staking_event ON staking_event.well_id = resource_well.id
WHERE staking_source.user_id = 1
GROUP BY staking_source.id;
SELECT
inventory_item.id AS inv_id,
staking_event.id AS stake_id,
staking_event.created_at AS stake_created_at
FROM inventory_item
LEFT JOIN staking_event ON inventory_item_id = inventory_item.id
WHERE inventory_item.id = 1 AND inventory_item.user_id = 1
ORDER BY stake_created_at DESC
LIMIT 1;

95
sql/tables-psql.sql Normal file
View File

@ -0,0 +1,95 @@
CREATE TABLE users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
wallet varchar(64),
name varchar(32) not null
);
CREATE TABLE resource (
id serial primary key,
name varchar(32) not null unique
);
CREATE TABLE staking_source (
id serial primary key,
name varchar not null,
description varchar not null,
user_id UUID not null,
address varchar(128) not null,
created_at timestamp with time zone default timezone('UTC', now()),
CONSTRAINT fk_user_staking_source FOREIGN KEY(user_id)
REFERENCES users(id) ON DELETE CASCADE
);
CREATE TABLE resource_well (
id serial primary key,
resource_id integer not null,
source_id integer not null,
supply integer not null,
CONSTRAINT fk_sid_resource_well FOREIGN KEY(source_id)
REFERENCES staking_source(id) ON DELETE CASCADE,
CONSTRAINT fk_rid_resource_well FOREIGN KEY(resource_id)
REFERENCES resource(id)
);
CREATE TABLE inventory_item (
id serial primary key,
user_id UUID not null,
tier integer not null default 0,
store_item_id varchar not null,
created_at timestamp with time zone default timezone('UTC', now()),
CONSTRAINT fk_user_inventory_item FOREIGN KEY(user_id)
REFERENCES users(id) ON DELETE CASCADE
CONSTRAINT uk_user_store_item UNIQUE (user_id, store_item_id)
);
CREATE TABLE upgrade_event (
id serial primary key,
inventory_item_id integer not null,
created_at timestamp with time zone default timezone('UTC', now()),
CONSTRAINT fk_iid_upgrade_event FOREIGN KEY(inventory_item_id)
REFERENCES inventory_item(id)
);
CREATE TABLE staking_event (
id serial primary key,
user_id UUID not null,
well_id integer not null,
inventory_item_id integer not null,
duration_in_mins integer not null,
stake_amount integer not null,
created_at timestamp with time zone default timezone('UTC', now()),
CONSTRAINT fk_user_staking_event FOREIGN KEY(user_id)
REFERENCES users(id) ON DELETE CASCADE,
CONSTRAINT fk_wid_staking_event FOREIGN KEY(well_id)
REFERENCES resource_well(id),
CONSTRAINT fk_iiid_staking_event FOREIGN KEY(inventory_item_id)
REFERENCES inventory_item(id)
);
CREATE TABLE claim_event (
id serial primary key,
staking_event_id integer not null,
claim_amount integer not null,
created_at timestamp with time zone default timezone('UTC', now()),
CONSTRAINT fk_se_claim_event FOREIGN KEY(staking_event_id)
REFERENCES staking_event(id) ON DELETE CASCADE
);
CREATE TABLE bank_account (
id serial primary key,
user_id UUID not null,
balance integer not null default 0 CHECK (balance >= 0),
CONSTRAINT fk_user_bank_account FOREIGN KEY(user_id)
REFERENCES users(id) ON DELETE CASCADE
);
CREATE TABLE resource_account (
id serial primary key,
resource_id integer not null,
user_id UUID not null,
balance integer not null default 0 CHECK (balance >= 0),
CONSTRAINT fk_user_resource_account FOREIGN KEY(user_id)
REFERENCES users(id) ON DELETE CASCADE,
CONSTRAINT fk_rid_resource_account FOREIGN KEY(resource_id)
REFERENCES resource(id)
);

View File

@ -1,12 +1,16 @@
"use client";
import React from "react";
import { IBankAccount } from "typings";
import BankAccount from "./BankAccount";
import ResourceAccount from "./ResourceAccount";
const BankAccountsView = (props: {
bankAccount: IBankAccount | undefined;
setLightBoxIsActive: () => void;
}) => {
if (props.bankAccount === undefined) {
return <p>No bankaccount</p>;
}
return (
<div className="p-4">
<div className="flex gap-8">
@ -25,6 +29,7 @@ const BankAccountsView = (props: {
</div>
</div>
{props.bankAccount &&
props.bankAccount?.resourceAccounts.length > 0 &&
props.bankAccount.resourceAccounts.map((account, id) => {
return <ResourceAccount key={id} account={account} />;
})}

View File

@ -11,6 +11,7 @@ const InventoryItemView = (props: {
<div className="bg-slate-800 text-white p-4 rounded-lg">
<h2 className="text-2xl font-bold mb-4">Your Inventory</h2>
{props.inventoryItems &&
props.inventoryItems.length > 0 &&
props.inventoryItems.map((inventoryItem, id) => (
<InventoryItem
key={id}

View File

@ -0,0 +1,123 @@
"use client";
import { Dispatch, SetStateAction, useEffect, useState } from "react";
import type { PublicKey } from "@solana/web3.js";
import { PhantomProvider } from "typings";
import { useRouter } from "next/navigation";
import { BiLoaderAlt } from "react-icons/bi";
export default function Navbar({
setUserId,
}: {
setUserId: Dispatch<SetStateAction<string>>;
}) {
const router = useRouter();
const [provider, setProvider] = useState<PhantomProvider>();
const [walletAddress, setWalletAddress] = useState("");
const [showErrorMessage, setShowErrorMessage] = useState(false);
const [isLoading, setIsLoading] = useState(true);
useEffect(() => {
const provider = getProvider();
setProvider(provider);
if (provider) {
provider.on("connect", async (publicKey: PublicKey) => {
setIsLoading(true);
const body = { wallet: publicKey };
const res = await fetch("/api/user/login", {
method: "POST",
body: JSON.stringify(body),
headers: { "Content-Type": "application/json" },
});
if (res.status === 200) {
const { userId } = await res.json();
localStorage.setItem("userId", userId);
setWalletAddress(publicKey.toBase58());
setUserId(userId);
}
if (res.status === 404) {
setShowErrorMessage(true);
setTimeout(() => {
setShowErrorMessage(false);
}, 3000);
}
setIsLoading(false);
});
}
const localStorageUserId = localStorage.getItem("userId");
if (localStorageUserId) {
setUserId(localStorageUserId);
const fetchWallet = async () => {
const res = await fetch(`/api/user/${localStorageUserId}/wallet`);
if (res.status === 200) {
const { wallet } = await res.json();
setWalletAddress(wallet);
setIsLoading(false);
}
};
fetchWallet();
return;
}
setIsLoading(false);
}, []);
const getProvider = () => {
if ("phantom" in window) {
const anyWindow: any = window;
const provider = anyWindow.phantom.solana;
if (provider.isPhantom) return provider;
}
};
const connectWallet = () => {
if (!provider) return console.log("no provider");
provider.connect();
};
const logout = () => {
localStorage.removeItem("userId");
setUserId("");
setWalletAddress("");
provider?.disconnect();
router.refresh();
};
return (
<nav className="text-white flex justify-between mt-4">
<button
onClick={() => router.push("/")}
className="p-2 m-4 text-3xl font-bold"
>
Moon Miners
</button>
{showErrorMessage && (
<div className="p-2 m-4 bg-red-800 rounded-lg">
Wallet address not registered!
</div>
)}
{walletAddress.length === 0 ? (
<button
onClick={connectWallet}
className="p-2 m-4 bg-slate-800 rounded-lg"
>
{isLoading ? (
<BiLoaderAlt className="animate-spin w-28" />
) : (
"Connect Wallet"
)}
</button>
) : (
<div className="flex items-stretch">
<button className="p-2 m-4 bg-slate-800 rounded-lg">
{walletAddress}
</button>
<button onClick={logout} className="p-2 m-4 bg-slate-800 rounded-lg">
Logout
</button>
</div>
)}
</nav>
);
}

View File

@ -11,10 +11,17 @@ const StakingSource = (props: {
stakingSource: IStakingSource;
inventoryItems: IInventoryItem[] | null | undefined;
claimStake: (stakingEventId: number) => void;
startStake: (inventoryItemId: number, wellId: number) => void;
startStake: (
inventoryItemId: number,
storeItemId: string,
wellId: number
) => void;
}) => {
const [activeStakes, setActiveStakes] = useState<IStake[]>([]);
const [selectedItemId, setSelectedItemId] = useState<number | null>(null);
const [selectedStoreItemId, setSelectedStoreItemId] = useState<string | null>(
null
);
const [selectedWellId, setSelectedWellId] = useState<number | null>(null);
// Check if claimable every second
@ -45,8 +52,8 @@ const StakingSource = (props: {
});
const handleStartMining = () => {
if (selectedItemId && selectedWellId) {
props.startStake(selectedItemId, selectedWellId);
if (selectedItemId && selectedWellId && selectedStoreItemId) {
props.startStake(selectedItemId, selectedStoreItemId, selectedWellId);
}
};
@ -54,8 +61,13 @@ const StakingSource = (props: {
props.claimStake(stakingEventId);
};
const handleSelectChange = (wellId: string, itemId: number) => {
const handleSelectChange = (
wellId: string,
itemId: number,
storeitemId: string
) => {
setSelectedWellId(Number(wellId));
setSelectedStoreItemId(storeitemId);
setSelectedItemId(itemId);
};
@ -156,7 +168,9 @@ const StakingSource = (props: {
label: well.resourceType,
})
)}
onChange={(value) => handleSelectChange(value, item.id)}
onChange={(value) =>
handleSelectChange(value, item.id, item.storeItem.id)
}
isActive={selectedItemId === item.id}
/>
{selectedItemId === item.id ? (

View File

@ -7,12 +7,39 @@ const StakingSourcesView = (props: {
stakingSources: IStakingSource[] | null;
inventoryItems: IInventoryItem[] | null | undefined;
claimStake: (stakingEventId: number) => void;
startStake: (inventoryItemId: number, wellId: number) => void;
startStake: (
inventoryItemId: number,
storeItemId: string,
wellId: number
) => void;
createStakingSource: () => void;
}) => {
return (
<div className="bg-slate-800 p-4 rounded-lg text-white">
<h2 className="text-2xl mb-4 font-bold">Your Moons</h2>
<div className="flex items-center mb-4">
<h2 className="text-2xl font-bold">Your Moons</h2>
<button
className="bg-green-600 rounded-full ml-2 p-1 inline"
onClick={() => props.createStakingSource()}
>
<svg
xmlns="http://www.w3.org/2000/svg"
fill="none"
viewBox="0 0 24 24"
strokeWidth={2}
stroke="currentColor"
className="w-6 h-6"
>
<path
strokeLinecap="round"
strokeLinejoin="round"
d="M12 4.5v15m7.5-7.5h-15"
/>
</svg>
</button>
</div>
{props.stakingSources &&
props.stakingSources.length > 0 &&
props.stakingSources.map((stakingSource, id) => (
<StakingSource
key={id}

View File

@ -1,5 +1,5 @@
import React from "react";
import { IInventoryItem, IStoreItem } from "typings";
import React, { useState } from "react";
import { IInventoryItem, IStakingSource, IStoreItem } from "typings";
import StoreItem from "./StoreItem";
const StoreItemView = (props: {
@ -12,6 +12,7 @@ const StoreItemView = (props: {
<h2 className="text-2xl font-bold mb-4 text-white">Store</h2>
<div className="grid grid-cols-1 gap-4">
{props.storeItems &&
props.storeItems.length > 0 &&
props.storeItems
.filter((item) => !item.isOwned)
.map((storeItem, id) => (

View File

@ -1,81 +1,15 @@
"use client";
import { useEffect, useState } from "react";
import type { PublicKey } from "@solana/web3.js";
import "./globals.css";
import { PhantomProvider } from "typings";
export default function RootLayout({
children,
}: {
children: React.ReactNode;
}) {
const [provider, setProvider] = useState<PhantomProvider>();
const [walletAddress, setWalletAddress] = useState("");
const [showErrorMessage, setShowErrorMessage] = useState(false);
useEffect(() => {
const provider = getProvider();
setProvider(provider);
if (!provider) return;
provider.on("connect", async (publicKey: PublicKey) => {
const body = { publicKey: publicKey };
const res = await fetch("/api/user/login", {
method: "POST",
body: JSON.stringify(body),
headers: { "Content-Type": "application/json" },
});
if (res.status === 200) {
setWalletAddress(publicKey.toBase58());
}
if (res.status === 404) {
setShowErrorMessage(true);
setTimeout(() => {
setShowErrorMessage(false);
}, 3000);
}
});
}, []);
const getProvider = () => {
if ("phantom" in window) {
const anyWindow: any = window;
const provider = anyWindow.phantom.solana;
if (provider.isPhantom) return provider;
}
};
const connectWallet = () => {
if (!provider) return console.log("no provider");
provider.connect();
};
return (
<html lang="en">
<head />
<body className="bg-slate-900">
<nav className="text-white flex justify-between mt-4">
<div className="p-2 m-4 bg-slate-800 rounded-lg">Moon Miners</div>
{showErrorMessage && (
<div className="p-2 m-4 bg-red-800 rounded-lg">
Wallet address not registered!
</div>
)}
{walletAddress.length === 0 ? (
<button
onClick={connectWallet}
className="p-2 m-4 bg-slate-800 rounded-lg"
>
Connect Wallet
</button>
) : (
<div className="p-2 m-4 bg-slate-800 rounded-lg">
{walletAddress}
</div>
)}
</nav>
{children}
</body>
<body className="bg-slate-900">{children}</body>
</html>
);
}

View File

@ -1,6 +1,5 @@
"use client";
import { useState, useEffect } from "react";
import InventoryItemView from "./Components/InventoryItemView";
import StakingSourcesView from "./Components/StakingSourcesView";
import BankAccountsView from "./Components/BankAccountsView";
@ -10,11 +9,13 @@ import NotificationPopover from "./Components/NotificationPopover";
import { gameConfig } from "@/utils/gameLogic";
import {
IInventoryItem,
IStoreStakingSource,
IStakingSource,
IBankAccount,
IStake,
Notification,
} from "typings";
import Navbar from "./Components/Navbar";
export default function Home() {
const [inventoryItems, setInventoryItems] = useState<
@ -26,13 +27,14 @@ export default function Home() {
const [bankAccount, setBankAccount] = useState<IBankAccount>();
const [userStakes, setUserStakes] = useState<IStake[]>([]);
const [lightBoxIsActive, setLightBoxIsActive] = useState(false);
const [userId, setUserId] = useState<number | null>(null);
const [userId, setUserId] = useState<string>("");
const [notification, setNotification] = useState<Notification | null>(null);
const [notificationTime, setNotificationTime] = useState(30);
const [storeItems, setStoreItems] = useState(gameConfig.store);
const [isLoading, setIsLoading] = useState(true);
const isOwned = (storeItemId: string) => {
if (inventoryItems) {
if (inventoryItems && inventoryItems?.length > 0) {
return inventoryItems?.some((item) => item.storeItem.id == storeItemId);
} else {
return false;
@ -43,28 +45,29 @@ export default function Home() {
const response = await fetch(`/api/user/${userId}/inventory-items`);
const DBInventoryItems = await response.json();
for (const invItem of DBInventoryItems) {
for (const invItem of DBInventoryItems.inventoryItems) {
invItem.storeItem = gameConfig.store.find(
(item) => item.id === invItem.storeItemId
);
}
setInventoryItems(DBInventoryItems);
// TODO Can you just return the array?
setInventoryItems(DBInventoryItems.inventoryItems);
};
const fetchStakingSources = async () => {
const response = await fetch(`/api/user/${userId}/staking-sources`);
const sources = await response.json();
setStakingSources(sources);
// TODO Can you just return the array?
setStakingSources(sources.stakingSources);
};
const fetchStakes = async () => {
const response = await fetch(`/api/user/${userId}/stakes`);
const stakes = await response.json();
setUserStakes(
stakes.map((stake: IStake) => ({
stakes.stakes.map((stake: IStake) => ({
...stake,
unclaimed: stake.unclaimed == 1,
unclaimed: stake.unclaimed,
}))
);
};
@ -76,29 +79,12 @@ export default function Home() {
};
useEffect(() => {
const fetchUser = async (wallet: string) => {
const response = await fetch(`/api/user/login`, {
method: "POST",
headers: { "Content-Type": "application/json" },
body: JSON.stringify({
wallet: wallet,
}),
});
if (response.status === 200) {
console.log("Logged in");
const { userId } = await response.json();
setUserId(userId);
}
};
fetchUser("abcdefg"); // Public key goes here
// Nico is there a better way of checking if a user is logged in?
if (userId) {
if (userId === "") return;
fetchBankAccount();
fetchStakingSources();
fetchInventoryItems();
fetchStakes();
}
setIsLoading(false);
}, [userId]);
// Update data
@ -154,12 +140,17 @@ export default function Home() {
}
};
const startStake = async (inventoryItemId: number, wellId: number) => {
const startStake = async (
inventoryItemId: number,
storeItemId: string,
wellId: number
) => {
const response = await fetch(`/api/user/${userId}/stakes/start`, {
method: "POST",
headers: { "Content-Type": "application/json" },
body: JSON.stringify({
inventoryItemId: inventoryItemId,
storeItemId,
wellId: wellId,
}),
});
@ -191,12 +182,13 @@ export default function Home() {
};
const buyStoreItem = async (itemId: string) => {
console.log(`Buying item with id ${itemId}`);
try {
const response = await fetch(`/api/user/${userId}/inventory-items`, {
method: "POST",
headers: { "Content-Type": "application/json" },
body: JSON.stringify({
itemId: itemId,
storeItemId: itemId,
}),
});
@ -251,6 +243,7 @@ export default function Home() {
// Return success message
setNotification({ message: "Item has been upgraded", type: "Success" });
fetchInventoryItems();
fetchBankAccount();
}
if (response.status == 400) {
@ -267,12 +260,34 @@ export default function Home() {
};
const createStakingSource = async () => {
console.log("Minting...");
try {
const response = await fetch(`/api/user/${userId}/staking-sources`, {
method: "POST",
headers: { "Content-Type": "application/json" },
body: JSON.stringify({}),
});
return await response.json();
const data = await response.json();
if (response.status == 200) {
// Return success message
setNotification({ message: "Moon has been minted", type: "Success" });
fetchInventoryItems();
fetchStakingSources();
fetchBankAccount();
}
if (response.status == 400) {
// return error message
setNotification({ message: data.error, type: "Error" });
}
} catch (error) {
if (error instanceof Error) {
setNotification({ message: error.message, type: "Error" });
} else {
setNotification({ message: "An unknown error occured", type: "Error" });
}
}
};
const handleSetLightBox = () => {
@ -283,10 +298,22 @@ export default function Home() {
setNotification(null);
};
if (!userId) return <p>Please login</p>;
if (!userId)
return (
<>
<Navbar setUserId={setUserId} />
<p>Please login</p>
</>
);
if (isLoading) {
return <p>Loading...</p>;
}
console.log(stakingSources);
return (
<>
<Navbar setUserId={setUserId} />
{notification && (
<NotificationPopover
notification={notification}
@ -309,6 +336,7 @@ export default function Home() {
inventoryItems={inventoryItems}
claimStake={claimStake}
startStake={startStake}
createStakingSource={createStakingSource}
/>
<InventoryItemView
stakes={userStakes}
@ -324,6 +352,3 @@ export default function Home() {
</>
);
}
// Pass data from storeComponent to parentComponent
// re-fetch data of inventory

View File

@ -11,7 +11,7 @@ export default async function handler(
const db = await dbConnection;
// Read SQL queries from file
const sql1 = fs.readFileSync('sql/tables.sql', 'utf-8');
const sql1 = fs.readFileSync('sql/tables-sqlite.sql', 'utf-8');
// Execute the SQL queries
await db.exec(sql1);

18
src/pages/api/test.ts Normal file
View File

@ -0,0 +1,18 @@
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
export default async function handler(
req: NextApiRequest,
res: NextApiResponse
) {
try {
if (req.method === "GET") {
const db = postgresConnection;
const a = await db.query("SELECT * FROM users");
console.log(a.rows);
res.status(200).json(a.rows);
}
} catch (error) {
res.status(500).json(error);
}
}

View File

@ -1,5 +1,7 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
import { checkIfValidUUID } from "@/utils/helpers";
import { IBankAccount } from "typings";
export default async function handler(
req: NextApiRequest,
@ -8,28 +10,27 @@ export default async function handler(
try {
if (req.method === "GET") {
const { userId } = req.query;
const db = await dbConnection;
const userSql = `SELECT * FROM users WHERE id = ?`;
const user = await db.all(userSql, [userId]);
if (user.length === 0) return res.status(404).json("User not found");
const db = postgresConnection;
const resourceAccountsSql = `
SELECT id,resname as resourceType,balance
FROM resource_account
WHERE user_id = ?`;
// need resourceName or at least a way to map together with gameConfiq
const resourceAccounts = await db.all(resourceAccountsSql, [userId]);
if (!checkIfValidUUID(userId)) {
return res.status(400).json({error: "Invalid UUID for user id"});
}
const bankAccountSql = `SELECT * FROM bank_account WHERE user_id = ?`;
const bankAccount = await db.all(bankAccountSql, [userId]);
const result = await db.query("SELECT * FROM get_accounts($1)", [userId]);
const bankAccountObj = {
id: bankAccount[0].id,
primaryBalance: bankAccount[0].balance,
resourceAccounts: resourceAccounts,
};
if (result.rowCount > 0) {
return res.status(200).json(bankAccountObj);
// Make the result to the type
/* const updatedResult: IBankAccount = {
id: result.rows[0].id,
primaryBalance: result.rows[0].primarybalance,
resourceAccounts: result.rows[0].resourceaccounts
} */
return res.status(200).json(result.rows[0]);
} else {
return res.status(400).json({error: "Could not find accounts for user"});
}
}
if (req.method === "PUT") {

View File

@ -1,4 +1,4 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
import { gameConfig } from "@/utils/gameLogic";
@ -7,24 +7,26 @@ export default async function handler(
res: NextApiResponse
) {
try {
const db = postgresConnection;
if (req.method === "GET") {
// Get all owned items
const { userId } = req.query;
const db = await dbConnection;
// TODO: We probably shouldn't keep the tier as a column in the database, we can
// just do a join and count how many upgrades there are
const inventorySql = `
SELECT id, store_item_id as storeItemId, tier as currentTierIndex
FROM inventory_item WHERE user_id = ?`;
const inventoryItems = await db.all(inventorySql, [userId]);
return res.status(200).json(inventoryItems);
SELECT id, store_item_id as "storeItemId", tier as "currentTierIndex"
FROM inventory_item WHERE user_id = $1`;
const results = await db.query(inventorySql, [userId]);
return res.status(200).json({"inventoryItems": results.rows});
} else if (req.method === "POST") {
// Buy a new item
const { userId } = req.query;
const { itemId } = req.body;
const db = await dbConnection;
const { storeItemId } = req.body;
const storeItem = gameConfig.store.find((item) => item.id == itemId);
const storeItem = gameConfig.store.find((item) => item.id == storeItemId);
if (storeItem == undefined) {
return res.status(400).json({ error: "Item does not exist" });
@ -32,52 +34,46 @@ export default async function handler(
const itemPrice = storeItem.price;
// TODO: Split the try catch to report already owned item error
try {
await db.run("BEGIN");
await db.run(`UPDATE bank_account SET balance = balance - ?
WHERE user_id = ?`, [itemPrice, userId]);
await db.run(`INSERT INTO inventory_item (user_id, store_item_id)
VALUES (?, ?)`, [userId, itemId]);
await db.run("COMMIT");
const result = await db.query("select purchase_item($1, $2, $3)", [userId, itemPrice, storeItemId]);
return res.status(200).json({ "newItemId": result.rows[0].purchase_item});
} catch (error) {
await db.exec("ROLLBACK");
return res.status(400).json({ error: "Either Insufficient funds or item is already owned" });
// TODO: Need to add better error handling when the user dodn't have enough money
return res.status(400).json({ error: error.message});
}
return res.status(200).json({ message: "Item purchased successfully" });
} else if (req.method === "PUT") {
// Upgrade an existing item
const { userId } = req.query;
// TODO: We cannot trust the client to provide us with this info
const { inventoryItemId, storeItemId } = req.body;
const db = await dbConnection;
const invItem = await db.get(`SELECT id,tier,store_item_id FROM inventory_item
WHERE id = ? AND user_id = ?`, [inventoryItemId, userId]);
const storeItem = gameConfig.store.find((item) => item.id == storeItemId);
const storeItem = gameConfig.store.find((item) => item.id == invItem.store_item_id);
if (storeItem == undefined) {
return res.status(400).json({ error: "Item does not exist" });
}
const tier = invItem.tier;
// TODO: We don't have this data here
// const tier = storeItem.tier;
const tier = 1;
if (tier == undefined) {
return res.status(400).json({ error: "Item does not exist" });
}
if (tier >= storeItem.upgrades.length) {
return res.status(400).json({ error: "Max upgrade reached" });
}
const upgradePrice = storeItem.upgrades[tier].price;
try {
await db.run("BEGIN");
await db.run(`UPDATE bank_account SET balance = balance - ?
WHERE user_id = ?`, [upgradePrice, userId]);
await db.run(`UPDATE inventory_item SET tier = tier + 1 WHERE id = ?`, [inventoryItemId]);
await db.run("INSERT INTO upgrade_event(inventory_item_id) VALUES ( ? )", [invItem.store_item_id]);
await db.run("COMMIT");
const result = await db.query("SELECT upgrade_item($1, $2, $3)",
[userId, inventoryItemId, upgradePrice]);
return res.status(200).json({ message: `Upgraded item ${inventoryItemId}`,
upgradeEventId: result.rows[0].upgrade_item});
} catch (error) {
await db.exec("ROLLBACK");
return res.status(400).json({ error: "Insufficient funds" });
return res.status(400).json({ error: error.message});
}
return res.status(200).json({ message: "Successfully upgraded item" });
}
} catch (error) {
if(error instanceof Error){

View File

@ -1,4 +1,4 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
import { IInventoryItem } from "typings";
import {
@ -14,45 +14,15 @@ export default async function handler(
const { userId } = req.query;
const { stakingEventId } = req.body;
const db = await dbConnection;
try {
const stake = await db.get("SELECT * FROM staking_event WHERE id = ? AND user_id = ?",
[stakingEventId, userId]);
const db = postgresConnection;
const result = await db.query("SELECT * FROM claim($1, $2)", [userId, stakingEventId]);
if (stake == undefined) {
return res.status(400).json({error: "Could not find stake"});
}
const claim = await db.get("SELECT id FROM claim_event WHERE staking_event_id = ?",
[stakingEventId])
if (claim != undefined) {
return res.status(400).json({error: "Stake already claimed"});
}
const timeRemaining = calculateRemainingTime(stake.created_at, stake.duration_in_mins);
if (timeRemaining > 0) {
return res.status(400).json({error: "Staking period has not ended"});
}
const well = await db.get("SELECT id,resname,supply FROM resource_well WHERE id = ?",
[stake.well_id])
const claimAmount = stake.stake_amount > well.supply ? well.supply : stake.stake_amount;
await db.run("BEGIN");
await db.run("INSERT INTO claim_event(staking_event_id, claim_amount) VALUES (?, ?)",
[stake.id, claimAmount])
console.log(well.id);
const r1 = await db.run(`UPDATE resource_well SET supply = supply - ? WHERE id = ?`,
[claimAmount, well.id]);
console.log(stake.user_id, well.resname);
const r2 = await db.run(`UPDATE resource_account SET balance = balance + ?
WHERE user_id = ? AND resname = ?`, [claimAmount, stake.user_id, well.resname]);
await db.run("COMMIT");
// console.log(result.rows[0].claim);
return res.status(200).json({claimEventId: result.rows[0].claim});
} catch (error) {
await db.exec("ROLLBACK");
return res.status(400).json({ error: error.message});
return res.status(400).json({error: error.message});
}
return res.status(200).json({result: "Successfully claimed stake"});
}
} catch (error) {
res.status(500).json(error);

View File

@ -1,4 +1,4 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
import { IInventoryItem } from "typings";
import { updateAllToCamelCase } from "@/utils/helpers";
@ -10,25 +10,13 @@ export default async function handler(
try {
if (req.method === "GET") {
const { userId } = req.query;
const db = await dbConnection;
// This is supposed to be activeStakes?
const inventorySql = `
SELECT staking_event.id, staking_source.id as sourceId, resname as resourceType,
inventory_item_id, duration_in_mins, stake_amount, staking_event.created_at,
CASE WHEN claim_event.staking_event_id IS NULL THEN 1 ELSE 0 END AS unclaimed
FROM staking_event
INNER JOIN resource_well ON well_id = resource_well.id
INNER JOIN staking_source ON source_id = staking_source.id
LEFT JOIN claim_event ON staking_event.id = claim_event.staking_event_id
WHERE staking_event.user_id = ?`;
const inventoryItems = await db.all(inventorySql, [userId]);
const db = postgresConnection;
// Change all keys to camelCase
// const updatedInventoryItems = updateAllToCamelCase(inventoryItems)
const result = await db.query("SELECT * FROM get_all_stakes($1)", [userId]);
return res.status(200).json(inventoryItems);
return res.status(200).json({stakes: result.rows});
}
} catch (error) {
res.status(500).json(error);
res.status(500).json(error.message);
}
}

View File

@ -1,4 +1,4 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
import {
calculateRemainingTime,
@ -15,66 +15,49 @@ export default async function handler(
const { userId } = req.query;
const {
inventoryItemId,
wellId,
storeItemId,
wellId
} = req.body;
console.log(`Start take: inventoryItemId: ${inventoryItemId} | wellId: ${wellId}`)
const db = await dbConnection;
const db = postgresConnection;
try {
const inventorySql = `
SELECT inventory_item.id, tier, store_item_id, staking_event.id as stakeId,
staking_event.created_at as stakeTime, duration_in_mins, stake_amount
FROM inventory_item
LEFT JOIN staking_event ON inventory_item_id = inventory_item.id
WHERE inventory_item.id = ? AND inventory_item.user_id = ?
ORDER BY staking_event.created_at;
`;
const invItem = await db.get(inventorySql, [inventoryItemId, userId]);
const well = await db.get(`
SELECT resource_well.id, resname, source_id, supply as wellId FROM resource_well
INNER JOIN staking_source ON source_id = staking_source.id
WHERE resource_well.id = ? AND user_id = ?;
`, [wellId, userId]);
if (well == undefined) {
return res.status(400).json({error: `Well ${wellId} not found`});
}
const item = gameConfig.store.find((i) => i.id == invItem.store_item_id);
if (invItem == undefined || well == undefined || item == undefined) {
const item = gameConfig.store.find((i) => i.id == storeItemId);
if (item == undefined) {
return res.status(400).json({ error: "A resource was not found" });
}
if (invItem.stakeId != undefined) {
const timeRemaining = calculateRemainingTime(invItem.stakeTime, invItem.duration_in_mins);
console.log(timeRemaining);
if (timeRemaining > 0) {
return res.status(400).json({error: `Item is still in use ${timeRemaining}`});
}
}
const result =
await db.query("SELECT * FROM stake($1, $2, $3, $4, $5) AS stake",
[ userId,
wellId,
inventoryItemId,
item.completionTimeInMins,
item.claimAmount]);
const boost = invItem.tier > 0 ? item.upgrades[invItem.tier - 1].claimBoost : 0;
const totalClaim = item.claimAmount + boost;
console.log(userId + " " + well.id + " " + invItem.id)
await db.run(`INSERT INTO staking_event(user_id, well_id, inventory_item_id, duration_in_mins, stake_amount)
VALUES (?,?,?,?,?)`,
[userId, well.id, invItem.id, item.completionTimeInMins, totalClaim]);
return res.status(200).json({stakingEventId: result.rows[0].stake});
// if (invItem.stakeId != undefined) {
// const timeRemaining = calculateRemainingTime(invItem.stakeTime, invItem.duration_in_mins);
// if (timeRemaining > 0) {
// return res.status(400).json({error: `Item is still in use ${timeRemaining}`});
// }
// }
// const boost = invItem.tier > 0 ? item.upgrades[invItem.tier - 1].claimBoost : 0;
// const totalClaim = item.claimAmount + boost;
// await db.run(`INSERT INTO staking_event(user_id, well_id, inventory_item_id, duration_in_mins, stake_amount)
// VALUES (?,?,?,?,?)`,
// [userId, well.id, invItem.id, item.completionTimeInMins, totalClaim]);
} catch (error) {
if(error instanceof Error){
return res.status(400).json({ error: error.message});
}else {
return res.status(400).json({ error: "Unknown Error"});
}
}
return res.status(200).json({result: "Successfully started a stake"});
}
} catch (error) {
if(error instanceof Error){
if (error instanceof Error){
res.status(500).json(error.message);
}else {
} else {
res.status(500).json({ error: "Unknown Error"});
}
}

View File

@ -1,8 +1,7 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
import { IStakingSource } from "typings";
import { gameConfig } from "@/utils/gameLogic";
import { updateAllToCamelCase } from "@/utils/helpers";
import {
generateRandomBase64String,
} from "../../../../utils/helpers";
@ -12,66 +11,54 @@ export default async function handler(
res: NextApiResponse
) {
try {
const db = postgresConnection;
if (req.method === "GET") {
const { userId } = req.query;
const db = await dbConnection;
const sourcesSql = `
SELECT id, name, description FROM staking_source
WHERE staking_source.user_id = ?`;
const stakingSources = await db.all(sourcesSql, [userId]);
for (const source of stakingSources) {
const wellsSql = `
SELECT id, resname as resourceType, supply FROM resource_well
WHERE source_id = ?`;
const resourceWells = await db.all(wellsSql, [source.id]);
source.resourceWells = resourceWells;
const stakesSql = `
SELECT staking_event.id, resname as resourceType, source_id as stakingSourceId,
inventory_item_id as inventoryItemId, duration_in_mins as durationInMins,
stake_amount as stakeAmount, staking_event.created_at as startTime
FROM staking_event
INNER JOIN resource_well ON well_id = resource_well.id
INNER JOIN staking_source ON source_id = staking_source.id
LEFT JOIN claim_event ON staking_event.id = claim_event.staking_event_id
WHERE staking_source.id = ? AND claim_event.staking_event_id IS NULL;`;
const activeStakes = await db.all(stakesSql, [source.id]);
source.activeStakes = activeStakes;
}
const results = await db.query({ text: "SELECT * from get_staking_sources($1)",
values: [userId], rowMode: 'array' });
// TODO: Do it this way until we get an ORM working, I guess
const stakingSources: IStakingSource[] = results.rows.map(row => {
return {
id: row[0],
name: row[1],
description: row[2],
resourceWells: row[3],
activeStakes: row[4]
};
});
return res.status(200).json({ "stakingSources": stakingSources });
} else if (req.method === "POST") {
return res.status(200).json(stakingSources);
}
if (req.method === "POST") {
const { userId } = req.query;
const db = await dbConnection;
try {
const randomName = "Moon 1";
const randomDescription = "This is a moon orbiting Selene's planet";
const randomKey = "0x" + generateRandomBase64String(16);
const randomDesc = "This is a moon orbiting Selene's planet";
const randomAddr = "0x" + generateRandomBase64String(16);
const resMax = gameConfig.moons.resourceMaxStartAmount;
const resMin = gameConfig.moons.resourceMinStartAmount;
const moonPrice = gameConfig.moons.price;
await db.run("BEGIN");
await db.run(`UPDATE bank_account SET balance = balance - ?
WHERE user_id = ?`, [moonPrice, userId]);
const result = await db.run(`INSERT INTO staking_source(user_id, name, description, address)
VALUES (?, ?, ?, ?)`, [userId, randomName, randomDescription, randomKey]);
const sourceId = result.lastID;
for (const resname of gameConfig.resources) {
if (Math.random() < gameConfig.moons.resourceChance) {
const randomNumber = Math.random();
const range = resMax - resMin + 1;
const initSupply = Math.floor(Math.random() * range + resMin);
await db.run(`INSERT INTO resource_well (source_id, resname, supply)
VALUES (?, ?, ?)`, [sourceId, resname, initSupply]);
const result = await db.query(
"SELECT * FROM create_staking_source($1, $2, $3, $4, $5, $6, $7)",
[ userId,
randomName,
randomDesc,
randomAddr,
moonPrice,
resMin,
resMax ]);
if (result.rows.length > 0) {
return res.status(200).json({"stakingSourceId": result.rows[0].create_staking_source});
} else {
return res.status(400).json({"error": "Something happened and I don't know what"});
}
}
await db.run("COMMIT");
return res.status(200).json({"stakingSourceId": sourceId});
} catch (error) {
await db.exec("ROLLBACK");
// TODO: Have to change this to match postgres' error or figure out a way to explicitly
// return this message from the postgres function
if (error.message.includes("CHECK constraint failed")) {
return res.status(400).json({ "error": "Insuficcient funds" });
} else {

View File

@ -0,0 +1,25 @@
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
export default async function handler(
req: NextApiRequest,
res: NextApiResponse
) {
try {
if (req.method === "GET") {
const db = postgresConnection;
const result = await db.query("SELECT wallet FROM users WHERE id = $1", [
req.query.userId,
]);
if (result.rowCount > 0) {
return res.status(200).json({ wallet: result.rows[0].wallet });
} else {
return res.status(404).json({ message: "User not found" });
}
}
} catch (error) {
res.status(500).json(error);
}
}

View File

@ -1,4 +1,4 @@
import { dbConnection } from "db";
import { postgresConnection } from "db";
import type { NextApiRequest, NextApiResponse } from "next";
export default async function handler(
@ -8,17 +8,13 @@ export default async function handler(
try {
if (req.method === "POST") {
const { wallet } = req.body;
// const db = await dbConnection;
// const user = await db.get("SELECT id FROM users WHERE wallet = ?", [wallet]);
// Comment me out
return res.status(200).json({ userId: 1});
/* if (user != undefined) {
return res.status(200).json({ userId: user.id});
const db = postgresConnection;
const result = await db.query("SELECT id FROM users WHERE wallet = $1", [wallet]);
if (result.rowCount > 0) {
return res.status(200).json({ userId: result.rows[0].id});
} else {
return res.status(404).json({ message: "User not found" });
} */
}
}
} catch (error) {
res.status(500).json(error);

View File

@ -44,6 +44,11 @@ export function resourceToFc(resourceName: string): string {
return mapping[resourceName]
}
export function checkIfValidUUID(uuid: string): bool {
const regexExp = /^[0-9a-fA-F]{8}\b-[0-9a-fA-F]{4}\b-[0-9a-fA-F]{4}\b-[0-9a-fA-F]{4}\b-[0-9a-fA-F]{12}$/gi;
return regexExp.test(uuid);
}
export function notificationTypeToBg(type: string): string {
const mapping: IMapping = {

View File

@ -1,6 +1,7 @@
:headers = <<
Content-Type: application/json
#
:user_id = 595ab570-fa74-4c6c-980e-4c80d1064dd1
# Get Inventory Items
GET http://localhost:3000/api/seed
@ -11,42 +12,42 @@ POST http://localhost:3000/api/user/login
:headers
{ "wallet" : "Wallet12345678" }
# Get Inventory Items
GET http://localhost:3000/api/user/1/bank-account
# Get bank account
GET http://localhost:3000/api/user/:user_id/bank-account
:headers
# Get Staking Sources
GET http://localhost:3000/api/user/:user_id/staking-sources
:headers
# Create a new staking source
POST http://localhost:3000/api/user/:user_id/staking-sources
:headers
# Get Inventory Items
GET http://localhost:3000/api/user/1/staking-sources
:headers
# Get Inventory Items
POST http://localhost:3000/api/user/1/staking-sources
:headers
# Get Inventory Items
GET http://localhost:3000/api/user/1/inventory-items
GET http://localhost:3000/api/user/:user_id/inventory-items
:headers
# Buy a new Item
POST http://localhost:3000/api/user/1/inventory-items/
POST http://localhost:3000/api/user/:user_id/inventory-items/
:headers
{ "itemId" : "item3" }
{ "storeItemId" : "item1" }
# Upgrade an owned item
PUT http://localhost:3000/api/user/1/inventory-items/
PUT http://localhost:3000/api/user/:user_id/inventory-items/
:headers
{ "itemId" : 1 }
{ "storeItemId" : "item3", "inventoryItemId": 3 }
# Get stakes
GET http://localhost:3000/api/user/1/stakes/
GET http://localhost:3000/api/user/:user_id/stakes/
:headers
# Start a stake
POST http://localhost:3000/api/user/1/stakes/start
POST http://localhost:3000/api/user/:user_id/stakes/start
:headers
{ "inventoryItemId": 1, "wellId": 1 }
{ "inventoryItemId": 3, "storeItemId": "item3", "wellId": 1 }
# Claim a stake
POST http://localhost:3000/api/user/1/stakes/claim
POST http://localhost:3000/api/user/:user_id/stakes/claim
:headers
{ "stakingEventId" : 4 }
{ "stakingEventId" : 3 }

12
typings.d.ts vendored
View File

@ -36,6 +36,18 @@ export interface IStakingSource {
activeStakes: IStake[];
}
export interface IStoreStakingSource {
id: number;
name: string;
description: string;
image: string
price: number
resourceChance: number
resourceMinStartAmount: number
resourceMaxStartAmount: number
}
export interface IInventoryItem {
id: number;
storeItem: IStoreItem;