feat: add gists_gists, gists_comments and gists_comments & related methods

The following changes are implemented for both db-sqlx-postgres and
db-sqlx-sqlite:

TABLE gists_gists
    Stores gist metadata with unique index on gists_gists.public_id for fast
    lookups

TABLE gists_comments
    Stores comment metadata

TABLE gists_privacy
    Stores gist privacy: sqlx currently doesn't have support Postgres
    enums(ref: https://github.com/launchbadge/sqlx/issues/1171), so storing
    possible privacy values as references from this table.

    This table shouldn't be mutated during runtime. Possible values are
    already recorded in database during migrations. All runtime operations
    on this table must only take references.

    Each implementation of GistDatabase also includes a method called
    privacy_exists, which is called during tests to ensure that
    migrations are successful.

VIEW gists_gists_view
    Gist lookups combines data from gists_users, gists_gists and
    gists_privacy. This SQL view boots performance(I think?). At any rate,
    it is much nicer to work with.

QUIRKS
    Database indexes are i64 in SQLite while i32 in Postgres
master
Aravinth Manivannan 2022-02-14 19:59:32 +05:30
parent e96550b6c0
commit 6b60e2a064
Signed by: realaravinth
GPG Key ID: AD9F0F08E855ED88
22 changed files with 1632 additions and 214 deletions

View File

@ -5,6 +5,7 @@ clean: ## Clean all build artifacts and dependencies
@-/bin/rm -rf target/
@-/bin/rm -rf database/migrator/target/
@-/bin/rm -rf database/*/target/
@-/bin/rm -rf database/*/tmp/
@cargo clean
coverage: migrate ## Generate coverage report in HTML format

View File

@ -2,7 +2,7 @@
<h1> Gists </h1>
<p>
**Self-Hosted GitHub Gists\***
**Self-Hosted GitHub Gists**
</p>
@ -33,4 +33,4 @@ can rival GitHub Gists.
1. All configuration is done through
[./config/default.toml](./config/default.toml)(can be moved to
`/etc/static-gists/config.toml`).
`/etc/gists/config.toml`).

View File

@ -19,16 +19,29 @@ pub enum DBError {
#[error("Email not available")]
DuplicateEmail,
/// Gist public ID taken
#[error("Gist ID not available")]
GistIDTaken,
/// Account with specified characteristics not found
#[error("Account with specified characteristics not found")]
AccountNotFound,
// /// errors that are specific to a database implementation
// #[error("Database error: {:?}", _0)]
// DBError(#[error(not(source))] String),
/// errors that are specific to a database implementation
#[error("{0}")]
DBError(#[source] BoxDynError),
/// email is already taken
#[error("Unknown privacy specifier {}", _0)]
UnknownPrivacySpecifier(String),
/// Gist with specified characteristics not found
#[error("Gist with specified characteristics not found")]
GistNotFound,
/// Comment with specified characteristics not found
#[error("Comment with specified characteristics not found")]
CommentNotFound,
}
/// Convenience type alias for grouping driver-specific errors

View File

@ -51,6 +51,108 @@ pub struct Password {
pub password: String,
}
#[derive(Clone, Debug)]
/// Data required to create a gist in DB
/// creation date defaults to time at which creation method is called
pub struct CreateGist {
/// owner of the gist
pub owner: String,
/// description of the gist
pub description: Option<String>,
/// public ID of the gist
pub public_id: String,
/// gist privacy
pub privacy: GistPrivacy,
}
/// Gist privacy
#[derive(Clone, PartialEq, Debug)]
pub enum GistPrivacy {
/// Everyone can see the gist, will be displayed on /explore and
/// search engines might index it too
Public,
/// Everyone with the link can see it, won't be listed on /explore and
/// search engines won't index them
Unlisted,
/// Only the owner can see gist
Private,
}
impl GistPrivacy {
/// Convert [GistPrivacy] to [str]
pub const fn to_str(&self) -> &'static str {
match self {
GistPrivacy::Private => "private",
GistPrivacy::Unlisted => "unlisted",
GistPrivacy::Public => "public",
}
}
/// Convert [str] to [GistPrivacy]
pub fn from_str(s: &str) -> DBResult<Self> {
const PRIVATE: &str = GistPrivacy::Private.to_str();
const PUBLIC: &str = GistPrivacy::Public.to_str();
const UNLISTED: &str = GistPrivacy::Unlisted.to_str();
let s = s.trim();
match s {
PRIVATE => Ok(Self::Private),
PUBLIC => Ok(Self::Public),
UNLISTED => Ok(Self::Unlisted),
_ => Err(DBError::UnknownPrivacySpecifier(s.to_owned())),
}
}
}
impl From<GistPrivacy> for String {
fn from(gp: GistPrivacy) -> String {
gp.to_str().into()
}
}
#[derive(Clone, Debug)]
/// Represents a gist
pub struct Gist {
/// owner of the gist
pub owner: String,
/// description of the gist
pub description: Option<String>,
/// public ID of the gist
pub public_id: String,
/// gist creation time
pub created: i64,
/// gist updated time
pub updated: i64,
/// gist privacy
pub privacy: GistPrivacy,
}
#[derive(Clone, Debug)]
/// Represents a comment on a Gist
pub struct GistComment {
/// Unique identifier, possible database assigned, auto-incremented ID
pub id: i64,
/// owner of the comment
pub owner: String,
/// public ID of the gist on which this comment was made
pub gist_public_id: String,
/// comment text
pub comment: String,
/// comment creation time
pub created: i64,
}
#[derive(Clone, Debug)]
/// Data required to create a comment on a Gist
/// creation date defaults to time at which creation method is called
pub struct CreateGistComment {
/// owner of the comment
pub owner: String,
/// public ID of the gist on which this comment was made
pub gist_public_id: String,
/// comment text
pub comment: String,
}
/// payload to register a user with username _and_ email
pub struct EmailRegisterPayload<'a> {
/// username of new user
@ -118,9 +220,33 @@ pub trait GistDatabase: std::marker::Send + std::marker::Sync + CloneGistDatabas
async fn email_register(&self, payload: &EmailRegisterPayload) -> DBResult<()>;
/// register with username
async fn username_register(&self, payload: &UsernameRegisterPayload) -> DBResult<()>;
/// ping DB
async fn ping(&self) -> bool;
/// Check if a Gist with the given ID exists
async fn gist_exists(&self, public_id: &str) -> DBResult<bool>;
/// Create new gists
async fn new_gist(&self, gist: &CreateGist) -> DBResult<()>;
/// Retrieve gist from database
async fn get_gist(&self, public_id: &str) -> DBResult<Gist>;
/// Retrieve gists belonging to user
async fn get_user_gists(&self, owner: &str) -> DBResult<Vec<Gist>>;
/// Delete gist
async fn delete_gist(&self, owner: &str, public_id: &str) -> DBResult<()>;
/// Create new comment
async fn new_comment(&self, comment: &CreateGistComment) -> DBResult<()>;
/// Get comments on a gist
async fn get_comments_on_gist(&self, public_id: &str) -> DBResult<Vec<GistComment>>;
/// Get a specific comment using its database assigned ID
async fn get_comment_by_id(&self, id: i64) -> DBResult<GistComment>;
/// Delete comment
async fn delete_comment(&self, owner: &str, id: i64) -> DBResult<()>;
/// check if privacy mode exists
async fn privacy_exists(&self, privacy: &GistPrivacy) -> DBResult<bool>;
}
#[async_trait]
@ -177,6 +303,46 @@ impl GistDatabase for Box<dyn GistDatabase> {
async fn ping(&self) -> bool {
(**self).ping().await
}
async fn gist_exists(&self, public_id: &str) -> DBResult<bool> {
(**self).gist_exists(public_id).await
}
async fn new_gist(&self, gist: &CreateGist) -> DBResult<()> {
(**self).new_gist(gist).await
}
async fn get_gist(&self, public_id: &str) -> DBResult<Gist> {
(**self).get_gist(public_id).await
}
async fn get_user_gists(&self, owner: &str) -> DBResult<Vec<Gist>> {
(**self).get_user_gists(owner).await
}
async fn delete_gist(&self, owner: &str, public_id: &str) -> DBResult<()> {
(**self).delete_gist(owner, public_id).await
}
async fn new_comment(&self, comment: &CreateGistComment) -> DBResult<()> {
(**self).new_comment(comment).await
}
async fn get_comments_on_gist(&self, public_id: &str) -> DBResult<Vec<GistComment>> {
(**self).get_comments_on_gist(public_id).await
}
async fn get_comment_by_id(&self, id: i64) -> DBResult<GistComment> {
(**self).get_comment_by_id(id).await
}
async fn delete_comment(&self, owner: &str, id: i64) -> DBResult<()> {
(**self).delete_comment(owner, id).await
}
async fn privacy_exists(&self, privacy: &GistPrivacy) -> DBResult<bool> {
(**self).privacy_exists(privacy).await
}
}
/// Trait to clone GistDatabase

