diff --git a/.gitignore b/.gitignore index c846c98..a4e6200 100644 --- a/.gitignore +++ b/.gitignore @@ -3,3 +3,4 @@ DBProject3.iml tech-db-forum target report.html +tech-db-forum.dat.gz diff --git a/Dockerfile b/Dockerfile new file mode 100644 index 0000000..9eed6ab --- /dev/null +++ b/Dockerfile @@ -0,0 +1,39 @@ +FROM ubuntu:16.04 + +MAINTAINER Serge Peshkoff + +RUN apt-get -y update + +ENV PGVER 9.5 +RUN apt-get install -y postgresql-$PGVER && apt-get clean all + +USER postgres + +RUN /etc/init.d/postgresql start &&\ + psql --command "CREATE USER docker WITH SUPERUSER PASSWORD 'docker';" &&\ + createdb -E UTF8 -T template0 -O docker docker &&\ + /etc/init.d/postgresql stop + +RUN echo "host all all 0.0.0.0/0 md5" >> /etc/postgresql/$PGVER/main/pg_hba.conf + +RUN echo "listen_addresses='*'" >> /etc/postgresql/$PGVER/main/postgresql.conf +RUN echo "synchronous_commit = off" >> /etc/postgresql/$PGVER/main/postgresql.conf + + +EXPOSE 5432 +VOLUME ["/etc/postgresql", "/var/log/postgresql", "/var/lib/postgresql"] + +USER root + +RUN apt-get install -y openjdk-8-jdk-headless && apt-get clean all +RUN apt-get install -y maven && apt-get clean all + +ENV APP /root/app +ADD ./ $APP + +WORKDIR $APP +RUN mvn package + +EXPOSE 5000 + +CMD service postgresql start && java -Xmx300M -Xmx300M -jar $APP/target/db-project-2.0.jar diff --git a/postgresql.log b/postgresql.log new file mode 100644 index 0000000..e69de29 diff --git a/src/main/java/coon/controllers/Forum.java b/src/main/java/coon/controllers/Forum.java index 68bf95f..0ae278a 100644 --- a/src/main/java/coon/controllers/Forum.java +++ b/src/main/java/coon/controllers/Forum.java @@ -138,7 +138,7 @@ public ResponseEntity> users( @RequestParam(name = "desc", defaultValue = "false", required = false) boolean desc ) { try { - this.forums.get(slug); + this.forums.realSlug(slug); } catch (EmptyResultDataAccessException e) { return new ResponseEntity<>(HttpStatus.NOT_FOUND); } diff --git a/src/main/java/coon/controllers/Thread.java b/src/main/java/coon/controllers/Thread.java index d9539a1..77abfaa 100644 --- a/src/main/java/coon/controllers/Thread.java +++ b/src/main/java/coon/controllers/Thread.java @@ -105,10 +105,10 @@ public ResponseEntity posts( @RequestParam(name = "desc", defaultValue = "false", required = false) boolean desc, @RequestParam(name = "sort", defaultValue = "flat", required = false) String sort ) { - ThreadData thread; + int threadId; try { - thread = this.threads.resolve(slugOrId); + threadId = this.threads.fastResolve(slugOrId); } catch (EmptyResultDataAccessException e) { return new ResponseEntity<>(HttpStatus.NOT_FOUND); } @@ -117,13 +117,13 @@ public ResponseEntity posts( int marker = 0; if (sort.equalsIgnoreCase("flat")) { - posts = this.posts.flat(thread, offset, limit, desc); + posts = this.posts.flat(threadId, offset, limit, desc); marker = posts.size(); } else if (sort.equalsIgnoreCase("tree")) { - posts = this.posts.tree(thread, offset, limit, desc); + posts = this.posts.tree(threadId, offset, limit, desc); marker = posts.size(); } else { - posts = this.posts.parentTree(thread, offset, limit, desc); + posts = this.posts.parentTree(threadId, offset, limit, desc); for (PostData post: posts) { if (post.getParent() == 0) { @@ -132,6 +132,12 @@ public ResponseEntity posts( } } + if (posts.size() == 0) { + if (!this.threads.exists(threadId)) { + return new ResponseEntity<>(HttpStatus.NOT_FOUND); + } + } + return new ResponseEntity<>( new PostQueryData(offset + marker, posts), HttpStatus.OK diff --git a/src/main/java/coon/models/Forums.java b/src/main/java/coon/models/Forums.java index f19a910..22d79a9 100644 --- a/src/main/java/coon/models/Forums.java +++ b/src/main/java/coon/models/Forums.java @@ -42,22 +42,13 @@ public ForumData create(ForumData forum) { public ForumData get(String slug) { return this.jdbc.queryForObject( - "SELECT * FROM Forums WHERE lower(slug) = lower(?) LIMIT 1", + "SELECT slug, title, author, posts, threads FROM Forums WHERE lower(slug) = lower(?) LIMIT 1", new ForumData(), slug ); } - public ForumData set(ForumData forum) { - return this.jdbc.queryForObject( - "UPDATE Forums SET posts = ?, threads = ? WHERE lower(slug) = lower(?) RETURNING *", - new ForumData(), - forum.getPosts(), forum.getThreads(), forum.getSlug() - ); - } - - public void addMember(String forum, String author) { try { this.jdbc.queryForObject( @@ -70,11 +61,6 @@ public void addMember(String forum, String author) { } catch (EmptyResultDataAccessException e) { UserData user = this.users.get(author); - /*this.jdbc.update( - "INSERT INTO Members (forum, author, fullname, email, about) VALUES (?, ?, ?, ?, ?)", - forum, user.getNickname(), user.getFullName(), user.getEmail(), user.getAbout() - );*/ - this.jdbc.update( "INSERT INTO Members (forum, author) VALUES (?, ?)", forum, user.getNickname() @@ -83,6 +69,15 @@ public void addMember(String forum, String author) { } + public void incStat(String slug, int postDelta, int threadDelta) { + this.jdbc.update( + "UPDATE Forums SET posts = posts + ?, threads = threads + ? " + + "WHERE lower(slug) = lower(?)", + postDelta, threadDelta, slug + ); + } + + public List members(String forum, String since, int limit, boolean desc) { String order = (desc ? "DESC" : "ASC"); @@ -93,20 +88,19 @@ public List members(String forum, String since, int limit, boolean des "lower(Members.forum) = lower(?) " + (since != null ? "AND lower(Members.author) " + (desc ? "<" : ">") + " lower(?)" : "AND ?::TEXT IS NULL")+ - " ORDER BY lower(Members.author) " + order + " LIMIT ?", + " ORDER BY lower(Users.nickname) " + order + " LIMIT ?", new UserData(), forum, since, limit ); + } - /*return this.jdbc.query( - "SELECT *, author AS nickname FROM Members WHERE " + - "lower(forum) = lower(?) " + - (since != null ? "AND lower(author) " + (desc ? "<" : ">") + " lower(?)" - : "AND ?::TEXT IS NULL")+ - " ORDER BY lower(author) " + order + " LIMIT ?", - new UserData(), - forum, since, limit - );*/ + + public String realSlug(String slug) { + return this.jdbc.queryForObject( + "SELECT slug FROM Forums WHERE lower(slug) = lower(?) LIMIT 1", + String.class, + slug + ); } } diff --git a/src/main/java/coon/models/Posts.java b/src/main/java/coon/models/Posts.java index 0b06320..3250712 100644 --- a/src/main/java/coon/models/Posts.java +++ b/src/main/java/coon/models/Posts.java @@ -32,45 +32,6 @@ public Posts(JdbcTemplate jdbc, Users users, Forums forums) { this.jdbc = jdbc; this.users = users; this.forums = forums; - - if (Application.triggered.compareAndSet(true, true)) { - return; - } - - this.jdbc.execute( - "CREATE OR REPLACE FUNCTION onPostInsert() RETURNS trigger AS $func$\n" + - "BEGIN\n" + - "\n" + - " IF NEW.parent > 0 THEN\n" + - " CREATE TEMPORARY TABLE parent AS" + - " SELECT thread, path FROM Posts WHERE id = NEW.parent LIMIT 1;\n" + - " IF (SELECT count(*) FROM parent) = 0 THEN\n" + - " DROP TABLE parent;\n" + - " RAISE EXCEPTION 'Parent post does not exist!';\n" + - " END IF;\n" + - " \n" + - " NEW.path = (SELECT path FROM parent) || NEW.id;\n" + - " \n" + - " IF NEW.thread <> (SELECT thread FROM parent) THEN\n" + - " DROP TABLE parent;" + - " RAISE EXCEPTION 'Parent post belongs to another thread!';\n" + - " END IF;\n" + - " \n" + - " DROP TABLE parent;\n" + - " ELSE\n" + - " NEW.path = array[]::INT[] || NEW.id;\n" + - " END IF;\n" + - "\n" + - " RETURN NEW;\n" + - "\n" + - "END;\n" + - "$func$ LANGUAGE plpgsql;\n" + - "\n" + - "\n" + - "DROP TRIGGER IF EXISTS postCheck ON Posts;\n" + - "CREATE TRIGGER postCheck BEFORE INSERT OR UPDATE ON Posts" + - " FOR EACH ROW EXECUTE PROCEDURE onPostInsert();" - ); } @@ -88,15 +49,31 @@ public List create(List posts, ThreadData thread) { PreparedStatement ps = conn.prepareStatement( "INSERT INTO Posts " + - "(author, forum, thread, message, created, isEdited, parent)" + + "(author, forum, thread, message, created, isEdited, parent, path, id)" + " VALUES " + - "(?, ?, ?, ?, ?::TIMESTAMPTZ, ?, ?)", - Statement.RETURN_GENERATED_KEYS + "(?, ?, ?, ?, ?::TIMESTAMPTZ, ?, ?, " + + " (SELECT path FROM Posts AS P WHERE P.id = ? LIMIT 1) || ?::INT, ?)", + Statement.NO_GENERATED_KEYS ); for (PostData post: posts) { + if (post.getParent() > 0) { + try { + int parentThread = this.jdbc.queryForObject( + "SELECT thread FROM Posts WHERE id = ? LIMIT 1", + Integer.class, post.getParent() + ); + + if (parentThread != thread.getId()) { + throw new SQLException(); + } + } catch (EmptyResultDataAccessException e) { + throw new SQLException(); + } + } + + post.setId(this.jdbc.queryForObject("SELECT nextVal('Posts_id_seq')", Integer.class)); post.setAuthor(this.users.get(post.getAuthor()).getNickname()); - this.forums.addMember(thread.getForum(), post.getAuthor()); post.setForum(thread.getForum()); post.setThread(thread.getId()); post.setCreated(created); @@ -108,22 +85,20 @@ public List create(List posts, ThreadData thread) { ps.setString(5, post.getCreated()); ps.setBoolean(6, post.isEdited()); ps.setInt(7, post.getParent()); + ps.setInt(8, post.getParent()); + ps.setInt(9, post.getId()); + ps.setInt(10, post.getId()); ps.addBatch(); } ps.executeBatch(); - ResultSet ids = ps.getGeneratedKeys(); + this.forums.incStat(thread.getForum(), posts.size(), 0); - while (ids.next()) { - posts.get(ids.getRow() - 1).setId(ids.getInt("id")); + for (PostData post: posts) { + this.forums.addMember(post.getForum(), post.getAuthor()); } - ForumData forum = this.forums.get(thread.getForum()); - forum.setPosts(forum.getPosts() + posts.size()); - this.forums.set(forum); - - ids.close(); conn.close(); return posts; @@ -136,59 +111,58 @@ public List create(List posts, ThreadData thread) { } } - throw new DataIntegrityViolationException("Parent post belongs to another thread"); + throw new DataIntegrityViolationException(""); } } - public List flat(ThreadData thread, int offset, int limit, boolean desc) { + public List flat(int threadId, int offset, int limit, boolean desc) { String order = (desc ? "DESC" : "ASC"); return this.jdbc.query( - "SELECT * FROM Posts WHERE thread = ? " + + "SELECT author, forum, thread, message, created, isEdited, parent, id " + + " FROM Posts WHERE thread = ? " + "ORDER BY" + - " created " + order + - " , id " + order + + " id " + order + " LIMIT ? OFFSET ?", new PostData(), - thread.getId(), limit, offset + threadId, limit, offset ); } - public List tree(ThreadData thread, int offset, int limit, boolean desc) { + public List tree(int threadId, int offset, int limit, boolean desc) { String order = (desc ? "DESC" : "ASC"); return this.jdbc.query( - "SELECT * FROM Posts WHERE thread = ? " + + "SELECT author, forum, thread, message, created, isEdited, parent, id, path " + + " FROM Posts WHERE thread = ? " + "ORDER BY" + " path " + order + - " , created " + order + - " , id " + order + " LIMIT ? OFFSET ?", new PostData(), - thread.getId(), limit, offset + threadId, limit, offset ); } - public List parentTree(ThreadData thread, int offset, int limit, boolean desc) { + public List parentTree(int threadId, int offset, int limit, boolean desc) { String order = (desc ? "DESC" : "ASC"); return this.jdbc.query( "WITH Roots AS (" + - "SELECT id FROM Posts WHERE thread = ? AND parent = 0 " + + "SELECT path FROM Posts WHERE thread = ? AND parent = 0 " + "ORDER BY" + - " created " + order + - " , id " + order + + " id " + order + " LIMIT ? OFFSET ?" + - ") SELECT * FROM Posts WHERE thread = ? AND Posts.path[1] IN (SELECT id FROM Roots)" + - "ORDER BY" + - " path " + order + - " , created " + order + - " , id " + order, + ") SELECT " + + " Posts.id, Posts.author, Posts.forum, Posts.created, Posts.message, Posts.thread, " + + " Posts.parent, Posts.isEdited " + + "FROM Posts JOIN Roots ON Roots.path <@ Posts.path WHERE thread = ?" + + " ORDER BY " + + " Posts.path " + order, new PostData(), - thread.getId(), limit, offset, thread.getId() + threadId, limit, offset, threadId ); } @@ -261,7 +235,8 @@ public PostDetailsData details(int id, String[] related) { public PostData set(int id, PostData post) { PostData oldPost = this.jdbc.queryForObject( - "SELECT * FROM Posts WHERE id = ? LIMIT 1", + "SELECT author, forum, thread, message, created, isEdited, parent, id" + + " FROM Posts WHERE id = ? LIMIT 1", new PostData(), id ); diff --git a/src/main/java/coon/models/Threads.java b/src/main/java/coon/models/Threads.java index bf7765b..1fcf103 100644 --- a/src/main/java/coon/models/Threads.java +++ b/src/main/java/coon/models/Threads.java @@ -36,9 +36,7 @@ public ThreadData create(ThreadData thread, ForumData forum, UserData author) { thread.setAuthor(author.getNickname()); thread.setForum(forum.getSlug()); - forum = this.forums.get(forum.getSlug()); - forum.setThreads(forum.getThreads() + 1); - this.forums.set(forum); + this.forums.incStat(thread.getForum(), 0, 1); this.forums.addMember(forum.getSlug(), author.getNickname()); if (thread.getCreated() == null) { @@ -61,7 +59,8 @@ public ThreadData create(ThreadData thread, ForumData forum, UserData author) { public ThreadData get(int id) { return this.jdbc.queryForObject( - "SELECT * FROM Threads WHERE id = ? LIMIT 1", + "SELECT author, created, forum, message, title, slug, id, votes " + + " FROM Threads WHERE id = ? LIMIT 1", new ThreadData(), id ); @@ -70,7 +69,8 @@ public ThreadData get(int id) { public ThreadData withSlug(String slug) { return this.jdbc.queryForObject( - "SELECT * FROM Threads WHERE lower(slug) = lower(?) LIMIT 1", + "SELECT author, created, forum, message, title, slug, id, votes " + + " FROM Threads WHERE lower(slug) = lower(?) LIMIT 1", new ThreadData(), slug ); @@ -79,7 +79,7 @@ public ThreadData withSlug(String slug) { public List all(String forum, String since, int limit, boolean desc) { return this.jdbc.query( - "SELECT * FROM Threads " + + "SELECT author, created, forum, message, title, slug, id, votes FROM Threads " + "WHERE lower(forum) = lower(?) AND " + (since != null ? @@ -104,6 +104,30 @@ public List all(String forum, String since, int limit, boolean desc) } + public int fastResolve(String slugOrId) { + try { + return Integer.valueOf(slugOrId); + } catch (NumberFormatException e1) { + return this.id(slugOrId); + } + } + + + public boolean exists(int id) { + try { + this.jdbc.queryForObject( + "SELECT id FROM Threads WHERE id = ? LIMIT 1", + Integer.class, + id + ); + + return true; + } catch (EmptyResultDataAccessException e) { + return false; + } + } + + public ThreadData resolve(String slugOrId) { try { int id = Integer.valueOf(slugOrId); @@ -166,4 +190,13 @@ public ThreadData set(ThreadData thread, ThreadData data) { } + public int id(String slug) { + return this.jdbc.queryForObject( + "SELECT id FROM Threads WHERE lower(slug) = lower(?) LIMIT 1", + Integer.class, + slug + ); + } + + } diff --git a/src/main/java/coon/models/Users.java b/src/main/java/coon/models/Users.java index 3160e38..6c28abf 100644 --- a/src/main/java/coon/models/Users.java +++ b/src/main/java/coon/models/Users.java @@ -37,7 +37,7 @@ public UserData create(UserData user) { public UserData get(String nickname) { return this.jdbc.queryForObject( - "SELECT * FROM Users WHERE lower(nickname) = lower(?) LIMIT 1", + "SELECT nickname, fullname, email, about FROM Users WHERE lower(nickname) = lower(?) LIMIT 1", new UserData(), nickname ); @@ -51,7 +51,7 @@ public List all(String nickname, String email) { } return this.jdbc.query( - "SELECT * FROM Users WHERE lower(nickname) = lower(?)", + "SELECT nickname, fullname, email, about FROM Users WHERE lower(nickname) = lower(?)", new UserData(), nickname ); @@ -59,14 +59,14 @@ public List all(String nickname, String email) { if (nickname == null) { return this.jdbc.query( - "SELECT * FROM Users WHERE lower(email) = lower(?)", + "SELECT nickname, fullname, email, about FROM Users WHERE lower(email) = lower(?)", new UserData(), email ); } return this.jdbc.query( - "SELECT * FROM Users WHERE lower(email) = lower(?) OR lower(nickname) = lower(?)", + "SELECT nickname, fullname, email, about FROM Users WHERE lower(email) = lower(?) OR lower(nickname) = lower(?)", new UserData(), email, nickname ); @@ -76,11 +76,6 @@ public List all(String nickname, String email) { public UserData set(String nickname, UserData user) { UserData newUser = this.get(nickname).merge(user); - this.jdbc.update( - "UPDATE Members SET fullname = ?, email = ?, about = ? WHERE lower(author) = lower(?)", - newUser.getFullName(), newUser.getEmail(), newUser.getAbout(), newUser.getNickname() - ); - return this.jdbc.queryForObject( "UPDATE Users SET fullname = ?, email = ?, about = ? WHERE lower(nickname) = lower(?)" + "RETURNING *", @@ -89,4 +84,13 @@ public UserData set(String nickname, UserData user) { ); } + + public String realNickname(String nickname) { + return this.jdbc.queryForObject( + "SELECT nickname FROM Users WHERE lower(nickname) = lower(?) LIMIT 1", + String.class, + nickname + ); + } + } diff --git a/src/main/resources/application.properties b/src/main/resources/application.properties index ecad94e..f9f443b 100644 --- a/src/main/resources/application.properties +++ b/src/main/resources/application.properties @@ -1,9 +1,9 @@ spring.jpa.database=POSTGRESQL spring.datasource.platform=postgres -#spring.datasource.url=jdbc:postgresql://localhost:5432/docker -#spring.datasource.username=docker -#spring.datasource.password=docker -spring.datasource.url=jdbc:postgresql://localhost:5433/motion -spring.datasource.username=coon -spring.datasource.password= +spring.datasource.url=jdbc:postgresql://localhost:5432/docker +spring.datasource.username=docker +spring.datasource.password=docker +#spring.datasource.url=jdbc:postgresql://localhost:5432/motion_test +#spring.datasource.username=coon +#spring.datasource.password= server.port=5000 diff --git a/src/main/resources/schema.sql b/src/main/resources/schema.sql index bf79e74..575d687 100644 --- a/src/main/resources/schema.sql +++ b/src/main/resources/schema.sql @@ -2,7 +2,7 @@ SET SYNCHRONOUS_COMMIT = 'off'; DROP TABLE IF EXISTS Users; -CREATE TABLE Users ( +CREATE TABLE IF NOT EXISTS Users ( nickname TEXT, fullname TEXT, email TEXT UNIQUE, @@ -19,12 +19,12 @@ CREATE UNIQUE INDEX UsersEmail ON Users (lower(email)); DROP TABLE IF EXISTS Forums; -CREATE TABLE Forums ( +CREATE TABLE IF NOT EXISTS Forums ( slug TEXT UNIQUE, title TEXT, author TEXT, - posts INT, - threads INT + posts INT DEFAULT 0, + threads INT DEFAULT 0 ); DROP INDEX IF EXISTS ForumsSlug; @@ -32,7 +32,7 @@ CREATE UNIQUE INDEX ForumsSlug ON Forums (lower(slug)); DROP TABLE IF EXISTS Threads; -CREATE TABLE Threads ( +CREATE TABLE IF NOT EXISTS Threads ( id SERIAL, slug TEXT UNIQUE, author TEXT, @@ -52,12 +52,20 @@ DROP INDEX IF EXISTS ThreadsSlug; CREATE UNIQUE INDEX ThreadsSlug ON Threads (lower(slug)); +DROP INDEX IF EXISTS ThreadsSlugAndId; +CREATE UNIQUE INDEX ThreadsSlugAndId ON Threads (lower(slug), id); + + +DROP INDEX IF EXISTS ThreadsForum; +CREATE INDEX ThreadsForum ON Threads (lower(forum)); + + DROP INDEX IF EXISTS ThreadsCreated; CREATE INDEX ThreadsCreated ON Threads (created); DROP TABLE IF EXISTS Posts; -CREATE TABLE Posts ( +CREATE TABLE IF NOT EXISTS Posts ( id SERIAL, author TEXT, forum TEXT, @@ -82,12 +90,24 @@ DROP INDEX IF EXISTS PostsParent; CREATE INDEX PostsParent ON Posts (parent); -DROP INDEX IF EXISTS PostsCreated; -CREATE INDEX PostsCreated ON Posts (created); +DROP INDEX IF EXISTS PostsThread; +CREATE INDEX PostsThread ON Posts (thread); + + +DROP INDEX IF EXISTS PostsThreadId; +CREATE INDEX PostsThreadId ON Posts (thread, id); + + +DROP INDEX IF EXISTS PostsThreadPath; +CREATE INDEX PostsThreadPath ON Posts (thread, path); + + +DROP INDEX IF EXISTS PostsThreadParentId; +CREATE INDEX PostsThreadParentId ON Posts (thread, parent, id); DROP TABLE IF EXISTS Votes; -CREATE TABLE Votes ( +CREATE TABLE IF NOT EXISTS Votes ( thread INT, author TEXT, voice INT @@ -99,14 +119,15 @@ CREATE UNIQUE INDEX VotesThreadAuthor ON Votes (thread, lower(author)); DROP TABLE IF EXISTS Members; -CREATE TABLE Members ( +CREATE TABLE IF NOT EXISTS Members ( forum TEXT, - author TEXT, - fullname TEXT, - email TEXT, - about TEXT + author TEXT ); +DROP INDEX IF EXISTS MembersForum; +CREATE INDEX MembersForum ON Members (lower(forum)); + + DROP INDEX IF EXISTS MembersForumAuthor; CREATE INDEX MembersForumAuthor ON Members (lower(forum), lower(author)); diff --git a/tech-db-forum.dat.gz b/tech-db-forum.dat.gz deleted file mode 100644 index dc1882d..0000000 Binary files a/tech-db-forum.dat.gz and /dev/null differ