feat: postgres migration
continuous-integration/drone/push Build is passing Details

This commit is contained in:
Timo Ley 2023-07-06 17:35:23 +02:00
parent 9bed0de064
commit 46773e9d17
8 changed files with 44 additions and 69 deletions

View File

@ -14,7 +14,7 @@ tower = { version = "0.4", features = ["util", "timeout"] }
tower-http = { version = "0.1", features = ["add-extension", "trace", "fs", "set-header"] }
serde = { version = "1.0", features = ["derive"] }
serde_json = "1.0.51"
sqlx = { version = "0.3", features = [ "mysql" ] }
sqlx = { version = "0.3", features = [ "postgres" ] }
rand = "0.8.0"
structopt = "0.3.22"
toml = "0.5.8"

View File

@ -1,4 +1,4 @@
CREATE TABLE IF NOT EXISTS categories (num INT UNIQUE NOT NULL , id varchar(255) NOT NULL , name TEXT, PRIMARY KEY (id));
CREATE TABLE IF NOT EXISTS users (id varchar(255) NOT NULL, name TEXT, authsource JSON, PRIMARY KEY (id));
CREATE TABLE IF NOT EXISTS memes (id INT NOT NULL AUTO_INCREMENT, filename varchar(255) NOT NULL, user varchar(255) NOT NULL, category varchar(255), timestamp DATETIME, ip varchar(255), cid varchar(255) NOT NULL, PRIMARY KEY (id), FOREIGN KEY (category) REFERENCES categories(id), FOREIGN KEY (user) REFERENCES users(id));
CREATE TABLE IF NOT EXISTS memes (id SERIAL, filename varchar(255) NOT NULL, userid varchar(255) NOT NULL, category varchar(255), timestamp TIMESTAMP, ip varchar(255), cid varchar(255) NOT NULL, PRIMARY KEY (id), FOREIGN KEY (category) REFERENCES categories(id), FOREIGN KEY (userid) REFERENCES users(id));
CREATE TABLE IF NOT EXISTS token (uid varchar(255) UNIQUE NOT NULL, token varchar(255), FOREIGN KEY (uid) REFERENCES users(id));

View File

