Updated the SQL file to support series subscriptions in the future, among other changes.
This commit is contained in:
@ -20,58 +20,64 @@ DROP TABLE IF EXISTS series;
|
|||||||
CREATE TABLE
|
CREATE TABLE
|
||||||
series (
|
series (
|
||||||
series_id uuid DEFAULT gen_random_uuid (),
|
series_id uuid DEFAULT gen_random_uuid (),
|
||||||
-- 3rd party used to fetch the data for this series.
|
-- 3rd party id for this series.
|
||||||
provider varchar(6) NOT NULL,
|
|
||||||
provider_series_id text,
|
provider_series_id text,
|
||||||
series_title text NOT NULL,
|
series_title text NOT NULL,
|
||||||
date_added timestamp default NULL,
|
-- 3rd party used to fetch the data for this series.
|
||||||
PRIMARY KEY (series_id)
|
provider varchar(12) NOT NULL,
|
||||||
|
added_at timestamp default NULL,
|
||||||
|
PRIMARY KEY (series_id),
|
||||||
|
UNIQUE (provider, provider_series_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE series
|
ALTER TABLE series
|
||||||
ALTER COLUMN date_added
|
ALTER COLUMN added_at
|
||||||
SET DEFAULT now ();
|
SET DEFAULT now ();
|
||||||
|
|
||||||
CREATE INDEX series_series_title_idx ON series USING HASH (series_title);
|
CREATE INDEX series_series_title_idx ON series (series_title);
|
||||||
|
|
||||||
CREATE TABLE
|
CREATE TABLE
|
||||||
books (
|
books (
|
||||||
book_id uuid DEFAULT gen_random_uuid (),
|
book_id uuid DEFAULT gen_random_uuid (),
|
||||||
series_id uuid,
|
-- 3rd party id for this series if applicable.
|
||||||
|
provider_series_id text,
|
||||||
|
-- 3rd party id for this book.
|
||||||
provider_book_id text NOT NULL,
|
provider_book_id text NOT NULL,
|
||||||
isbn varchar(16),
|
|
||||||
book_title text NOT NULL,
|
book_title text NOT NULL,
|
||||||
book_desc text NOT NULL,
|
book_desc text,
|
||||||
book_volume integer,
|
book_volume integer,
|
||||||
date_released timestamp default NULL,
|
-- 3rd party used to fetch the data for this book.
|
||||||
date_added timestamp default NULL,
|
provider varchar(12) NOT NULL,
|
||||||
|
published_at timestamp default NULL,
|
||||||
|
added_at timestamp default NULL,
|
||||||
PRIMARY KEY (book_id),
|
PRIMARY KEY (book_id),
|
||||||
FOREIGN KEY (series_id) REFERENCES series (series_id)
|
-- FOREIGN KEY (series_id) REFERENCES series (series_id),
|
||||||
|
FOREIGN KEY (provider, provider_series_id) REFERENCES series (provider, provider_series_id) ON DELETE CASCADE,
|
||||||
|
UNIQUE NULLS NOT DISTINCT (provider_series_id, provider_book_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE books
|
ALTER TABLE books
|
||||||
ALTER COLUMN date_released
|
ALTER COLUMN added_at
|
||||||
SET DEFAULT now ();
|
SET DEFAULT now ();
|
||||||
|
|
||||||
ALTER TABLE books
|
-- CREATE INDEX books_series_id_idx ON books (series_id);
|
||||||
ALTER COLUMN date_added
|
CREATE INDEX books_provider_series_id_idx ON books (provider_series_id);
|
||||||
SET DEFAULT now ();
|
|
||||||
|
|
||||||
CREATE INDEX books_series_id_idx ON books USING HASH (series_id);
|
-- CREATE INDEX books_isbn_idx ON books USING HASH (isbn);
|
||||||
|
CREATE INDEX books_book_title_idx ON books (book_title);
|
||||||
CREATE INDEX books_isbn_idx ON books USING HASH (isbn);
|
|
||||||
|
|
||||||
CREATE INDEX books_book_title_idx ON books USING HASH (book_title);
|
|
||||||
|
|
||||||
CREATE TABLE
|
CREATE TABLE
|
||||||
book_origins (
|
book_origins (
|
||||||
book_id uuid,
|
book_origin_id uuid DEFAULT gen_random_uuid (),
|
||||||
origin_type varchar(8),
|
book_id uuid NOT NULL,
|
||||||
|
origin_type integer,
|
||||||
origin_value text,
|
origin_value text,
|
||||||
PRIMARY KEY (book_id, origin_type, origin_value)
|
PRIMARY KEY (book_origin_id),
|
||||||
|
FOREIGN KEY (book_id) REFERENCES books (book_id) ON DELETE CASCADE,
|
||||||
|
UNIQUE (book_id, origin_type, origin_value)
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX book_origins_book_id_idx ON book_origins USING HASH (book_id);
|
CREATE INDEX book_origins_book_id_idx ON book_origins (book_id);
|
||||||
|
|
||||||
CREATE INDEX book_origins_type_value_idx ON book_origins (origin_type, origin_value);
|
CREATE INDEX book_origins_type_value_idx ON book_origins (origin_type, origin_value);
|
||||||
|
|
||||||
@ -83,24 +89,22 @@ CREATE TABLE
|
|||||||
password text NOT NULL,
|
password text NOT NULL,
|
||||||
salt bigint NOT NULL,
|
salt bigint NOT NULL,
|
||||||
is_admin boolean NOT NULL,
|
is_admin boolean NOT NULL,
|
||||||
date_joined timestamp default NULL,
|
joined_at timestamp default NULL,
|
||||||
PRIMARY KEY (user_id),
|
PRIMARY KEY (user_id),
|
||||||
UNIQUE (user_login)
|
UNIQUE (user_login)
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE users
|
ALTER TABLE users
|
||||||
ALTER COLUMN date_joined
|
ALTER COLUMN joined_at
|
||||||
SET DEFAULT now ();
|
SET DEFAULT now ();
|
||||||
|
|
||||||
CREATE INDEX users_user_login_idx ON users USING HASH (user_login);
|
|
||||||
|
|
||||||
CREATE TABLE
|
CREATE TABLE
|
||||||
refresh_tokens (
|
refresh_tokens (
|
||||||
user_id uuid NOT NULL,
|
user_id uuid NOT NULL,
|
||||||
refresh_token_hash text NOT NULL,
|
refresh_token_hash text NOT NULL,
|
||||||
exp timestamp NOT NULL,
|
exp timestamp NOT NULL,
|
||||||
PRIMARY KEY (user_id, refresh_token_hash),
|
PRIMARY KEY (user_id, refresh_token_hash),
|
||||||
FOREIGN KEY (user_id) REFERENCES users (user_id)
|
FOREIGN KEY (user_id) REFERENCES users (user_id) ON DELETE CASCADE
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TABLE
|
CREATE TABLE
|
||||||
@ -108,34 +112,45 @@ CREATE TABLE
|
|||||||
user_id uuid,
|
user_id uuid,
|
||||||
book_id uuid,
|
book_id uuid,
|
||||||
state varchar(12),
|
state varchar(12),
|
||||||
date_added timestamp default NULL,
|
added_at timestamp default NULL,
|
||||||
date_modified timestamp default NULL,
|
modified_at timestamp default NULL,
|
||||||
PRIMARY KEY (user_id, book_id),
|
PRIMARY KEY (user_id, book_id),
|
||||||
FOREIGN KEY (user_id) REFERENCES users (user_id),
|
FOREIGN KEY (user_id) REFERENCES users (user_id) ON DELETE CASCADE,
|
||||||
FOREIGN KEY (book_id) REFERENCES books (book_id)
|
FOREIGN KEY (book_id) REFERENCES books (book_id) ON DELETE CASCADE
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE book_statuses
|
ALTER TABLE book_statuses
|
||||||
ALTER COLUMN date_added
|
ALTER COLUMN added_at
|
||||||
SET DEFAULT now ();
|
SET DEFAULT now ();
|
||||||
|
|
||||||
ALTER TABLE book_statuses
|
CREATE INDEX book_statuses_user_id_login_idx ON users (user_id);
|
||||||
ALTER COLUMN date_modified
|
|
||||||
SET DEFAULT now ();
|
|
||||||
|
|
||||||
CREATE INDEX book_statuses_user_id_login_idx ON users USING HASH (user_id);
|
CREATE TABLE
|
||||||
|
series_subscriptions (
|
||||||
|
user_id uuid,
|
||||||
|
provider text,
|
||||||
|
provider_series_id text,
|
||||||
|
added_at timestamp default NULL,
|
||||||
|
PRIMARY KEY (user_id, provider, provider_series_id),
|
||||||
|
FOREIGN KEY (user_id) REFERENCES users (user_id) ON DELETE CASCADE,
|
||||||
|
FOREIGN KEY (provider, provider_series_id) REFERENCES series (provider, provider_series_id) ON DELETE CASCADE
|
||||||
|
);
|
||||||
|
|
||||||
|
ALTER TABLE series_subscriptions
|
||||||
|
ALTER COLUMN added_at
|
||||||
|
SET DEFAULT now ();
|
||||||
|
|
||||||
CREATE TABLE
|
CREATE TABLE
|
||||||
api_keys (
|
api_keys (
|
||||||
user_id uuid,
|
user_id uuid,
|
||||||
api_key char(64),
|
api_key char(64),
|
||||||
date_added timestamp default NULL,
|
added_at timestamp default NULL,
|
||||||
PRIMARY KEY (user_id, api_key),
|
PRIMARY KEY (user_id, api_key),
|
||||||
FOREIGN KEY (user_id) REFERENCES users (user_id)
|
FOREIGN KEY (user_id) REFERENCES users (user_id) ON DELETE CASCADE
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE api_keys
|
ALTER TABLE api_keys
|
||||||
ALTER COLUMN date_added
|
ALTER COLUMN added_at
|
||||||
SET DEFAULT now ();
|
SET DEFAULT now ();
|
||||||
|
|
||||||
CREATE INDEX api_keys_api_key_idx ON api_keys USING HASH (api_key);
|
CREATE INDEX api_keys_api_key_idx ON api_keys (api_key);
|
@ -1,9 +1,10 @@
|
|||||||
import * as argon2 from 'argon2';
|
import * as argon2 from 'argon2';
|
||||||
import * as crypto from 'crypto';
|
import * as crypto from 'crypto';
|
||||||
import { UUID } from "crypto";
|
import { UUID } from "crypto";
|
||||||
|
import { BookStatusEntity } from 'src/books/books/entities/book-status.entity';
|
||||||
import { BigIntTransformer } from 'src/shared/transformers/bigint';
|
import { BigIntTransformer } from 'src/shared/transformers/bigint';
|
||||||
import { StringToLowerCaseTransformer } from 'src/shared/transformers/string';
|
import { StringToLowerCaseTransformer } from 'src/shared/transformers/string';
|
||||||
import { BeforeInsert, Column, Entity, PrimaryGeneratedColumn } from "typeorm";
|
import { BeforeInsert, Column, Entity, OneToMany, PrimaryGeneratedColumn } from "typeorm";
|
||||||
|
|
||||||
@Entity({
|
@Entity({
|
||||||
name: 'users'
|
name: 'users'
|
||||||
@ -18,17 +19,20 @@ export class UserEntity {
|
|||||||
@Column({ name: 'user_name', nullable: false })
|
@Column({ name: 'user_name', nullable: false })
|
||||||
userName: string;
|
userName: string;
|
||||||
|
|
||||||
@Column({ nullable: false })
|
@Column({ name: 'password', nullable: false })
|
||||||
password: string;
|
password: string;
|
||||||
|
|
||||||
@Column({ type: 'bigint', nullable: false, transformer: BigIntTransformer })
|
@Column({ name: 'salt', type: 'bigint', nullable: false, transformer: BigIntTransformer })
|
||||||
salt: BigInt;
|
salt: BigInt;
|
||||||
|
|
||||||
@Column({ name: 'is_admin', nullable: false })
|
@Column({ name: 'is_admin', nullable: false })
|
||||||
isAdmin: boolean;
|
isAdmin: boolean;
|
||||||
|
|
||||||
@Column({ name: 'date_joined', type: 'timestamptz', nullable: false })
|
@Column({ name: 'joined_at', type: 'timestamptz', nullable: false })
|
||||||
dateJoined: Date;
|
joinedAt: Date;
|
||||||
|
|
||||||
|
@OneToMany(type => BookStatusEntity, bookStatus => bookStatus.userId)
|
||||||
|
bookStatuses: BookStatusEntity[];
|
||||||
|
|
||||||
@BeforeInsert()
|
@BeforeInsert()
|
||||||
async hashPassword() {
|
async hashPassword() {
|
@ -1,6 +1,6 @@
|
|||||||
import { Module } from '@nestjs/common';
|
import { Module } from '@nestjs/common';
|
||||||
import { UsersService } from './users.service';
|
import { UsersService } from './users.service';
|
||||||
import { UserEntity } from './users.entity';
|
import { UserEntity } from './entities/users.entity';
|
||||||
import { TypeOrmModule } from '@nestjs/typeorm';
|
import { TypeOrmModule } from '@nestjs/typeorm';
|
||||||
import { UsersController } from './users.controller';
|
import { UsersController } from './users.controller';
|
||||||
import { ConfigModule } from '@nestjs/config';
|
import { ConfigModule } from '@nestjs/config';
|
||||||
|
@ -2,7 +2,7 @@ import * as argon2 from 'argon2';
|
|||||||
import { Injectable } from '@nestjs/common';
|
import { Injectable } from '@nestjs/common';
|
||||||
import { InjectRepository } from '@nestjs/typeorm';
|
import { InjectRepository } from '@nestjs/typeorm';
|
||||||
import { Repository } from 'typeorm';
|
import { Repository } from 'typeorm';
|
||||||
import { UserEntity } from './users.entity';
|
import { UserEntity } from './entities/users.entity';
|
||||||
import { LoginUserDto } from './dto/login-user.dto';
|
import { LoginUserDto } from './dto/login-user.dto';
|
||||||
import { UUID } from 'crypto';
|
import { UUID } from 'crypto';
|
||||||
|
|
||||||
@ -11,7 +11,7 @@ class UserDto {
|
|||||||
userLogin: string;
|
userLogin: string;
|
||||||
userName: string;
|
userName: string;
|
||||||
isAdmin: boolean;
|
isAdmin: boolean;
|
||||||
dateJoined: Date;
|
joinedAt: Date;
|
||||||
}
|
}
|
||||||
|
|
||||||
@Injectable()
|
@Injectable()
|
||||||
@ -28,7 +28,7 @@ export class UsersService {
|
|||||||
userLogin: u.userLogin,
|
userLogin: u.userLogin,
|
||||||
userName: u.userName,
|
userName: u.userName,
|
||||||
isAdmin: u.isAdmin,
|
isAdmin: u.isAdmin,
|
||||||
dateJoined: u.dateJoined,
|
joinedAt: u.joinedAt,
|
||||||
}));
|
}));
|
||||||
}
|
}
|
||||||
|
|
||||||
|
Reference in New Issue
Block a user