package io.gitlab.jfronny.gitea.helpdesk.db; import io.gitlab.jfronny.commons.throwable.ThrowingConsumer; import io.gitlab.jfronny.gitea.helpdesk.Config; import org.apache.commons.dbcp2.BasicDataSource; import java.sql.*; import java.util.Optional; public class DBInterface implements AutoCloseable { private final BasicDataSource ds = new BasicDataSource(); public DBInterface(Config.Database config) throws SQLException { ds.setUrl("jdbc:" + config.connectionString); ds.setMinIdle(1); ds.setMaxIdle(10); ds.setMaxOpenPreparedStatements(100); try (Statement st = ds.getConnection().createStatement()) { st.execute(""" CREATE OR REPLACE FUNCTION generate_uid(size INT) RETURNS TEXT AS $$ DECLARE characters TEXT := 'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789'; bytes BYTEA := gen_random_bytes(size); l INT := length(characters); i INT := 0; output TEXT := ''; BEGIN WHILE i < size LOOP output := output || substr(characters, get_byte(bytes, i) % l + 1, 1); i := i + 1; END LOOP; RETURN output; END; $$ LANGUAGE plpgsql VOLATILE;"""); st.execute(""" create table if not exists subscriptions( id text primary key default generate_uid(20), email text, repo_owner text, repo text, issue bigint, issue_comment bigint, reference_chain text )"""); } } public void forEachSubscription(ThrowingConsumer action) throws SQLException, TEx { try (Statement st = ds.getConnection().createStatement(); ResultSet rs = st.executeQuery("select * from subscriptions")) { while (rs.next()) { action.accept(get(rs)); } } } public String addSubscription(String email, String repoOwner, String repo, long issue, long issueComment, String referenceChain) throws SQLException { try (PreparedStatement st = ds.getConnection().prepareStatement(""" insert into subscriptions (email, repo_owner, repo, issue, issue_comment, reference_chain) values (?, ?, ?, ?, ?, ?) returning id""")) { st.setString(1, email); st.setString(2, repoOwner); st.setString(3, repo); st.setLong(4, issue); st.setLong(5, issueComment); st.setString(6, referenceChain); try (ResultSet rs = st.executeQuery()) { rs.next(); return rs.getString("id"); } } } public Optional getSubscription(String id) throws SQLException { try (PreparedStatement st = ds.getConnection() .prepareStatement("select id, email, repo_owner, repo, issue, issue_comment, reference_chain from subscriptions where id = ?")) { st.setString(1, id); try (ResultSet rs = st.executeQuery()) { if (rs.next()) { return Optional.of(get(rs)); } else return Optional.empty(); } } } public void removeSubscription(String id) throws SQLException { try (PreparedStatement st = ds.getConnection().prepareStatement("delete from subscriptions where id = ?")) { st.setString(1, id); st.executeUpdate(); } } public void updateSubscriptionIssueComment(String id, long issueComment) throws SQLException { try (PreparedStatement st = ds.getConnection().prepareStatement("update subscriptions set issue_comment = ? where id = ?")) { st.setLong(1, issueComment); st.setString(2, id); st.executeUpdate(); } } public void updateSubscriptionReferenceChain(String id, String referenceChain) throws SQLException { try (PreparedStatement st = ds.getConnection().prepareStatement("update subscriptions set reference_chain = ? where id = ?")) { st.setString(1, referenceChain); st.setString(2, id); st.executeUpdate(); } } private Subscription get(ResultSet rs) throws SQLException { return new Subscription( rs.getString("id"), rs.getString("email"), rs.getString("repo_owner"), rs.getString("repo"), rs.getLong("issue"), rs.getLong("issue_comment"), rs.getString("reference_chain") ); } @Override public void close() throws SQLException { ds.close(); } }