View File

@ -39,6 +39,121 @@ pub async fn email_register_works<T: GistDatabase>(
assert!(matches!(err, Some(DBError::DuplicateEmail)));
}
/// test if all privacy modes are available on database
pub async fn privacy_works<T: GistDatabase>(db: &T) {
for p in [
GistPrivacy::Public,
GistPrivacy::Unlisted,
GistPrivacy::Private,
]
.iter()
{
println!("Testing privacy: {}", p.to_str());
assert!(db.privacy_exists(p).await.unwrap());
}
}
/// test all gist methods
pub async fn gists_work<T: GistDatabase>(
db: &T,
username: &str,
password: &str,
secret: &str,
public_id: &str,
) {
fn assert_comments(lhs: &CreateGistComment, rhs: &GistComment) {
println!("lhs: {:?} rhs: {:?}", lhs, rhs);
assert_eq!(rhs.owner, lhs.owner);
assert_eq!(rhs.comment, lhs.comment);
assert_eq!(rhs.gist_public_id, lhs.gist_public_id);
}
fn assert_gists(lhs: &CreateGist, rhs: &Gist) {
assert_eq!(lhs.description, rhs.description);
assert_eq!(lhs.owner, rhs.owner);
assert_eq!(lhs.public_id, rhs.public_id);
assert_eq!(lhs.privacy, rhs.privacy);
}
let _ = db.delete_account(username).await;
let register_payload = UsernameRegisterPayload {
username,
password,
secret,
};
db.username_register(&register_payload).await.unwrap();
let create_gist = CreateGist {
owner: username.into(),
description: Some("foo".to_string()),
public_id: public_id.to_string(),
privacy: GistPrivacy::Public,
};
assert!(!db.gist_exists(&create_gist.public_id).await.unwrap());
// create gist
assert!(db.get_user_gists(username).await.unwrap().is_empty());
db.new_gist(&create_gist).await.unwrap();
assert!(matches!(
db.new_gist(&create_gist).await.err(),
Some(DBError::GistIDTaken)
));
assert!(db.gist_exists(&create_gist.public_id).await.unwrap());
// get gist
let db_gist = db.get_gist(&create_gist.public_id).await.unwrap();
assert_gists(&create_gist, &db_gist);
let mut gists = db.get_user_gists(username).await.unwrap();
assert_eq!(gists.len(), 1);
let gist = gists.pop().unwrap();
assert_gists(&create_gist, &gist);
// comment on gist
let create_comment = CreateGistComment {
owner: username.into(),
gist_public_id: create_gist.public_id.clone(),
comment: "foo".into(),
};
db.new_comment(&create_comment).await.unwrap();
// get all comments on gist
let mut comments = db
.get_comments_on_gist(&create_gist.public_id)
.await
.unwrap();
assert!(comments.len() == 1);
let comment = comments.pop().unwrap();
assert_comments(&create_comment, &comment);
// get all comments by ID
let comment = db.get_comment_by_id(comment.id).await.unwrap();
assert_comments(&create_comment, &comment);
// delete comment
db.delete_comment(username, comment.id).await.unwrap();
assert!(matches!(
db.get_comment_by_id(comment.id).await.err().unwrap(),
DBError::CommentNotFound
));
// delete gist
db.delete_gist(username, &create_gist.public_id)
.await
.unwrap();
assert!(matches!(
db.get_gist(&create_gist.public_id).await.err().unwrap(),
DBError::GistNotFound
));
assert!(db
.get_comments_on_gist(&create_gist.public_id)
.await
.unwrap()
.is_empty());
}
/// test username registration implementation
pub async fn username_register_works<T: GistDatabase>(
db: &T,

View File

@ -14,7 +14,7 @@ include = ["./mgrations/"]
[dependencies]
db-core = {path = "../db-core"}
sqlx = { version = "0.5.10", features = [ "postgres", "time", "offline" ] }
sqlx = { version = "0.5.10", features = [ "postgres", "time", "offline", "runtime-actix-rustls"] }
async-trait = "0.1.51"
[dev-dependencies]

View File

@ -0,0 +1,28 @@
CREATE TABLE IF NOT EXISTS gists_privacy (
name VARCHAR(15) NOT NULL UNIQUE,
ID SERIAL PRIMARY KEY NOT NULL
);
INSERT INTO gists_privacy (name) VALUES('private') ON CONFLICT (name) DO NOTHING;
INSERT INTO gists_privacy (name) VALUES('unlisted') ON CONFLICT (name) DO NOTHING;
INSERT INTO gists_privacy (name) VALUES('public') ON CONFLICT (name) DO NOTHING;
CREATE TABLE IF NOT EXISTS gists_gists (
owner_id INTEGER NOT NULL references gists_users(ID) ON DELETE CASCADE,
privacy INTEGER NOT NULL references gists_privacy(ID),
description TEXT DEFAULT NULL,
created timestamptz NOT NULL,
updated timestamptz NOT NULL,
public_id VARCHAR(32) UNIQUE NOT NULL,
ID SERIAL PRIMARY KEY NOT NULL
);
CREATE INDEX ON gists_gists(public_id);
CREATE TABLE IF NOT EXISTS gists_comments (
owner_id INTEGER NOT NULL references gists_users(ID) ON DELETE CASCADE,
gist_id INTEGER NOT NULL references gists_gists(ID) ON DELETE CASCADE,
comment TEXT DEFAULT NULL,
created timestamptz NOT NULL DEFAULT now(),
ID SERIAL PRIMARY KEY NOT NULL
);

View File

@ -0,0 +1,24 @@
CREATE OR REPLACE VIEW gists_gists_view AS
SELECT
gists.description,
gists.created,
gists.updated,
gists.public_id,
gists_users.username as owner,
gists_privacy.name as privacy
FROM gists_gists gists
INNER JOIN gists_privacy ON gists_privacy.ID = gists.privacy
INNER JOIN gists_users ON gists_users.ID = gists.owner_id;
CREATE OR REPLACE VIEW gists_comments_view AS
SELECT
gists_comments.ID,
gists_comments.comment,
gists_comments.created,
gists_gists.public_id as gist_public_id,
gists_gists.ID as gist_id,
gists_users.username as owner
FROM gists_comments gists_comments
INNER JOIN gists_users ON gists_users.ID = gists_comments.owner_id
INNER JOIN gists_gists ON gists_gists.ID = gists_comments.gist_id;

View File

@ -1,15 +1,139 @@
{
"db": "PostgreSQL",
"0b6e7311c44fa5278b5279b1ecfb8eba57a80f5ddc5f0e1a78f126113a31187b": {
"query": "insert into gists_users \n (username , password, email, secret) values ($1, $2, $3, $4)",
"1516ec34202a21239aa8275d5637007d4c2c54ada5ed346dcebfb4b7b3cdf019": {
"query": "\n SELECT\n ID,\n comment,\n owner,\n created,\n gist_public_id\n FROM\n gists_comments_view\n WHERE\n gist_public_id = $1\n ORDER BY created;\n ",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "id",
"type_info": "Int4"
},
{
"ordinal": 1,
"name": "comment",
"type_info": "Text"
},
{
"ordinal": 2,
"name": "owner",
"type_info": "Varchar"
},
{
"ordinal": 3,
"name": "created",
"type_info": "Timestamptz"
},
{
"ordinal": 4,
"name": "gist_public_id",
"type_info": "Varchar"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
true,
true,
true,
true,
true
]
}
},
"19c04856cfeaa552b1fbf5fb1dc5172c1329d88f39f771c83d3ca104f23a59b8": {
"query": "INSERT INTO gists_gists \n (owner_id , description, public_id, privacy, created, updated)\n VALUES (\n (SELECT ID FROM gists_users WHERE username = $1),\n $2, $3, (SELECT ID FROM gists_privacy WHERE name = $4), $5, $6\n )",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text",
"Text",
"Varchar",
"Varchar"
"Text",
"Timestamptz",
"Timestamptz"
]
},
"nullable": []
}
},
"1ea7ea0bb1a6f4b84a2b9c6b1741c6bf9f1938f107133bd80e72a82fb44d5c8a": {
"query": "INSERT INTO gists_comments (owner_id, gist_id, comment, created)\n VALUES (\n (SELECT ID FROM gists_users WHERE username = $1),\n (SELECT ID FROM gists_gists WHERE public_id = $2),\n $3,\n $4\n )",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Text",
"Text",
"Text",
"Timestamptz"
]
},
"nullable": []
}
},
"2e627e47d7dce8da4aebfc39f3baf02cbb471d514410cbe82ef442b7de9dfc55": {
"query": "SELECT\n owner,\n privacy,\n created,\n updated,\n public_id,\n description\n FROM\n gists_gists_view\n WHERE owner = $1\n ",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "owner",
"type_info": "Varchar"
},
{
"ordinal": 1,
"name": "privacy",
"type_info": "Varchar"
},
{
"ordinal": 2,
"name": "created",
"type_info": "Timestamptz"
},
{
"ordinal": 3,
"name": "updated",
"type_info": "Timestamptz"
},
{
"ordinal": 4,
"name": "public_id",
"type_info": "Varchar"
},
{
"ordinal": 5,
"name": "description",
"type_info": "Text"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
true,
true,
true,
true,
true,
true
]
}
},
"340413dd6062e88bf2db846a05f600d6d0384f8b7038445653c3156b997232a8": {
"query": "DELETE FROM gists_gists \n WHERE \n public_id = $1\n AND\n owner_id = (SELECT ID FROM gists_users WHERE username = $2)\n ",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Text",
"Text"
]
},
"nullable": []
@ -48,6 +172,56 @@
"nullable": []
}
},
"71e74dfde93b42fb7cc064e439f3067ddd49db646b9837a66938c43474b34233": {
"query": "SELECT\n owner,\n privacy,\n created,\n updated,\n public_id,\n description\n FROM\n gists_gists_view\n WHERE public_id = $1\n ",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "owner",
"type_info": "Varchar"
},
{
"ordinal": 1,
"name": "privacy",
"type_info": "Varchar"
},
{
"ordinal": 2,
"name": "created",
"type_info": "Timestamptz"
},
{
"ordinal": 3,
"name": "updated",
"type_info": "Timestamptz"
},
{
"ordinal": 4,
"name": "public_id",
"type_info": "Varchar"
},
{
"ordinal": 5,
"name": "description",
"type_info": "Text"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
true,
true,
true,
true,
true,
true
]
}
},
"7cc18cdd39aa42dcbb75b0b0d06b6df05ac654654b86db71be07344e3f09510d": {
"query": "UPDATE gists_users set username = $1 WHERE username = $2",
"describe": {
@ -87,6 +261,22 @@
]
}
},
"8ba77aab32a3b71ee10bde66676396263fd1bb41cf5d270dcb813c0c0e089bc7": {
"query": "INSERT INTO gists_gists \n (owner_id , public_id, privacy, created, updated)\n VALUES (\n (SELECT ID FROM gists_users WHERE username = $1),\n $2, (SELECT ID FROM gists_privacy WHERE name = $3), $4, $5\n )",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Text",
"Varchar",
"Text",
"Timestamptz",
"Timestamptz"
]
},
"nullable": []
}
},
"8c7af53d14214f2bd23b089d3c9134909c2d1cc13cd42e88778bfb20f497c2dd": {
"query": "SELECT EXISTS (SELECT 1 from gists_users WHERE email = $1)",
"describe": {
@ -120,6 +310,65 @@
"nullable": []
}
},
"9e09535aa7dd7be208c23776acd97e418cb6a2dcf3822ba535a087b8730d8954": {
"query": "INSERT INTO gists_users \n (username , password, email, secret) VALUES ($1, $2, $3, $4)",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text",
"Varchar",
"Varchar"
]
},
"nullable": []
}
},
"a123bde2c6da21bc9b98036b4c68c34dc5e1fbe73564e9f64d832b8d9a2b667d": {
"query": "\n SELECT\n ID,\n comment,\n owner,\n created,\n gist_public_id\n FROM\n gists_comments_view\n WHERE\n ID = $1\n ",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "id",
"type_info": "Int4"
},
{
"ordinal": 1,
"name": "comment",
"type_info": "Text"
},
{
"ordinal": 2,
"name": "owner",
"type_info": "Varchar"
},
{
"ordinal": 3,
"name": "created",
"type_info": "Timestamptz"
},
{
"ordinal": 4,
"name": "gist_public_id",
"type_info": "Varchar"
}
],
"parameters": {
"Left": [
"Int4"
]
},
"nullable": [
true,
true,
true,
true,
true
]
}
},
"aa899a667f05d021e1d537f1ab53289edcec5fc76a88b56abb08909bbc5b8478": {
"query": "UPDATE gists_users set secret = $1\n WHERE username = $2",
"describe": {
@ -145,6 +394,59 @@
"nullable": []
}
},
"bc934d97678a5fef7a55f10657e1cefcdfe51a11b8755aa635cda0be468dc9dd": {
"query": "SELECT EXISTS (SELECT 1 from gists_privacy WHERE name = $1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "exists",
"type_info": "Bool"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
null
]
}
},
"d5ad01498e65415f65a3c30e327b60c61b016a89050ff3fb2e853d0b0632f964": {
"query": "DELETE FROM gists_comments\n WHERE\n ID = $1\n AND\n owner_id = (SELECT ID FROM gists_users WHERE username = $2)\n ",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Int4",
"Text"
]
},
"nullable": []
}
},
"e0a12b823159b7e2a3667bbb4c9dd22dd52b9ffb618f3464a2d61b11ad068821": {
"query": "SELECT EXISTS (SELECT 1 from gists_gists WHERE public_id = $1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "exists",
"type_info": "Bool"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
null
]
}
},
"e3604664ce429e2f49c0c4cc2601c5336be3f8690c06b9883b64b53085c9c9a6": {
"query": "INSERT INTO gists_users \n (username , password, secret) VALUES ($1, $2, $3)",
"describe": {

View File

@ -15,6 +15,8 @@ pub fn map_register_err(e: Error) -> DBError {
DBError::DuplicateEmail
} else if msg.contains("gists_users_secret_key") {
DBError::DuplicateSecret
} else if msg.contains("gists_gists_public_id") {
DBError::GistIDTaken
} else {
DBError::DBError(Box::new(Error::Database(err)))
}

View File

@ -6,6 +6,7 @@
use db_core::dev::*;
use sqlx::postgres::PgPoolOptions;
use sqlx::types::time::OffsetDateTime;
use sqlx::PgPool;
mod errors;
@ -115,8 +116,8 @@ impl GistDatabase for Database {
async fn email_register(&self, payload: &EmailRegisterPayload) -> DBResult<()> {
sqlx::query!(
"insert into gists_users
(username , password, email, secret) values ($1, $2, $3, $4)",
"INSERT INTO gists_users
(username , password, email, secret) VALUES ($1, $2, $3, $4)",
&payload.username,
&payload.password,
&payload.email,
@ -281,4 +282,291 @@ impl GistDatabase for Database {
false
}
}
/// Check if a Gist with the given ID exists
async fn gist_exists(&self, public_id: &str) -> DBResult<bool> {
let res = sqlx::query!(
"SELECT EXISTS (SELECT 1 from gists_gists WHERE public_id = $1)",
public_id,
)
.fetch_one(&self.pool)
.await
.map_err(|e| DBError::DBError(Box::new(e)))?;
let mut exists = false;
if let Some(x) = res.exists {
exists = x;
};
Ok(exists)
}
/// Create new gists
async fn new_gist(&self, gist: &CreateGist) -> DBResult<()> {
let now = OffsetDateTime::now_utc();
if let Some(description) = &gist.description {
sqlx::query!(
"INSERT INTO gists_gists
(owner_id , description, public_id, privacy, created, updated)
VALUES (
(SELECT ID FROM gists_users WHERE username = $1),
$2, $3, (SELECT ID FROM gists_privacy WHERE name = $4), $5, $6
)",
&gist.owner,
description,
&gist.public_id,
gist.privacy.to_str(),
&now,
&now
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
} else {
sqlx::query!(
"INSERT INTO gists_gists
(owner_id , public_id, privacy, created, updated)
VALUES (
(SELECT ID FROM gists_users WHERE username = $1),
$2, (SELECT ID FROM gists_privacy WHERE name = $3), $4, $5
)",
&gist.owner,
&gist.public_id,
gist.privacy.to_str(),
&now,
&now
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
}
Ok(())
}
/// Retrieve gist from database
async fn get_gist(&self, public_id: &str) -> DBResult<Gist> {
let res = sqlx::query_as!(
InnerGist,
"SELECT
owner,
privacy,
created,
updated,
public_id,
description
FROM
gists_gists_view
WHERE public_id = $1
",
public_id
)
.fetch_one(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::GistNotFound,
e => DBError::DBError(Box::new(e)),
})?;
res.to_gist()
}
/// Retrieve gists belonging to user from database
async fn get_user_gists(&self, owner: &str) -> DBResult<Vec<Gist>> {
let mut res = sqlx::query_as!(
InnerGist,
"SELECT
owner,
privacy,
created,
updated,
public_id,
description
FROM
gists_gists_view
WHERE owner = $1
",
owner
)
.fetch_all(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::GistNotFound,
e => DBError::DBError(Box::new(e)),
})?;
let mut gists = Vec::with_capacity(res.len());
for r in res.drain(..) {
gists.push(r.to_gist()?);
}
Ok(gists)
}
async fn delete_gist(&self, owner: &str, public_id: &str) -> DBResult<()> {
sqlx::query!(
"DELETE FROM gists_gists
WHERE
public_id = $1
AND
owner_id = (SELECT ID FROM gists_users WHERE username = $2)
",
public_id,
owner
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
Ok(())
}
/// Create new comment
async fn new_comment(&self, comment: &CreateGistComment) -> DBResult<()> {
let now = OffsetDateTime::now_utc();
sqlx::query!(
"INSERT INTO gists_comments (owner_id, gist_id, comment, created)
VALUES (
(SELECT ID FROM gists_users WHERE username = $1),
(SELECT ID FROM gists_gists WHERE public_id = $2),
$3,
$4
)",
comment.owner,
comment.gist_public_id,
comment.comment,
&now,
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
Ok(())
}
/// Get comments on a gist
async fn get_comments_on_gist(&self, public_id: &str) -> DBResult<Vec<GistComment>> {
let mut res = sqlx::query_as!(
InnerGistComment,
"
SELECT
ID,
comment,
owner,
created,
gist_public_id
FROM
gists_comments_view
WHERE
gist_public_id = $1
ORDER BY created;
",
public_id,
)
.fetch_all(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::CommentNotFound,
e => DBError::DBError(Box::new(e)),
})?;
let mut comments: Vec<GistComment> = Vec::with_capacity(res.len());
res.drain(..).for_each(|r| comments.push(r.into()));
Ok(comments)
}
/// Get a specific comment using its database assigned ID
async fn get_comment_by_id(&self, id: i64) -> DBResult<GistComment> {
let res = sqlx::query_as!(
InnerGistComment,
"
SELECT
ID,
comment,
owner,
created,
gist_public_id
FROM
gists_comments_view
WHERE
ID = $1
",
id as i32
)
.fetch_one(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::CommentNotFound,
e => DBError::DBError(Box::new(e)),
})?;
Ok(res.into())
}
/// Delete comment
async fn delete_comment(&self, owner: &str, id: i64) -> DBResult<()> {
sqlx::query!(
"DELETE FROM gists_comments
WHERE
ID = $1
AND
owner_id = (SELECT ID FROM gists_users WHERE username = $2)
",
id as i32,
owner,
)
.execute(&self.pool)
.await
.map_err(|e| DBError::DBError(Box::new(e)))?;
Ok(())
}
async fn privacy_exists(&self, privacy: &GistPrivacy) -> DBResult<bool> {
let res = sqlx::query!(
"SELECT EXISTS (SELECT 1 from gists_privacy WHERE name = $1)",
privacy.to_str()
)
.fetch_one(&self.pool)
.await
.map_err(|e| DBError::DBError(Box::new(e)))?;
let mut exists = false;
if let Some(x) = res.exists {
exists = x
};
Ok(exists)
}
}
struct InnerGist {
owner: Option<String>,
description: Option<String>,
public_id: Option<String>,
created: Option<OffsetDateTime>,
updated: Option<OffsetDateTime>,
privacy: Option<String>,
}
impl InnerGist {
fn to_gist(self) -> DBResult<Gist> {
Ok(Gist {
owner: self.owner.unwrap(),
description: self.description,
public_id: self.public_id.unwrap(),
created: self.created.as_ref().unwrap().unix_timestamp(),
updated: self.updated.as_ref().unwrap().unix_timestamp(),
privacy: GistPrivacy::from_str(self.privacy.as_ref().unwrap())?,
})
}
}
struct InnerGistComment {
id: Option<i32>,
owner: Option<String>,
comment: Option<String>,
gist_public_id: Option<String>,
created: Option<OffsetDateTime>,
}
impl From<InnerGistComment> for GistComment {
fn from(g: InnerGistComment) -> Self {
Self {
id: g.id.unwrap() as i64,
owner: g.owner.unwrap(),
comment: g.comment.unwrap(),
gist_public_id: g.gist_public_id.unwrap(),
created: g.created.unwrap().unix_timestamp(),
}
}
}

View File

@ -38,3 +38,30 @@ async fn everyting_works() {
};
db.update_password(&creds).await.unwrap();
}
#[actix_rt::test]
async fn privacy_test() {
let url = env::var("POSTGRES_DATABASE_URL").unwrap();
let pool_options = PgPoolOptions::new().max_connections(2);
let connection_options = ConnectionOptions::Fresh(Fresh { pool_options, url });
let db = connection_options.connect().await.unwrap();
db.migrate().await.unwrap();
privacy_works(&db).await;
}
#[actix_rt::test]
async fn gist_test() {
const NAME: &str = "postgisttest";
const PASSWORD: &str = "pasdfasdfasdfadf";
const SECRET: &str = "postgisttestsecret";
const PUBLIC_ID: &str = "postgisttestsecret";
let url = env::var("POSTGRES_DATABASE_URL").unwrap();
let pool_options = PgPoolOptions::new().max_connections(2);
let connection_options = ConnectionOptions::Fresh(Fresh { pool_options, url });
let db = connection_options.connect().await.unwrap();
db.migrate().await.unwrap();
gists_work(&db, NAME, PASSWORD, SECRET, PUBLIC_ID).await;
}

View File

@ -12,7 +12,7 @@ include = ["./mgrations/"]
# See more keys and their definitions at https://doc.rust-lang.org/cargo/reference/manifest.html
[dependencies]
sqlx = { version = "0.5.10", features = [ "sqlite", "time", "offline" ] }
sqlx = { version = "0.5.10", features = [ "sqlite", "time", "offline", "runtime-actix-rustls" ] }
db-core = {path = "../db-core"}
async-trait = "0.1.51"

View File

@ -0,0 +1,29 @@
CREATE TABLE IF NOT EXISTS gists_privacy (
name VARCHAR(15) NOT NULL UNIQUE,
ID INTEGER PRIMARY KEY NOT NULL
);
INSERT OR IGNORE INTO gists_privacy (name) VALUES('private');
INSERT OR IGNORE INTO gists_privacy (name) VALUES('unlisted');
INSERT OR IGNORE INTO gists_privacy (name) VALUES('public');
CREATE TABLE IF NOT EXISTS gists_gists (
owner_id INTEGER NOT NULL references gists_users(ID) ON DELETE CASCADE,
description TEXT DEFAULT NULL,
created INTEGER NOT NULL,
updated INTEGER NOT NULL,
privacy INTEGER NOT NULL references gists_privacy(ID),
public_id VARCHAR(32) UNIQUE NOT NULL,
ID INTEGER PRIMARY KEY NOT NULL
);
CREATE UNIQUE INDEX IF NOT EXISTS public_id_index ON gists_gists (public_id);
CREATE TABLE IF NOT EXISTS gists_comments (
owner_id INTEGER NOT NULL references gists_users(ID) ON DELETE CASCADE,
gist_id INTEGER NOT NULL references gists_gists(ID) ON DELETE CASCADE,
comment TEXT DEFAULT NULL,
created INTEGER NOT NULL,
ID INTEGER PRIMARY KEY NOT NULL
);

View File

@ -0,0 +1,26 @@
DROP VIEW IF EXISTS gists_gists_view;
CREATE VIEW gists_gists_view AS
SELECT
gists.description,
gists.created,
gists.updated,
gists.public_id,
gists_users.username as owner,
gists_privacy.name as privacy
FROM gists_gists gists
INNER JOIN gists_privacy ON gists_privacy.ID = gists.privacy
INNER JOIN gists_users ON gists_users.ID = gists.owner_id;
DROP VIEW IF EXISTS gists_comments_view;
CREATE VIEW gists_comments_view AS
SELECT
gists_comments.ID,
gists_comments.comment,
gists_comments.created,
gists_gists.public_id as gist_public_id,
gists_gists.ID as gist_id,
gists_users.username as owner
FROM gists_comments gists_comments
INNER JOIN gists_users ON gists_users.ID = gists_comments.owner_id
INNER JOIN gists_gists ON gists_gists.ID = gists_comments.gist_id;

View File

@ -10,6 +10,162 @@
"nullable": []
}
},
"1088bc2872170b2ed8511d34ea07062d4bbc420d33724148720f492c8730ce2e": {
"query": "SELECT ID from gists_privacy WHERE name = $1",
"describe": {
"columns": [
{
"name": "ID",
"ordinal": 0,
"type_info": "Int64"
}
],
"parameters": {
"Right": 1
},
"nullable": [
false
]
}
},
"1516ec34202a21239aa8275d5637007d4c2c54ada5ed346dcebfb4b7b3cdf019": {
"query": "\n SELECT\n ID,\n comment,\n owner,\n created,\n gist_public_id\n FROM\n gists_comments_view\n WHERE\n gist_public_id = $1\n ORDER BY created;\n ",
"describe": {
"columns": [
{
"name": "ID",
"ordinal": 0,
"type_info": "Int64"
},
{
"name": "comment",
"ordinal": 1,
"type_info": "Text"
},
{
"name": "owner",
"ordinal": 2,
"type_info": "Text"
},
{
"name": "created",
"ordinal": 3,
"type_info": "Int64"
},
{
"name": "gist_public_id",
"ordinal": 4,
"type_info": "Text"
}
],
"parameters": {
"Right": 1
},
"nullable": [
false,
true,
false,
false,
false
]
}
},
"19c04856cfeaa552b1fbf5fb1dc5172c1329d88f39f771c83d3ca104f23a59b8": {
"query": "INSERT INTO gists_gists \n (owner_id , description, public_id, privacy, created, updated)\n VALUES (\n (SELECT ID FROM gists_users WHERE username = $1),\n $2, $3, (SELECT ID FROM gists_privacy WHERE name = $4), $5, $6\n )",
"describe": {
"columns": [],
"parameters": {
"Right": 6
},
"nullable": []
}
},
"1ea7ea0bb1a6f4b84a2b9c6b1741c6bf9f1938f107133bd80e72a82fb44d5c8a": {
"query": "INSERT INTO gists_comments (owner_id, gist_id, comment, created)\n VALUES (\n (SELECT ID FROM gists_users WHERE username = $1),\n (SELECT ID FROM gists_gists WHERE public_id = $2),\n $3,\n $4\n )",
"describe": {
"columns": [],
"parameters": {
"Right": 4
},
"nullable": []
}
},
"2e627e47d7dce8da4aebfc39f3baf02cbb471d514410cbe82ef442b7de9dfc55": {
"query": "SELECT\n owner,\n privacy,\n created,\n updated,\n public_id,\n description\n FROM\n gists_gists_view\n WHERE owner = $1\n ",
"describe": {
"columns": [
{
"name": "owner",
"ordinal": 0,
"type_info": "Text"
},
{
"name": "privacy",
"ordinal": 1,
"type_info": "Text"
},
{
"name": "created",
"ordinal": 2,
"type_info": "Int64"
},
{
"name": "updated",
"ordinal": 3,
"type_info": "Int64"
},
{
"name": "public_id",
"ordinal": 4,
"type_info": "Text"
},
{
"name": "description",
"ordinal": 5,
"type_info": "Text"
}
],
"parameters": {
"Right": 1
},
"nullable": [
false,
false,
false,
false,
false,
true
]
}
},
"340413dd6062e88bf2db846a05f600d6d0384f8b7038445653c3156b997232a8": {
"query": "DELETE FROM gists_gists \n WHERE \n public_id = $1\n AND\n owner_id = (SELECT ID FROM gists_users WHERE username = $2)\n ",
"describe": {
"columns": [],
"parameters": {
"Right": 2
},
"nullable": []
}
},
"39cea9b1c3ff61fdc935e3559151ce3100fe7d7090843cb39dc77ec67d668980": {
"query": "SELECT ID from gists_gists WHERE public_id = $1",
"describe": {
"columns": [
{
"name": "ID",
"ordinal": 0,
"type_info": "Int64"
}
],
"parameters": {
"Right": 1
},
"nullable": [
false
]
}
},
"405772009a7aee0194b6b25c42955c2674c3ff92b812d7f15c4075d243879c60": {
"query": "SELECT password FROM gists_users WHERE username = ($1)",
"describe": {
@ -38,6 +194,54 @@
"nullable": []
}
},
"71e74dfde93b42fb7cc064e439f3067ddd49db646b9837a66938c43474b34233": {
"query": "SELECT\n owner,\n privacy,\n created,\n updated,\n public_id,\n description\n FROM\n gists_gists_view\n WHERE public_id = $1\n ",
"describe": {
"columns": [
{
"name": "owner",
"ordinal": 0,
"type_info": "Text"
},
{
"name": "privacy",
"ordinal": 1,
"type_info": "Text"
},
{
"name": "created",
"ordinal": 2,
"type_info": "Int64"
},
{
"name": "updated",
"ordinal": 3,
"type_info": "Int64"
},
{
"name": "public_id",
"ordinal": 4,
"type_info": "Text"
},
{
"name": "description",
"ordinal": 5,
"type_info": "Text"
}
],
"parameters": {
"Right": 1
},
"nullable": [
false,
false,
false,
false,
false,
true
]
}
},
"7cc18cdd39aa42dcbb75b0b0d06b6df05ac654654b86db71be07344e3f09510d": {
"query": "UPDATE gists_users set username = $1 WHERE username = $2",
"describe": {
@ -72,6 +276,16 @@
]
}
},
"8ba77aab32a3b71ee10bde66676396263fd1bb41cf5d270dcb813c0c0e089bc7": {
"query": "INSERT INTO gists_gists \n (owner_id , public_id, privacy, created, updated)\n VALUES (\n (SELECT ID FROM gists_users WHERE username = $1),\n $2, (SELECT ID FROM gists_privacy WHERE name = $3), $4, $5\n )",
"describe": {
"columns": [],
"parameters": {
"Right": 5
},
"nullable": []
}
},
"9aaf3a384bf79f278bf79c99b34fadcc172cfa4e7857111502782e6ad7110b7b": {
"query": "UPDATE gists_users set email = $1\n WHERE username = $2",
"describe": {
@ -82,6 +296,48 @@
"nullable": []
}
},
"a123bde2c6da21bc9b98036b4c68c34dc5e1fbe73564e9f64d832b8d9a2b667d": {
"query": "\n SELECT\n ID,\n comment,\n owner,\n created,\n gist_public_id\n FROM\n gists_comments_view\n WHERE\n ID = $1\n ",
"describe": {
"columns": [
{
"name": "ID",
"ordinal": 0,
"type_info": "Int64"
},
{
"name": "comment",
"ordinal": 1,
"type_info": "Text"
},
{
"name": "owner",
"ordinal": 2,
"type_info": "Text"
},
{
"name": "created",
"ordinal": 3,
"type_info": "Int64"
},
{
"name": "gist_public_id",
"ordinal": 4,
"type_info": "Text"
}
],
"parameters": {
"Right": 1
},
"nullable": [
false,
true,
false,
false,
false
]
}
},
"aa899a667f05d021e1d537f1ab53289edcec5fc76a88b56abb08909bbc5b8478": {
"query": "UPDATE gists_users set secret = $1\n WHERE username = $2",
"describe": {
@ -138,6 +394,16 @@
]
}
},
"d5ad01498e65415f65a3c30e327b60c61b016a89050ff3fb2e853d0b0632f964": {
"query": "DELETE FROM gists_comments\n WHERE\n ID = $1\n AND\n owner_id = (SELECT ID FROM gists_users WHERE username = $2)\n ",
"describe": {
"columns": [],
"parameters": {
"Right": 2
},
"nullable": []
}
},
"e3604664ce429e2f49c0c4cc2601c5336be3f8690c06b9883b64b53085c9c9a6": {
"query": "INSERT INTO gists_users \n (username , password, secret) VALUES ($1, $2, $3)",
"describe": {

View File

@ -14,6 +14,8 @@ pub fn map_register_err(e: Error) -> DBError {
DBError::DuplicateEmail
} else if msg.contains("gists_users.secret") {
DBError::DuplicateSecret
} else if msg.contains("gists_gists.public_id") {
DBError::GistIDTaken
} else {
DBError::DBError(Box::new(Error::Database(err)))
}

View File

@ -2,6 +2,7 @@ use db_core::dev::*;
use sqlx::sqlite::SqlitePool;
use sqlx::sqlite::SqlitePoolOptions;
use sqlx::types::time::OffsetDateTime;
pub mod errors;
#[cfg(test)]
@ -250,4 +251,286 @@ impl GistDatabase for Database {
false
}
}
/// Check if a Gist with the given ID exists
async fn gist_exists(&self, public_id: &str) -> DBResult<bool> {
match sqlx::query!("SELECT ID from gists_gists WHERE public_id = $1", public_id)
.fetch_one(&self.pool)
.await
{
Ok(_) => Ok(true),
Err(Error::RowNotFound) => Ok(false),
Err(e) => Err(DBError::DBError(Box::new(e))),
}
}
/// Create new gists
async fn new_gist(&self, gist: &CreateGist) -> DBResult<()> {
let now = now_unix_time_stamp();
let privacy = gist.privacy.to_str();
if let Some(description) = &gist.description {
sqlx::query!(
"INSERT INTO gists_gists
(owner_id , description, public_id, privacy, created, updated)
VALUES (
(SELECT ID FROM gists_users WHERE username = $1),
$2, $3, (SELECT ID FROM gists_privacy WHERE name = $4), $5, $6
)",
gist.owner,
description,
gist.public_id,
privacy,
now,
now
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
} else {
sqlx::query!(
"INSERT INTO gists_gists
(owner_id , public_id, privacy, created, updated)
VALUES (
(SELECT ID FROM gists_users WHERE username = $1),
$2, (SELECT ID FROM gists_privacy WHERE name = $3), $4, $5
)",
gist.owner,
gist.public_id,
privacy,
now,
now
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
}
Ok(())
}
/// Retrieve gist from database
async fn get_gist(&self, public_id: &str) -> DBResult<Gist> {
let res = sqlx::query_as!(
InnerGist,
"SELECT
owner,
privacy,
created,
updated,
public_id,
description
FROM
gists_gists_view
WHERE public_id = $1
",
public_id
)
.fetch_one(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::GistNotFound,
e => DBError::DBError(Box::new(e)),
})?;
res.to_gist()
}
/// Retrieve gists belonging to user from database
async fn get_user_gists(&self, owner: &str) -> DBResult<Vec<Gist>> {
let mut res = sqlx::query_as!(
InnerGist,
"SELECT
owner,
privacy,
created,
updated,
public_id,
description
FROM
gists_gists_view
WHERE owner = $1
",
owner
)
.fetch_all(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::GistNotFound,
e => DBError::DBError(Box::new(e)),
})?;
let mut gists = Vec::with_capacity(res.len());
for r in res.drain(..) {
gists.push(r.to_gist()?);
}
Ok(gists)
}
async fn delete_gist(&self, owner: &str, public_id: &str) -> DBResult<()> {
sqlx::query!(
"DELETE FROM gists_gists
WHERE
public_id = $1
AND
owner_id = (SELECT ID FROM gists_users WHERE username = $2)
",
public_id,
owner
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
Ok(())
}
/// Create new comment
async fn new_comment(&self, comment: &CreateGistComment) -> DBResult<()> {
let now = now_unix_time_stamp();
sqlx::query!(
"INSERT INTO gists_comments (owner_id, gist_id, comment, created)
VALUES (
(SELECT ID FROM gists_users WHERE username = $1),
(SELECT ID FROM gists_gists WHERE public_id = $2),
$3,
$4
)",
comment.owner,
comment.gist_public_id,
comment.comment,
now,
)
.execute(&self.pool)
.await
.map_err(map_register_err)?;
Ok(())
}
/// Get comments on a gist
async fn get_comments_on_gist(&self, public_id: &str) -> DBResult<Vec<GistComment>> {
let mut res = sqlx::query_as!(
InnerGistComment,
"
SELECT
ID,
comment,
owner,
created,
gist_public_id
FROM
gists_comments_view
WHERE
gist_public_id = $1
ORDER BY created;
",
public_id,
)
.fetch_all(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::CommentNotFound,
e => DBError::DBError(Box::new(e)),
})?;
let mut comments: Vec<GistComment> = Vec::with_capacity(res.len());
res.drain(..).for_each(|r| comments.push(r.into()));
Ok(comments)
}
/// Get a specific comment using its database assigned ID
async fn get_comment_by_id(&self, id: i64) -> DBResult<GistComment> {
let res = sqlx::query_as!(
InnerGistComment,
"
SELECT
ID,
comment,
owner,
created,
gist_public_id
FROM
gists_comments_view
WHERE
ID = $1
",
id
)
.fetch_one(&self.pool)
.await
.map_err(|e| match e {
Error::RowNotFound => DBError::CommentNotFound,
e => DBError::DBError(Box::new(e)),
})?;
Ok(res.into())
}
/// Delete comment
async fn delete_comment(&self, owner: &str, id: i64) -> DBResult<()> {
sqlx::query!(
"DELETE FROM gists_comments
WHERE
ID = $1
AND
owner_id = (SELECT ID FROM gists_users WHERE username = $2)
",
id,
owner,
)
.execute(&self.pool)
.await
.map_err(|e| DBError::DBError(Box::new(e)))?;
Ok(())
}
async fn privacy_exists(&self, privacy: &GistPrivacy) -> DBResult<bool> {
let privacy = privacy.to_str();
match sqlx::query!("SELECT ID from gists_privacy WHERE name = $1", privacy)
.fetch_one(&self.pool)
.await
{
Ok(_) => Ok(true),
Err(Error::RowNotFound) => Ok(false),
Err(e) => Err(DBError::DBError(Box::new(e))),
}
}
}
fn now_unix_time_stamp() -> i64 {
OffsetDateTime::now_utc().unix_timestamp()
}
struct InnerGist {
owner: String,
description: Option<String>,
public_id: String,
created: i64,
updated: i64,
privacy: String,
}
impl InnerGist {
fn to_gist(self) -> DBResult<Gist> {
Ok(Gist {
owner: self.owner,
description: self.description,
public_id: self.public_id,
created: self.created,
updated: self.updated,
privacy: GistPrivacy::from_str(&self.privacy)?,
})
}
}
#[allow(non_snake_case)]
struct InnerGistComment {
ID: i64,
owner: String,
comment: Option<String>,
gist_public_id: String,
created: i64,
}
impl From<InnerGistComment> for GistComment {
fn from(g: InnerGistComment) -> Self {
Self {
id: g.ID,
owner: g.owner,
comment: g.comment.unwrap(),
gist_public_id: g.gist_public_id,
created: g.created,
}
}
}