@ -1,28 +1,28 @@
use sqlx::{mysql::MySqlRow, MySqlPool, Result, Row};
use sqlx::{postgres::PgRow, PgPool, Result, Row};
pub async fn get_cid(user: String, filename: String, pool: &MySqlPool) -> Result<String> {
pub async fn get_cid(user: String, filename: String, pool: &PgPool) -> Result<String> {
let q: String =
sqlx::query("SELECT cid FROM memes WHERE user = ? AND filename = ? ORDER BY id DESC")
.bind(user)
.bind(filename)
.map(|row: MySqlRow| row.get("cid"))
.map(|row: PgRow| row.get("cid"))
.fetch_one(pool)
.await?;
Ok(q)
}
pub async fn get_memes(user: String, pool: &MySqlPool) -> Result<Vec<String>> {
pub async fn get_memes(user: String, pool: &PgPool) -> Result<Vec<String>> {
let q: Vec<String> = sqlx::query("SELECT filename FROM memes WHERE user = ? ORDER BY filename")
.bind(user)
.map(|row: MySqlRow| row.get("filename"))
.map(|row: PgRow| row.get("filename"))
.fetch_all(pool)
.await?;
Ok(q)
}
pub async fn get_users(pool: &MySqlPool) -> Result<Vec<String>> {
pub async fn get_users(pool: &PgPool) -> Result<Vec<String>> {
let q: Vec<String> = sqlx::query("SELECT id FROM users ORDER BY id")
.map(|row: MySqlRow| row.get("id"))
.map(|row: PgRow| row.get("id"))
.fetch_all(pool)
.await?;
Ok(q)

View File

@ -1,6 +1,6 @@
use reqwest::Url;
use serde::Deserialize;
use sqlx::MySqlPool;
use sqlx::PgPool;
use std::{net::SocketAddr, sync::Arc};
use crate::{error::JMError, JMService, JMServiceInner};
@ -17,7 +17,7 @@ pub struct Config {
}
impl Config {
pub fn service(&self, db_pool: MySqlPool) -> Result<JMService, JMError> {
pub fn service(&self, db_pool: PgPool) -> Result<JMService, JMError> {
let client = reqwest::ClientBuilder::new().user_agent("curl").build()?;
Ok(Arc::new(JMServiceInner {
client,

View File

@ -6,7 +6,7 @@ use axum::{
use config::Config;
use error::JMError;
use reqwest::{Client, Url};
use sqlx::MySqlPool;
use sqlx::PgPool;
use std::{path::PathBuf, sync::Arc};
use structopt::StructOpt;
use tower_http::{add_extension::AddExtensionLayer, set_header::SetResponseHeaderLayer};
@ -35,7 +35,7 @@ struct Opt {
pub struct JMServiceInner {
client: Client,
db_pool: MySqlPool,
db_pool: PgPool,
ipfs_url: Url,
cdn_url: String,
matrix_url: Url,
@ -51,7 +51,7 @@ async fn main() -> Result<(), JMError> {
let config = std::fs::read(&opt.config)?;
let config = toml::from_slice::<Config>(&config)?;
let db_pool = MySqlPool::new(&config.database).await?;
let db_pool = PgPool::new(&config.database).await?;
let service = config.service(db_pool)?;
let app = Router::new()

View File

@ -38,7 +38,7 @@ impl JMServiceInner {
filename: String,
cid: String,
user: String,
id: u64,
id: u32,
) -> Result<(), ServiceError> {
let meme = Meme {
category,

View File

@ -1,42 +1,17 @@
use crate::ipfs::IPFSFile;
use crate::models::{Category, Count, Meme, MemeOptions, User, UserIdentifier};
use crate::JMServiceInner;
use sqlx::mysql::MySqlRow;
use sqlx::{MySqlPool, Result, Row};
impl Category {
pub async fn add_meme(
&self,
user: &User,
file: &IPFSFile,
ip: &String,
pool: &MySqlPool,
) -> Result<u64> {
let mut tx = pool.begin().await?;
sqlx::query("INSERT INTO memes (filename, user, category, timestamp, ip, cid) VALUES (?, ?, ?, NOW(), ?, ?)")
.bind(&file.name)
.bind(&user.id)
.bind(&self.id)
.bind(ip)
.bind(&file.hash)
.execute(&mut tx).await?;
let id: u64 = sqlx::query("SELECT LAST_INSERT_ID() as id")
.map(|row: MySqlRow| row.get("id"))
.fetch_one(&mut tx)
.await?;
tx.commit().await?;
Ok(id)
}
}
use sqlx::postgres::PgRow;
use sqlx::{Result, Row};
impl JMServiceInner {
pub async fn get_meme(&self, id: i32) -> Result<Option<Meme>> {
let q: Option<Meme> = sqlx::query("SELECT memes.id, user, filename, category, name, UNIX_TIMESTAMP(timestamp) AS ts, cid FROM memes, users WHERE memes.user = users.id AND memes.id=?").bind(id)
.map(|row: MySqlRow| Meme {
let q: Option<Meme> = sqlx::query("SELECT memes.id, userid, filename, category, name, extract(epoch FROM timestamp) AS ts, cid FROM memes, users WHERE memes.userid = users.id AND memes.id=?").bind(id)
.map(|row: PgRow| Meme {
id: row.get("id"),
filename: row.get("filename"),
username: row.get("name"),
userid: row.get("user"),
userid: row.get("userid"),
category: row.get("category"),
timestamp: row.get("ts"),
ipfs: row.get("cid"),
@ -46,18 +21,18 @@ impl JMServiceInner {
}
pub async fn get_memes(&self, filter: MemeOptions) -> Result<Vec<Meme>> {
let q: Vec<Meme> = sqlx::query("SELECT memes.id, user, filename, category, name, UNIX_TIMESTAMP(timestamp) AS ts, cid FROM memes, users WHERE memes.user = users.id AND (category LIKE ? AND name LIKE ? AND filename LIKE ? AND memes.user LIKE ? AND memes.id > ?) ORDER BY memes.id LIMIT ?")
let q: Vec<Meme> = sqlx::query("SELECT memes.id, userid, filename, category, name, extract(epoch FROM timestamp) AS ts, cid FROM memes, users WHERE memes.userid = users.id AND (category LIKE ? AND name LIKE ? AND filename LIKE ? AND memes.userid LIKE ? AND memes.id > ?) ORDER BY memes.id LIMIT ?")
.bind(filter.category.unwrap_or_else(|| String::from("%")))
.bind(format!("%{}%", filter.username.unwrap_or_default()))
.bind(format!("%{}%", filter.search.unwrap_or_default()))
.bind(filter.user_id.unwrap_or_else(|| String::from("%")))
.bind(filter.after.unwrap_or(0))
.bind(filter.limit.unwrap_or(100))
.map(|row: MySqlRow| Meme {
.map(|row: PgRow| Meme {
id: row.get("id"),
filename: row.get("filename"),
username: row.get("name"),
userid: row.get("user"),
userid: row.get("userid"),
category: row.get("category"),
timestamp: row.get("ts"),
ipfs: row.get("cid"),
@ -67,17 +42,17 @@ impl JMServiceInner {
}
pub async fn get_random_meme(&self, filter: MemeOptions) -> Result<Meme> {
let q: Meme = sqlx::query("SELECT memes.id, user, filename, category, name, UNIX_TIMESTAMP(timestamp) AS ts, cid FROM memes, users WHERE memes.user = users.id AND (category LIKE ? AND name LIKE ? AND filename LIKE ? AND memes.user LIKE ? AND memes.id > ?) ORDER BY RAND() LIMIT 1")
let q: Meme = sqlx::query("SELECT memes.id, userid, filename, category, name, extract(epoch FROM timestamp) AS ts, cid FROM memes, users WHERE memes.userid = users.id AND (category LIKE ? AND name LIKE ? AND filename LIKE ? AND memes.userid LIKE ? AND memes.id > ?) ORDER BY RAND() LIMIT 1")
.bind(filter.category.unwrap_or_else(|| String::from("%")))
.bind(format!("%{}%", filter.username.unwrap_or_default()))
.bind(format!("%{}%", filter.search.unwrap_or_default()))
.bind(filter.user_id.unwrap_or_else(|| String::from("%")))
.bind(filter.after.unwrap_or(0))
.map(|row: MySqlRow| Meme {
.map(|row: PgRow| Meme {
id: row.get("id"),
filename: row.get("filename"),
username: row.get("name"),
userid: row.get("user"),
userid: row.get("userid"),
category: row.get("category"),
timestamp: row.get("ts"),
ipfs: row.get("cid"),
@ -88,11 +63,11 @@ impl JMServiceInner {
pub async fn count_memes(&self, filter: MemeOptions) -> Result<Count> {
let q: Count = sqlx::query(
"SELECT COUNT(id) AS count FROM memes WHERE category LIKE ? AND user LIKE ?",
"SELECT COUNT(id) AS count FROM memes WHERE category LIKE ? AND userid LIKE ?",
)
.bind(filter.category.unwrap_or_else(|| String::from("%")))
.bind(filter.user_id.unwrap_or_else(|| String::from("%")))
.map(|row: MySqlRow| Count {
.map(|row: PgRow| Count {
count: row.get("count"),
})
.fetch_one(&self.db_pool)
@ -101,14 +76,14 @@ impl JMServiceInner {
}
pub async fn get_user_meme(&self, user_id: String, filename: String) -> Result<Option<Meme>> {
let q: Option<Meme> = sqlx::query("SELECT memes.id, user, filename, category, name, UNIX_TIMESTAMP(timestamp) AS ts, cid FROM memes, users WHERE memes.user = users.id AND memes.user = ? AND filename = ? ORDER BY memes.id DESC")
let q: Option<Meme> = sqlx::query("SELECT memes.id, userid, filename, category, name, extract(epoch FROM timestamp) AS ts, cid FROM memes, users WHERE memes.userid = users.id AND memes.userid = ? AND filename = ? ORDER BY memes.id DESC")
.bind(user_id)
.bind(filename)
.map(|row: MySqlRow| Meme {
.map(|row: PgRow| Meme {
id: row.get("id"),
filename: row.get("filename"),
username: row.get("name"),
userid: row.get("user"),
userid: row.get("userid"),
category: row.get("category"),
timestamp: row.get("ts"),
ipfs: row.get("cid"),
@ -120,7 +95,7 @@ impl JMServiceInner {
pub async fn get_category(&self, id: &String) -> Result<Option<Category>> {
let q: Option<Category> = sqlx::query("SELECT * FROM categories WHERE id=?")
.bind(id)
.map(|row: MySqlRow| Category {
.map(|row: PgRow| Category {
id: row.get("id"),
name: row.get("name"),
})
@ -131,7 +106,7 @@ impl JMServiceInner {
pub async fn get_categories(&self) -> Result<Vec<Category>> {
let q: Vec<Category> = sqlx::query("SELECT * FROM categories ORDER BY num")
.map(|row: MySqlRow| Category {
.map(|row: PgRow| Category {
id: row.get("id"),
name: row.get("name"),
})
@ -142,13 +117,13 @@ impl JMServiceInner {
pub async fn get_user(&self, identifier: UserIdentifier) -> Result<Option<User>> {
let query = match identifier {
UserIdentifier::Id(id) => sqlx::query("SELECT id, name, IFNULL(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, IFNULL(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT user, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (user)) AS count ON users.id = count.user) AS users LEFT JOIN token ON users.id = token.uid WHERE users.id = ?").bind(id),
UserIdentifier::Token(token) => sqlx::query("SELECT id, name, IFNULL(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, IFNULL(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT user, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (user)) AS count ON users.id = count.user) AS users LEFT JOIN token ON users.id = token.uid WHERE token = ?").bind(token),
UserIdentifier::Username(name) => sqlx::query("SELECT id, name, IFNULL(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, IFNULL(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT user, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (user)) AS count ON users.id = count.user) AS users LEFT JOIN token ON users.id = token.uid WHERE name = ?").bind(name),
UserIdentifier::Id(id) => sqlx::query("SELECT id, name, COALESCE(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, COALESCE(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT userid, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (userid)) AS count ON users.id = count.userid) AS users LEFT JOIN token ON users.id = token.uid WHERE users.id = ?").bind(id),
UserIdentifier::Token(token) => sqlx::query("SELECT id, name, COALESCE(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, COALESCE(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT userid, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (userid)) AS count ON users.id = count.userid) AS users LEFT JOIN token ON users.id = token.uid WHERE token = ?").bind(token),
UserIdentifier::Username(name) => sqlx::query("SELECT id, name, COALESCE(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, COALESCE(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT userid, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (userid)) AS count ON users.id = count.userid) AS users LEFT JOIN token ON users.id = token.uid WHERE name = ?").bind(name),
UserIdentifier::Null => sqlx::query("SELECT id, name, '0' AS hash, 0 AS uploads FROM users WHERE id = '000'"),
};
let q: Option<User> = query
.map(|row: MySqlRow| User {
.map(|row: PgRow| User {
id: row.get("id"),
name: row.get("name"),
userdir: row.get("id"),
@ -161,8 +136,8 @@ impl JMServiceInner {
}
pub async fn get_users(&self) -> Result<Vec<User>> {
let q: Vec<User> = sqlx::query("SELECT id, name, IFNULL(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, IFNULL(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT user, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURDATE() GROUP BY (user)) AS count ON users.id = count.user) AS users LEFT JOIN token ON users.id = token.uid")
.map(|row: MySqlRow| User {
let q: Vec<User> = sqlx::query("SELECT id, name, COALESCE(MD5(token), '0') AS hash, uploads FROM (SELECT id, name, COALESCE(count.uploads, 0) AS uploads FROM users LEFT JOIN (SELECT userid, COUNT(*) AS uploads FROM memes WHERE DATE(timestamp) = CURRENT_DATE GROUP BY (userid)) AS count ON users.id = count.userid) AS users LEFT JOIN token ON users.id = token.uid")
.map(|row: PgRow| User {
id: row.get("id"),
name: row.get("name"),
userdir: row.get("id"),
@ -184,17 +159,17 @@ impl JMServiceInner {
file: &IPFSFile,
ip: &String,
category: &Category,
) -> Result<u64> {
) -> Result<u32> {
let mut tx = self.db_pool.begin().await?;
sqlx::query("INSERT INTO memes (filename, user, category, timestamp, ip, cid) VALUES (?, ?, ?, NOW(), ?, ?)")
sqlx::query("INSERT INTO memes (filename, userid, category, timestamp, ip, cid) VALUES (?, ?, ?, NOW(), ?, ?)")
.bind(&file.name)
.bind(&user.id)
.bind(&category.id)
.bind(ip)
.bind(&file.hash)
.execute(&mut tx).await?;
let id: u64 = sqlx::query("SELECT LAST_INSERT_ID() as id")
.map(|row: MySqlRow| row.get("id"))
let id: u32 = sqlx::query("SELECT LASTVAL() as id")
.map(|row: PgRow| row.get("id"))
.fetch_one(&mut tx)
.await?;
tx.commit().await?;

View File

@ -139,7 +139,7 @@ impl From<MemeFilter> for MemeOptions {
user_id: None,
username: filter.user,
search: filter.search,
limit: Some(-1),
limit: Some(100000), //TODO: find postgres compatible default value
after: None,
}
}