diff --git a/.dockerignore b/.dockerignore
index d95cec9..fe9214f 100644
--- a/.dockerignore
+++ b/.dockerignore
@@ -1,4 +1,7 @@
Dockerfile
+Dockerfile.prod
+docker-compose.yml
.dockerignore
.git
.gitignore
+node_modules
diff --git a/Dockerfile.prod b/Dockerfile.prod
new file mode 100644
index 0000000..49539fd
--- /dev/null
+++ b/Dockerfile.prod
@@ -0,0 +1,24 @@
+FROM node:14 AS builder
+
+USER node
+
+ENV PATH="/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/sbin:/bin:/app/node_modules/.bin"
+
+COPY --chown=node . /app
+WORKDIR /app
+RUN ["npm", "install"]
+RUN ["tsc", "--outDir", "build"]
+
+FROM node:14-alpine
+
+EXPOSE 3000
+ENV PORT 3000
+ENV PATH="/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/sbin:/bin:/app/node_modules/.bin" NODE_ENV="production"
+
+USER node
+WORKDIR /app
+COPY --from=builder /app/build build
+COPY --from=builder /app/node_modules node_modules
+COPY --from=builder /app/public public
+COPY --from=builder /app/views views
+CMD ["node", "./build/app.js"]
diff --git a/RELEASE.md b/RELEASE.md
new file mode 100644
index 0000000..c60d7c9
--- /dev/null
+++ b/RELEASE.md
@@ -0,0 +1,30 @@
+# Release Checklist
+
+## Release Type
+- Were there any database schema changes?
+- Are there any significant UI changes?
+- Have any significant new features been added?
+- Are there any API changes?
+
+If the answer to any of the above is yes, then the release MUST be a major or minor release. Otherwise, the release MAY be a patch release (at developer's discretion).
+
+## Major/Minor Releases
+- [ ] Add a commit which adds a database upgrade script at `db/upgrade/[oldversion]-[newversion].sql`
+ - ALWAYS use a transaction for the entirety of this file
+ - At minimum, DB version must be bumped
+ - Test the upgrade script as follows:
+ ```
+ git checkout [previous release tag]
+ docker-compose down
+ docker-compose up
+ psql -h 0 -U postgres < db/upgrade/v[previous]-v[current].sql
+ ```
+ Update the version in `src/version.ts` and verify the app works as expected.
+- [ ] Add a commit which bumps the version in `src/version.ts` and `db/00-version.sql`, entitled `Bump version to vMAJOR.MINOR`
+- [ ] Tag the latest commit with `vMAJOR.MINOR`
+- [ ] Write release notes
+
+## Patch Releases
+- [ ] Add a commit which bumps the patch level in `src/version.ts`, entitled `Bump version to vMAJOR.MINOR.PATCH`
+- [ ] Tag the latest commit with `vMAJOR.MINOR.PATCH`
+- [ ] Write release notes
\ No newline at end of file
diff --git a/db/00-version.sql b/db/00-version.sql
index 5c43aec..6686897 100644
--- a/db/00-version.sql
+++ b/db/00-version.sql
@@ -8,4 +8,4 @@ CREATE OR REPLACE FUNCTION get_version() RETURNS VARCHAR
AS $$SELECT major || '.' || minor FROM version $$
LANGUAGE SQL;
-INSERT INTO version (major,minor) VALUES (0,2);
+INSERT INTO version (major,minor) VALUES (0,8);
diff --git a/db/05-config.sql b/db/05-config.sql
index edf6d9e..2e830ab 100644
--- a/db/05-config.sql
+++ b/db/05-config.sql
@@ -1,10 +1,14 @@
CREATE TABLE config (
rowlock bool DEFAULT TRUE UNIQUE NOT NULL CHECK (rowlock = TRUE),
- normaluservotepoints int NOT NULL,
- followervotepoints int NOT NULL,
- subscribervotepoints int NOT NULL,
+ normaluservotepoints int NOT NULL DEFAULT 10,
+ followervotepoints int NOT NULL DEFAULT 50,
+ subscribervotepoints int NOT NULL DEFAULT 100,
+ normaluserratelimit int NOT NULL DEFAULT 1,
+ followerratelimit int NOT NULL DEFAULT 2,
+ subscriberratelimit int NOT NULL DEFAULT 3,
+ title varchar NOT NULL DEFAULT '{username}''s Learn Request Queue',
+ colors jsonb NOT NULL DEFAULT '{"bg": {"primary": "#444444","table": "#282828","navbar": "#666666","error": "#ff0000"},"fg": {"primary": "#dddddd","ahover": "#ffffff","title": "#eeeeee"}}',
PRIMARY KEY (rowLock)
);
-INSERT INTO config (normalUserVotePoints,followerVotePoints,subscriberVotePoints)
- VALUES (10,50,100);
+INSERT INTO config (rowlock) VALUES (true);
diff --git a/db/10-cron.sql b/db/10-cron.sql
new file mode 100644
index 0000000..a0b1941
--- /dev/null
+++ b/db/10-cron.sql
@@ -0,0 +1,13 @@
+CREATE TABLE cron (
+ jobName varchar UNIQUE NOT NULL, -- Application-recognizable name for the job
+ runinterval interval NOT NULL, -- Duration between runs
+ -- Last successful run - only gets updated if run is successful
+ lastSuccess timestamptz DEFAULT to_timestamp(0), -- Defaults to beginning of time
+ PRIMARY KEY(jobName)
+);
+
+INSERT INTO cron (jobName,runInterval) VALUES
+('processBans','30 minutes'),
+('processFollows','30 minutes'),
+('processSubscriptions','30 minutes'),
+('processEmptyMetadata','1 day');
diff --git a/db/10-users.sql b/db/10-users.sql
index dc0aef7..7774265 100644
--- a/db/10-users.sql
+++ b/db/10-users.sql
@@ -2,7 +2,5 @@ CREATE TABLE users (
userId int NOT NULL,
displayName varchar NOT NULL,
imageUrl varchar,
- isFollower boolean NOT NULL DEFAULT FALSE,
- isSubscriber boolean NOT NULL DEFAULT FALSE,
PRIMARY KEY (userId)
);
diff --git a/db/15-streamer.sql b/db/15-streamer.sql
index 53068c8..b39604c 100644
--- a/db/15-streamer.sql
+++ b/db/15-streamer.sql
@@ -3,4 +3,4 @@ CREATE TABLE streamer (
tokenPair json,
PRIMARY KEY (userid),
FOREIGN KEY (userid) REFERENCES users(userid)
-)
+);
diff --git a/db/20-requests.sql b/db/20-requests.sql
index c3f3cf5..b63c359 100644
--- a/db/20-requests.sql
+++ b/db/20-requests.sql
@@ -1,5 +1,5 @@
CREATE TABLE requests (
- url varchar NOT NULL UNIQUE,
+ url varchar NOT NULL,
requester int NOT NULL,
state varchar NOT NULL DEFAULT 'Requested',
reqTimestamp timestamptz NOT NULL DEFAULT NOW(),
diff --git a/db/30-votes.sql b/db/30-votes.sql
index 0b878ba..8da76f0 100644
--- a/db/30-votes.sql
+++ b/db/30-votes.sql
@@ -1,6 +1,6 @@
CREATE TABLE votes (
- requestUrl varchar,
- userId int,
+ requestUrl varchar NOT NULL,
+ userId int NOT NULL,
PRIMARY KEY (requestUrl,userId),
FOREIGN KEY (requestUrl) REFERENCES requests(url) ON DELETE CASCADE,
FOREIGN KEY (userId) REFERENCES users(userId) ON DELETE CASCADE
diff --git a/db/50-bans.sql b/db/50-bans.sql
index 979ae21..20ecfa1 100644
--- a/db/50-bans.sql
+++ b/db/50-bans.sql
@@ -1,4 +1,4 @@
CREATE TABLE bans (
userid integer,
PRIMARY KEY (userid)
-)
+);
diff --git a/db/50-follows.sql b/db/50-follows.sql
new file mode 100644
index 0000000..63e1200
--- /dev/null
+++ b/db/50-follows.sql
@@ -0,0 +1,4 @@
+CREATE TABLE follows (
+ userid integer,
+ PRIMARY KEY (userid)
+);
diff --git a/db/50-subscriptions.sql b/db/50-subscriptions.sql
new file mode 100644
index 0000000..7e23cf1
--- /dev/null
+++ b/db/50-subscriptions.sql
@@ -0,0 +1,4 @@
+CREATE TABLE subscriptions (
+ userid integer,
+ PRIMARY KEY (userid)
+);
diff --git a/db/90-views.sql b/db/90-views.sql
index e274069..a31ec16 100644
--- a/db/90-views.sql
+++ b/db/90-views.sql
@@ -2,8 +2,7 @@ CREATE OR REPLACE VIEW requests_vw AS
SELECT url,COALESCE(videoTitle,url) AS title,displayName AS requester,imageUrl,state,score,reqTimestamp FROM requests
JOIN requestMetadata USING (url)
JOIN scores USING (url)
- JOIN users ON requests.requester = users.userid
- ORDER BY score DESC, reqTimestamp ASC;
+ JOIN users ON requests.requester = users.userid;
CREATE OR REPLACE FUNCTION get_requests_voted(votinguserid int)
RETURNS TABLE (
@@ -21,8 +20,7 @@ CREATE OR REPLACE FUNCTION get_requests_voted(votinguserid int)
SELECT url,title,requester,imageUrl,state,score,reqTimestamp,
(CASE WHEN votes.userid IS NULL THEN FALSE ELSE TRUE END) AS voted
FROM requests_vw
- LEFT JOIN votes ON (requests_vw.url = votes.requesturl AND votes.userid = votinguserid)
- ORDER BY score DESC, reqTimestamp ASC;
+ LEFT JOIN votes ON (requests_vw.url = votes.requesturl AND votes.userid = votinguserid);
$$;
/*
@@ -40,18 +38,20 @@ CREATE OR REPLACE VIEW vote_score_vw AS
COUNT(votes.requesturl) AS count,
COALESCE(
SUM(CASE
- WHEN users.isfollower = FALSE AND users.issubscriber = FALSE
+ WHEN follows.userid IS NULL AND subscriptions.userid IS NULL
+ AND votes.userid IS NOT NULL
THEN votepoints.normaluservotepoints
- WHEN users.isfollower = TRUE AND users.issubscriber = FALSE
+ WHEN follows.userid IS NOT NULL AND subscriptions.userid IS NULL
THEN votepoints.followervotepoints
- WHEN users.issubscriber = TRUE
+ WHEN subscriptions.userid IS NOT NULL
THEN votepoints.subscribervotepoints
END), 0
) AS votescore
FROM requests
LEFT JOIN votes ON votes.requesturl = requests.url
- LEFT JOIN users on votes.userid = users.userid
- LEFT JOIN bans ON users.userid = bans.userid
+ LEFT JOIN bans ON votes.userid = bans.userid
+ LEFT JOIN follows ON votes.userid = follows.userid
+ LEFT JOIN subscriptions ON votes.userid = subscriptions.userid
CROSS JOIN votepoints
WHERE bans.userid IS NULL
GROUP BY url;
@@ -60,3 +60,22 @@ CREATE OR REPLACE VIEW streamer_user_vw AS
SELECT users.userid as userid, users.displayname as displayname, users.imageurl as imageurl FROM streamer
LEFT JOIN users
ON streamer.userid = users.userid;
+
+CREATE OR REPLACE VIEW ratelimit_vw AS
+ SELECT users.userid,COALESCE(count,0),ratelimit.reqcount AS max,COALESCE(count,0) >= ratelimit.reqcount AS status
+ FROM users
+ LEFT JOIN (SELECT requester,COUNT(url)
+ FROM requests
+ WHERE reqtimestamp > (now() - '24 hours'::interval)
+ GROUP BY requests.requester
+ ) AS requests ON users.userid = requests.requester
+ LEFT JOIN follows ON requests.requester = follows.userid
+ LEFT JOIN subscriptions ON requests.requester = subscriptions.userid
+ CROSS JOIN config
+ CROSS JOIN LATERAL (VALUES (
+ CASE
+ WHEN follows.userid IS NULL AND subscriptions.userid IS NULL THEN config.normaluserratelimit
+ WHEN follows.userid IS NOT NULL AND subscriptions.userid IS NULL THEN config.followerratelimit
+ WHEN subscriptions.userid IS NOT NULL THEN config.subscriberratelimit
+ END
+ )) AS ratelimit(reqcount);
diff --git a/db/95-procedures.sql b/db/95-procedures.sql
index f2427bf..650f119 100644
--- a/db/95-procedures.sql
+++ b/db/95-procedures.sql
@@ -16,6 +16,13 @@ CREATE OR REPLACE PROCEDURE add_request(url varchar,requester int)
CALL update_scores();
$$;
+CREATE OR REPLACE PROCEDURE clear_zero_votes()
+ LANGUAGE SQL
+ AS $$
+ DELETE FROM requests WHERE NOT EXISTS
+ (SELECT FROM votes WHERE requests.url = votes.requesturl);
+ $$;
+
CREATE OR REPLACE PROCEDURE add_vote(url varchar,voteuser int)
LANGUAGE SQL
AS $$
@@ -28,6 +35,7 @@ CREATE OR REPLACE PROCEDURE delete_vote(url varchar,voteuser int)
AS $$
DELETE FROM votes WHERE requesturl = url AND userid = voteuser;
CALL update_scores();
+ CALL clear_zero_votes();
$$;
CREATE OR REPLACE PROCEDURE update_request_score_modifier(updateurl varchar, scoreDiff int)
@@ -36,3 +44,11 @@ CREATE OR REPLACE PROCEDURE update_request_score_modifier(updateurl varchar, sco
UPDATE scores SET scoreModifier = scoreModifier + scoreDiff WHERE url = updateurl;
CALL update_scores();
$$;
+
+CREATE OR REPLACE PROCEDURE update_vote_points(normaluser int, follower int, subscriber int)
+ LANGUAGE SQL
+ AS $$
+ UPDATE config SET normaluservotepoints = normaluser,
+ followervotepoints = follower, subscribervotepoints = subscriber;
+ CALL update_scores();
+ $$;
diff --git a/db/testdata.sql b/db/testdata.sql
index 83428e6..98db264 100644
--- a/db/testdata.sql
+++ b/db/testdata.sql
@@ -1,8 +1,16 @@
-INSERT INTO users (userid,displayName,isFollower,isSubscriber) VALUES
- (001,'TestUser',false,false),
- (002,'TestFollower',true,false),
- (003,'TestSubscriber',true,true),
- (004,'TestSubNonFollower',false,true);
+INSERT INTO users (userid,displayName) VALUES
+ (001,'TestUser'),
+ (002,'TestFollower'),
+ (003,'TestSubscriber'),
+ (004,'TestSubNonFollower');
+
+INSERT INTO follows (userid) VALUES
+ (002),
+ (003);
+
+INSERT INTO subscriptions (userid) VALUES
+ (003),
+ (004);
CALL add_request('https://www.youtube.com/watch?v=dQw4w9WgXcQ',001);
CALL add_request('https://www.youtube.com/watch?v=C5oeWHngDS4',002);
diff --git a/db/upgrade/v0.2-v0.3.sql b/db/upgrade/v0.2-v0.3.sql
new file mode 100644
index 0000000..defe309
--- /dev/null
+++ b/db/upgrade/v0.2-v0.3.sql
@@ -0,0 +1,18 @@
+BEGIN;
+
+UPDATE version SET minor = 3;
+
+CREATE TABLE cron (
+ jobName varchar UNIQUE NOT NULL, -- Application-recognizable name for the job
+ runinterval interval NOT NULL, -- Duration between runs
+ -- Last successful run - only gets updated if run is successful
+ lastSuccess timestamptz DEFAULT to_timestamp(0), -- Defaults to beginning of time
+ PRIMARY KEY(jobName)
+);
+
+INSERT INTO cron (jobName,runInterval) VALUES
+('processBans','30 minutes'),
+('processEmptyMetadata','1 day');
+
+
+COMMIT;
diff --git a/db/upgrade/v0.3-0.4.sql b/db/upgrade/v0.3-0.4.sql
new file mode 100644
index 0000000..e15ef43
--- /dev/null
+++ b/db/upgrade/v0.3-0.4.sql
@@ -0,0 +1,9 @@
+BEGIN;
+
+UPDATE version SET minor = 4;
+
+ALTER TABLE config ADD COLUMN title varchar, ADD COLUMN colors jsonb;
+UPDATE config SET title = '{username}''s Learn Request Queue', colors = '{"bg": {"primary": "#444444","table": "#282828","navbar" : "#666666","error": "#ff0000"},"fg": {"primary": "#dddddd","ahover": "#ffffff","title": "#eeeeee"}}';
+ALTER TABLE config ALTER COLUMN title SET NOT NULL, ALTER COLUMN colors SET NOT NULL;
+
+COMMIT;
diff --git a/db/upgrade/v0.4-0.5.sql b/db/upgrade/v0.4-0.5.sql
new file mode 100644
index 0000000..df6d8e7
--- /dev/null
+++ b/db/upgrade/v0.4-0.5.sql
@@ -0,0 +1,53 @@
+BEGIN;
+
+UPDATE version SET minor = 5;
+
+CREATE OR REPLACE PROCEDURE update_vote_points(normaluser int, follower int, subscriber int)
+ LANGUAGE SQL
+ AS $$
+ UPDATE config SET normaluservotepoints = normaluser,
+ followervotepoints = follower, subscribervotepoints = subscriber;
+ CALL update_scores();
+ $$;
+
+CREATE TABLE follows (
+ userid integer,
+ PRIMARY KEY (userid)
+);
+
+CREATE TABLE subscriptions (
+ userid integer,
+ PRIMARY KEY (userid)
+);
+
+CREATE OR REPLACE VIEW vote_score_vw AS
+ WITH votepoints AS (SELECT normaluservotepoints, followervotepoints, subscribervotepoints FROM config)
+ SELECT requests.url AS url,
+ COUNT(votes.requesturl) AS count,
+ COALESCE(
+ SUM(CASE
+ WHEN follows.userid IS NULL AND subscriptions.userid IS NULL
+ AND votes.userid IS NOT NULL
+ THEN votepoints.normaluservotepoints
+ WHEN follows.userid IS NOT NULL AND subscriptions.userid IS NULL
+ THEN votepoints.followervotepoints
+ WHEN subscriptions.userid IS NOT NULL
+ THEN votepoints.subscribervotepoints
+ END), 0
+ ) AS votescore
+ FROM requests
+ LEFT JOIN votes ON votes.requesturl = requests.url
+ LEFT JOIN bans ON votes.userid = bans.userid
+ LEFT JOIN follows ON votes.userid = follows.userid
+ LEFT JOIN subscriptions ON votes.userid = subscriptions.userid
+ CROSS JOIN votepoints
+ WHERE bans.userid IS NULL
+ GROUP BY url;
+
+ALTER TABLE users DROP COLUMN isfollower, DROP COLUMN issubscriber;
+
+INSERT INTO cron (jobName,runInterval) VALUES
+('processFollows','30 minutes'),
+('processSubscriptions','30 minutes');
+
+COMMIT;
diff --git a/db/upgrade/v0.5-v0.6.sql b/db/upgrade/v0.5-v0.6.sql
new file mode 100644
index 0000000..a43869c
--- /dev/null
+++ b/db/upgrade/v0.5-v0.6.sql
@@ -0,0 +1,5 @@
+BEGIN;
+
+UPDATE version SET minor = 6;
+
+COMMIT;
diff --git a/db/upgrade/v0.6-v0.7.sql b/db/upgrade/v0.6-v0.7.sql
new file mode 100644
index 0000000..0939227
--- /dev/null
+++ b/db/upgrade/v0.6-v0.7.sql
@@ -0,0 +1,24 @@
+BEGIN;
+
+UPDATE version SET minor = 7;
+
+ALTER TABLE votes
+ ALTER COLUMN requestUrl SET NOT NULL,
+ ALTER COLUMN userId SET NOT NULL;
+
+CREATE OR REPLACE PROCEDURE clear_zero_votes()
+ LANGUAGE SQL
+ AS $$
+ DELETE FROM requests WHERE NOT EXISTS
+ (SELECT FROM votes WHERE requests.url = votes.requesturl);
+ $$;
+
+CREATE OR REPLACE PROCEDURE delete_vote(url varchar,voteuser int)
+ LANGUAGE SQL
+ AS $$
+ DELETE FROM votes WHERE requesturl = url AND userid = voteuser;
+ CALL update_scores();
+ CALL clear_zero_votes();
+ $$;
+
+COMMIT;
diff --git a/db/upgrade/v0.7-v0.8.sql b/db/upgrade/v0.7-v0.8.sql
new file mode 100644
index 0000000..af83dae
--- /dev/null
+++ b/db/upgrade/v0.7-v0.8.sql
@@ -0,0 +1,35 @@
+BEGIN;
+
+UPDATE version SET minor = 8;
+
+ALTER TABLE config
+ ALTER COLUMN normaluservotepoints SET DEFAULT 10,
+ ALTER COLUMN followervotepoints SET DEFAULT 50,
+ ALTER COLUMN subscribervotepoints SET DEFAULT 100,
+ ALTER COLUMN title SET DEFAULT '{username}''s Learn Request Queue',
+ ALTER COLUMN colors SET DEFAULT '{"bg": {"primary": "#444444","table": "#282828","navbar": "#666666","error": "#ff0000"},"fg": {"primary": "#dddddd","ahover": "#ffffff","title": "#eeeeee"}}',
+ ADD COLUMN normaluserratelimit int NOT NULL DEFAULT 1,
+ ADD COLUMN followerratelimit int NOT NULL DEFAULT 2,
+ ADD COLUMN subscriberratelimit int NOT NULL DEFAULT 3;
+
+CREATE OR REPLACE VIEW ratelimit_vw AS
+ SELECT users.userid,COALESCE(count,0),ratelimit.reqcount AS max,COALESCE(count,0) >= ratelimit.reqcount AS status
+ FROM users
+ LEFT JOIN (SELECT requester,COUNT(url)
+ FROM requests
+ WHERE reqtimestamp > (now() - '24 hours'::interval)
+ GROUP BY requests.requester
+ ) AS requests ON users.userid = requests.requester
+ LEFT JOIN follows ON requests.requester = follows.userid
+ LEFT JOIN subscriptions ON requests.requester = subscriptions.userid
+ CROSS JOIN config
+ CROSS JOIN LATERAL (VALUES (
+ CASE
+ WHEN follows.userid IS NULL AND subscriptions.userid IS NULL THEN config.normaluserratelimit
+ WHEN follows.userid IS NOT NULL AND subscriptions.userid IS NULL THEN config.followerratelimit
+ WHEN subscriptions.userid IS NOT NULL THEN config.subscriberratelimit
+ END
+ )) AS ratelimit(reqcount);
+
+
+COMMIT;
diff --git a/docker-compose.yml b/docker-compose.yml
index aa08979..818df75 100644
--- a/docker-compose.yml
+++ b/docker-compose.yml
@@ -1,7 +1,7 @@
version: '3.8'
services:
app:
- container_name: learn-request-queue
+ container_name: lrq
build: .
depends_on:
- db
@@ -11,7 +11,7 @@ services:
- "80:3000"
env_file: .env
db:
- container_name: learn-request-queue-db
+ container_name: lrqdb
image: postgres
ports:
- "5432:5432"
diff --git a/public/main.js b/public/main.js
index d4cf22c..e9fee5d 100644
--- a/public/main.js
+++ b/public/main.js
@@ -1,28 +1,52 @@
var requestsDiv = document.getElementById("requests");
+var cronJobs = ['processBans'];
+var currentPage = 1;
+var totalPages = 1;
+var count = document.getElementById("count").value;
+var sortBy = document.getElementById("sortBy").value;
+var sortDir = "desc";
-function getRequests(count,allRequests) {
- var reqUrl;
- if (allRequests) {
- reqUrl = "/api/getAllRequests";
- } else {
- reqUrl = "/api/getRequests";
- }
- reqUrl += `?count=${count}`;
+function getRequests(offset,allRequests) {
+ if (allRequests) var reqUrl = "/api/getAllRequests";
+ else var reqUrl = "/api/getRequests";
+ reqUrl += `?count=${count}&offset=${offset}&sort=${sortBy}&sortDirection=${sortDir}`;
fetch(reqUrl)
.then(response => response.json())
.then(requests => {
- window.requests = requests;
- buildTable();
+ buildTable(requests);
});
}
-function buildTable() {
- var requestsDivHTML = '