View File

@ -38,3 +38,30 @@ async fn everyting_works() {
};
db.update_password(&creds).await.unwrap();
}
#[actix_rt::test]
async fn privacy_test() {
let url = env::var("SQLITE_DATABASE_URL").expect("Set SQLITE_DATABASE_URL env var");
let pool_options = SqlitePoolOptions::new().max_connections(2);
let connection_options = ConnectionOptions::Fresh(Fresh { pool_options, url });
let db = connection_options.connect().await.unwrap();
db.migrate().await.unwrap();
privacy_works(&db).await;
}
#[actix_rt::test]
async fn gist_test() {
const NAME: &str = "postgisttest";
const PASSWORD: &str = "pasdfasdfasdfadf";
const SECRET: &str = "postgisttestsecret";
const PUBLIC_ID: &str = "postgisttestsecret";
let url = env::var("SQLITE_DATABASE_URL").expect("Set SQLITE_DATABASE_URL env var");
let pool_options = SqlitePoolOptions::new().max_connections(2);
let connection_options = ConnectionOptions::Fresh(Fresh { pool_options, url });
let db = connection_options.connect().await.unwrap();
db.migrate().await.unwrap();
gists_work(&db, NAME, PASSWORD, SECRET, PUBLIC_ID).await;
}

View File

@ -0,0 +1,3 @@
{
"db": "SQLite"
}

View File

@ -1,202 +1,3 @@
{
"db": "PostgreSQL",
"0b6e7311c44fa5278b5279b1ecfb8eba57a80f5ddc5f0e1a78f126113a31187b": {
"query": "insert into gists_users \n (username , password, email, secret) values ($1, $2, $3, $4)",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text",
"Varchar",
"Varchar"
]
},
"nullable": []
}
},
"405772009a7aee0194b6b25c42955c2674c3ff92b812d7f15c4075d243879c60": {
"query": "SELECT password FROM gists_users WHERE username = ($1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "password",
"type_info": "Text"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
false
]
}
},
"4eb5627f85e0395422df67fb6d9bb8a1325bb751293b55a370f3906b42fec554": {
"query": "UPDATE gists_users set password = $1\n WHERE username = $2",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Text",
"Text"
]
},
"nullable": []
}
},
"7cc18cdd39aa42dcbb75b0b0d06b6df05ac654654b86db71be07344e3f09510d": {
"query": "UPDATE gists_users set username = $1 WHERE username = $2",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text"
]
},
"nullable": []
}
},
"87e92bd84adbe95b27200a84c861d30b7c09b0a7976df7a02caa645b46cdf7dd": {
"query": "SELECT username, password FROM gists_users WHERE email = ($1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "username",
"type_info": "Varchar"
},
{
"ordinal": 1,
"name": "password",
"type_info": "Text"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
false,
false
]
}
},
"8c7af53d14214f2bd23b089d3c9134909c2d1cc13cd42e88778bfb20f497c2dd": {
"query": "SELECT EXISTS (SELECT 1 from gists_users WHERE email = $1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "exists",
"type_info": "Bool"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
null
]
}
},
"9aaf3a384bf79f278bf79c99b34fadcc172cfa4e7857111502782e6ad7110b7b": {
"query": "UPDATE gists_users set email = $1\n WHERE username = $2",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text"
]
},
"nullable": []
}
},
"aa899a667f05d021e1d537f1ab53289edcec5fc76a88b56abb08909bbc5b8478": {
"query": "UPDATE gists_users set secret = $1\n WHERE username = $2",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text"
]
},
"nullable": []
}
},
"b3c2a524999bb13149704c53c059a856c5003ef537b9e966548123a52c01802b": {
"query": "DELETE FROM gists_users WHERE username = ($1)",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Text"
]
},
"nullable": []
}
},
"e3604664ce429e2f49c0c4cc2601c5336be3f8690c06b9883b64b53085c9c9a6": {
"query": "INSERT INTO gists_users \n (username , password, secret) VALUES ($1, $2, $3)",
"describe": {
"columns": [],
"parameters": {
"Left": [
"Varchar",
"Text",
"Varchar"
]
},
"nullable": []
}
},
"e7aadec10bcf05eeac542b2f89ce27fcf2efd5d5e8c4ff929fce35c47d7feed1": {
"query": "SELECT secret FROM gists_users WHERE username = ($1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "secret",
"type_info": "Varchar"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
false
]
}
},
"fdd95c62a27eab173de335225e9e319b901832962b7a562ec4d1749ff74f8fd4": {
"query": "SELECT EXISTS (SELECT 1 from gists_users WHERE username = $1)",
"describe": {
"columns": [
{
"ordinal": 0,
"name": "exists",
"type_info": "Bool"
}
],
"parameters": {
"Left": [
"Text"
]
},
"nullable": [
null
]
}
}
"db": "PostgreSQL"
}

View File

@ -58,6 +58,14 @@ pub enum ServiceError {
/// account not found
AccountNotFound,
#[display(fmt = "Gist not found")]
/// gist not found
GistNotFound,
#[display(fmt = "comment not found")]
/// comment not found
CommentNotFound,
/// when the value passed contains profainity
#[display(fmt = "Can't allow profanity in usernames")]
ProfainityError,
@ -129,6 +137,10 @@ impl From<DBError> for ServiceError {
DBError::DuplicateUsername => ServiceError::UsernameTaken,
DBError::AccountNotFound => ServiceError::AccountNotFound,
DBError::DuplicateSecret => ServiceError::InternalServerError,
DBError::GistNotFound => ServiceError::GistNotFound,
DBError::CommentNotFound => ServiceError::CommentNotFound,
DBError::GistIDTaken => ServiceError::InternalServerError,
DBError::UnknownPrivacySpecifier(_) => ServiceError::InternalServerError,
}
}
}
@ -185,6 +197,9 @@ impl ResponseError for ServiceError {
ServiceError::UsernameTaken => 400, //BADREQUEST,
ServiceError::EmailTaken => 400, //BADREQUEST,
ServiceError::GistNotFound => 404,
ServiceError::CommentNotFound => 404,
};
StatusCode::from_u16(status_code).unwrap()