From 3d6f7be740f024a7c8f5cc00bf802aa4bdff73b6 Mon Sep 17 00:00:00 2001
From: Kurtis Van Gent <31518063+kurtisvg@users.noreply.github.com>
Date: Thu, 8 Nov 2018 08:48:48 -0800
Subject: [PATCH] Add Cloud SQL Postgres connectivity sample for servlets.
(#1255)
* Add Cloud SQL Prostgres connectivity sample for serverlets.
* Add MySQL prefix to region tags.
---
cloud-sql/mysql/servlet/pom.xml | 2 +-
.../ConnectionPoolContextListener.java | 16 +-
.../com/example/cloudsql/IndexServlet.java | 5 +-
cloud-sql/postgres/servlet/README.md | 66 ++++++++
cloud-sql/postgres/servlet/pom.xml | 87 +++++++++++
.../ConnectionPoolContextListener.java | 138 +++++++++++++++++
.../com/example/cloudsql/IndexServlet.java | 143 ++++++++++++++++++
.../main/java/com/example/cloudsql/Vote.java | 47 ++++++
.../src/main/webapp/WEB-INF/appengine-web.xml | 26 ++++
.../servlet/src/main/webapp/index.jsp | 118 +++++++++++++++
pom.xml | 2 +-
11 files changed, 637 insertions(+), 13 deletions(-)
create mode 100644 cloud-sql/postgres/servlet/README.md
create mode 100644 cloud-sql/postgres/servlet/pom.xml
create mode 100644 cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/ConnectionPoolContextListener.java
create mode 100644 cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/IndexServlet.java
create mode 100644 cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/Vote.java
create mode 100644 cloud-sql/postgres/servlet/src/main/webapp/WEB-INF/appengine-web.xml
create mode 100644 cloud-sql/postgres/servlet/src/main/webapp/index.jsp
diff --git a/cloud-sql/mysql/servlet/pom.xml b/cloud-sql/mysql/servlet/pom.xml
index 32ecccbd230..606c4d45e44 100644
--- a/cloud-sql/mysql/servlet/pom.xml
+++ b/cloud-sql/mysql/servlet/pom.xml
@@ -18,7 +18,7 @@
war1.0-SNAPSHOTcom.example.cloudsql
- tabs-vs-spaces
+ tabs-vs-spaces-mysql
+
+ 4.0.0
+ war
+ 1.0-SNAPSHOT
+ com.example.cloudsql
+ tabs-vs-spaces-postgres
+
+
+
+ com.google.cloud.samples
+ shared-configuration
+ 1.0.10
+
+
+
+ 1.8
+ 1.8
+ false
+
+
+
+
+ javax.servlet
+ javax.servlet-api
+ 3.1.0
+ jar
+ provided
+
+
+ javax.servlet
+ jstl
+ 1.2
+
+
+ org.postgresql
+ postgresql
+ 42.2.5
+
+
+ com.google.cloud.sql
+ postgres-socket-factory
+ 1.0.11
+
+
+ com.zaxxer
+ HikariCP
+ 3.1.0
+
+
+
+
+
+
+ org.eclipse.jetty
+ jetty-maven-plugin
+ 9.4.10.v20180503
+
+ 1
+
+
+
+
+ com.google.cloud.tools
+ appengine-maven-plugin
+ 1.3.2
+
+
+
+
diff --git a/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/ConnectionPoolContextListener.java b/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/ConnectionPoolContextListener.java
new file mode 100644
index 00000000000..8d6c72c4c1c
--- /dev/null
+++ b/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/ConnectionPoolContextListener.java
@@ -0,0 +1,138 @@
+/*
+ * Copyright 2018 Google LLC
+ *
+ * Licensed under the Apache License, Version 2.0 (the "License");
+ * you may not use this file except in compliance with the License.
+ * You may obtain a copy of the License at
+ *
+ * http://www.apache.org/licenses/LICENSE-2.0
+ *
+ * Unless required by applicable law or agreed to in writing, software
+ * distributed under the License is distributed on an "AS IS" BASIS,
+ * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+ * See the License for the specific language governing permissions and
+ * limitations under the License.
+ */
+
+package com.example.cloudsql;
+
+import com.zaxxer.hikari.HikariConfig;
+import com.zaxxer.hikari.HikariDataSource;
+import java.sql.Connection;
+import java.sql.PreparedStatement;
+import java.sql.SQLException;
+import java.util.logging.Logger;
+import javax.servlet.ServletContextEvent;
+import javax.servlet.ServletContextListener;
+import javax.servlet.annotation.WebListener;
+import javax.sql.DataSource;
+
+@WebListener("Creates a connection pool that is stored in the Servlet's context for later use.")
+public class ConnectionPoolContextListener implements ServletContextListener {
+
+ private static final Logger LOGGER = Logger.getLogger(IndexServlet.class.getName());
+
+ // Saving credentials in environment variables is convenient, but not secure - consider a more
+ // secure solution such as https://cloud.google.com/kms/ to help keep secrets safe.
+ private static final String CLOUD_SQL_INSTANCE_NAME = System.getenv("CLOUD_SQL_INSTANCE_NAME");
+ private static final String DB_USER = System.getenv("DB_USER");
+ private static final String DB_PASS = System.getenv("DB_PASS");
+ private static final String DB_NAME = System.getenv("DB_NAME");
+
+ private DataSource createConnectionPool() {
+ // [START cloud_sql_postgres_connection_pool]
+ // The configuration object specifies behaviors for the connection pool.
+ HikariConfig config = new HikariConfig();
+
+ // Configure which instance and what database user to connect with.
+ config.setJdbcUrl(String.format("jdbc:postgresql:///%s", DB_NAME));
+ config.setUsername(DB_USER); // e.g. "root", "postgres"
+ config.setPassword(DB_PASS); // e.g. "my-password"
+
+ // For Java users, the Cloud SQL JDBC Socket Factory can provide authenticated connections.
+ // See https://github.com/GoogleCloudPlatform/cloud-sql-jdbc-socket-factory for details.
+ config.addDataSourceProperty("socketFactory", "com.google.cloud.sql.postgres.SocketFactory");
+ config.addDataSourceProperty("cloudSqlInstance", CLOUD_SQL_INSTANCE_NAME);
+
+ // ... Specify additional connection properties here.
+
+ // [START_EXCLUDE]
+
+ // [START cloud_sql_postgres_limit_connections]
+ // maximumPoolSize limits the total number of concurrent connections this pool will keep. Ideal
+ // values for this setting are highly variable on app design, infrastructure, and database.
+ config.setMaximumPoolSize(5);
+ // minimumIdle is the minimum number of idle connections Hikari maintains in the pool.
+ // Additional connections will be established to meet this value unless the pool is full.
+ config.setMinimumIdle(5);
+ // [END cloud_sql_postgres_limit_connections]
+
+ // [START cloud_sql_postgres_connection_timeout]
+ // setConnectionTimeout is the maximum number of milliseconds to wait for a connection checkout.
+ // Any attempt to retrieve a connection from this pool that exceeds the set limit will throw an
+ // SQLException.
+ config.setConnectionTimeout(10000); // 10 seconds
+ // idleTimeout is the maximum amount of time a connection can sit in the pool. Connections that
+ // sit idle for this many milliseconds are retried if minimumIdle is exceeded.
+ config.setIdleTimeout(600000); // 10 minutes
+ // [END cloud_sql_postgres_connection_timeout]
+
+ // [START cloud_sql_postgres_connection_backoff]
+ // Hikari automatically delays between failed connection attempts, eventually reaching a
+ // maximum delay of `connectionTimeout / 2` between attempts.
+ // [END cloud_sql_postgres_connection_backoff]
+
+ // [START cloud_sql_postgres_connection_lifetime]
+ // maxLifetime is the maximum possible lifetime of a connection in the pool. Connections that
+ // live longer than this many milliseconds will be closed and reestablished between uses. This
+ // value should be several minutes shorter than the database's timeout value to avoid unexpected
+ // terminations.
+ config.setMaxLifetime(1800000); // 30 minutes
+ // [END cloud_sql_postgres_connection_lifetime]
+
+ // [END_EXCLUDE]
+
+ // Initialize the connection pool using the configuration object.
+ DataSource pool = new HikariDataSource(config);
+ // [END cloud_sql_postgres_connection_pool]
+ return pool;
+ }
+
+ private void createTable(DataSource pool) throws SQLException {
+ // Safely attempt to create the table schema.
+ try (Connection conn = pool.getConnection()) {
+ PreparedStatement createTableStatement = conn.prepareStatement(
+ "CREATE TABLE IF NOT EXISTS votes ( "
+ + "vote_id SERIAL NOT NULL, time_cast timestamp NOT NULL, candidate CHAR(6) NOT NULL,"
+ + " PRIMARY KEY (vote_id) );"
+ );
+ createTableStatement.execute();
+ }
+ }
+
+ @Override
+ public void contextDestroyed(ServletContextEvent event) {
+ // This function is called when the Servlet is destroyed.
+ HikariDataSource pool = (HikariDataSource) event.getServletContext().getAttribute("my-pool");
+ if (pool != null) {
+ pool.close();
+ }
+ }
+
+ @Override
+ public void contextInitialized(ServletContextEvent event) {
+ // This function is called when the application starts and will safely create a connection pool
+ // that can be used to connect to.
+ DataSource pool = (DataSource) event.getServletContext().getAttribute("my-pool");
+ if (pool == null) {
+ pool = createConnectionPool();
+ event.getServletContext().setAttribute("my-pool", pool);
+ }
+ try {
+ createTable(pool);
+ } catch (SQLException ex) {
+ throw new RuntimeException("Unable to verify table schema. Please double check the steps"
+ + "in the README and try again.", ex);
+ }
+ }
+}
diff --git a/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/IndexServlet.java b/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/IndexServlet.java
new file mode 100644
index 00000000000..75db20833aa
--- /dev/null
+++ b/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/IndexServlet.java
@@ -0,0 +1,143 @@
+/*
+ * Copyright 2018 Google LLC
+ *
+ * Licensed under the Apache License, Version 2.0 (the "License");
+ * you may not use this file except in compliance with the License.
+ * You may obtain a copy of the License at
+ *
+ * http://www.apache.org/licenses/LICENSE-2.0
+ *
+ * Unless required by applicable law or agreed to in writing, software
+ * distributed under the License is distributed on an "AS IS" BASIS,
+ * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+ * See the License for the specific language governing permissions and
+ * limitations under the License.
+ */
+
+package com.example.cloudsql;
+
+import java.io.IOException;
+import java.sql.Connection;
+import java.sql.PreparedStatement;
+import java.sql.ResultSet;
+import java.sql.SQLException;
+import java.sql.Timestamp;
+import java.util.ArrayList;
+import java.util.Date;
+import java.util.List;
+import java.util.logging.Level;
+import java.util.logging.Logger;
+import javax.servlet.ServletException;
+import javax.servlet.annotation.WebServlet;
+import javax.servlet.http.HttpServlet;
+import javax.servlet.http.HttpServletRequest;
+import javax.servlet.http.HttpServletResponse;
+import javax.sql.DataSource;
+
+@WebServlet(name = "Index", value = "")
+public class IndexServlet extends HttpServlet {
+
+ private static final Logger LOGGER = Logger.getLogger(IndexServlet.class.getName());
+
+ @Override
+ public void doGet(HttpServletRequest req, HttpServletResponse resp)
+ throws IOException, ServletException {
+ // Extract the pool from the Servlet Context, reusing the one that was created
+ // in the ContextListener when the application was started
+ DataSource pool = (DataSource) req.getServletContext().getAttribute("my-pool");
+
+ int tabCount;
+ int spaceCount;
+ List recentVotes = new ArrayList<>();
+ try (Connection conn = pool.getConnection()) {
+ // PreparedStatements are compiled by the database immediately and executed at a later date.
+ // Most databases cache previously compiled queries, which improves efficiency.
+ PreparedStatement voteStmt = conn.prepareStatement(
+ "SELECT candidate, time_cast FROM votes ORDER BY time_cast DESC LIMIT 5");
+ // Execute the statement
+ ResultSet voteResults = voteStmt.executeQuery();
+ // Convert a ResultSet into Vote objects
+ while (voteResults.next()) {
+ String candidate = voteResults.getString(1);
+ Timestamp timeCast = voteResults.getTimestamp(2);
+ recentVotes.add(new Vote(candidate.trim(), timeCast));
+ }
+
+ // PreparedStatements can also be executed multiple times with different arguments. This can
+ // improve efficiency, and project a query from being vulnerable to an SQL injection.
+ PreparedStatement voteCountStmt = conn.prepareStatement(
+ "SELECT COUNT(vote_id) FROM votes WHERE candidate=?");
+
+ voteCountStmt.setString(1, "TABS");
+ ResultSet tabResult = voteCountStmt.executeQuery();
+ tabResult.next(); // Move to the first result
+ tabCount = tabResult.getInt(1);
+
+ voteCountStmt.setString(1, "SPACES");
+ ResultSet spaceResult = voteCountStmt.executeQuery();
+ spaceResult.next(); // Move to the first result
+ spaceCount = spaceResult.getInt(1);
+
+ } catch (SQLException ex) {
+ // If something goes wrong, the application needs to react appropriately. This might mean
+ // getting a new connection and executing the query again, or it might mean redirecting the
+ // user to a different page to let them know something went wrong.
+ throw new ServletException("Unable to successfully connect to the database. Please check the "
+ + "steps in the README and try again.", ex);
+ }
+
+ // Add variables and render the page
+ req.setAttribute("tabCount", tabCount);
+ req.setAttribute("spaceCount", spaceCount);
+ req.setAttribute("recentVotes", recentVotes);
+ req.getRequestDispatcher("/index.jsp").forward(req, resp);
+ }
+
+ @Override
+ public void doPost(HttpServletRequest req, HttpServletResponse resp)
+ throws IOException {
+ // Get the team from the request and record the time of the vote.
+ String team = req.getParameter("team");
+ if (team != null) {
+ team = team.toUpperCase();
+ }
+ Timestamp now = new Timestamp(new Date().getTime());
+ if (team == null || (!team.equals("TABS") && !team.equals("SPACES"))) {
+ resp.setStatus(400);
+ resp.getWriter().append("Invalid team specified.");
+ return;
+ }
+
+ // Reuse the pool that was created in the ContextListener when the Servlet started.
+ DataSource pool = (DataSource) req.getServletContext().getAttribute("my-pool");
+ // [START cloud_sql_postgres_example_statement]
+ // Using a try-with-resources statement ensures that the connection is always released back
+ // into the pool at the end of the statement (even if an error occurs)
+ try (Connection conn = pool.getConnection()) {
+
+ // PreparedStatements can be more efficient and project against injections.
+ PreparedStatement voteStmt = conn.prepareStatement(
+ "INSERT INTO votes (time_cast, candidate) VALUES (?, ?);");
+ voteStmt.setTimestamp(1, now);
+ voteStmt.setString(2, team);
+
+ // Finally, execute the statement. If it fails, an error will be thrown.
+ voteStmt.execute();
+
+ } catch (SQLException ex) {
+ // If something goes wrong, handle the error in this section. This might involve retrying or
+ // adjusting parameters depending on the situation.
+ // [START_EXCLUDE]
+ LOGGER.log(Level.WARNING, "Error while attempting to submit vote.", ex);
+ resp.setStatus(500);
+ resp.getWriter().write("Unable to successfully cast vote! Please check the application "
+ + "logs for more details.");
+ // [END_EXCLUDE]
+ }
+ // [END cloud_sql_postgres_example_statement]
+
+ resp.setStatus(200);
+ resp.getWriter().printf("Vote successfully cast for '%s' at time %s!\n", team, now);
+ }
+
+}
diff --git a/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/Vote.java b/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/Vote.java
new file mode 100644
index 00000000000..455c99175ea
--- /dev/null
+++ b/cloud-sql/postgres/servlet/src/main/java/com/example/cloudsql/Vote.java
@@ -0,0 +1,47 @@
+/*
+ * Copyright 2018 Google LLC
+ *
+ * Licensed under the Apache License, Version 2.0 (the "License");
+ * you may not use this file except in compliance with the License.
+ * You may obtain a copy of the License at
+ *
+ * http://www.apache.org/licenses/LICENSE-2.0
+ *
+ * Unless required by applicable law or agreed to in writing, software
+ * distributed under the License is distributed on an "AS IS" BASIS,
+ * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+ * See the License for the specific language governing permissions and
+ * limitations under the License.
+ */
+
+package com.example.cloudsql;
+
+import java.sql.Timestamp;
+
+public class Vote {
+
+ private String candidate;
+ private Timestamp timeCast;
+
+ public Vote(String candidate, Timestamp timeCast) {
+ this.candidate = candidate.toUpperCase();
+ this.timeCast = timeCast;
+ }
+
+ public String getCandidate() {
+ return candidate;
+ }
+
+ public void setCandidate(String candidate) {
+ this.candidate = candidate.toUpperCase();
+ }
+
+ public Timestamp getTimeCast() {
+ return timeCast;
+ }
+
+ public void setTimeCast(Timestamp timeCast) {
+ this.timeCast = timeCast;
+ }
+
+}
diff --git a/cloud-sql/postgres/servlet/src/main/webapp/WEB-INF/appengine-web.xml b/cloud-sql/postgres/servlet/src/main/webapp/WEB-INF/appengine-web.xml
new file mode 100644
index 00000000000..5ce3ec0199f
--- /dev/null
+++ b/cloud-sql/postgres/servlet/src/main/webapp/WEB-INF/appengine-web.xml
@@ -0,0 +1,26 @@
+
+
+
+ true
+ java8
+
+
+
+
+
+
+
diff --git a/cloud-sql/postgres/servlet/src/main/webapp/index.jsp b/cloud-sql/postgres/servlet/src/main/webapp/index.jsp
new file mode 100644
index 00000000000..0fc9a23b21b
--- /dev/null
+++ b/cloud-sql/postgres/servlet/src/main/webapp/index.jsp
@@ -0,0 +1,118 @@
+
+<%@ page contentType="text/html;charset=UTF-8" language="java" %>
+<%@ taglib prefix="c" uri="http://java.sun.com/jsp/jstl/core" %>
+
+
+ Tabs VS Spaces
+
+
+
+
+
+
+
+
+
+
+
+ TABS and SPACES are evenly matched!
+
+
+ TABS are winning by
+ !
+
+
+ SPACES are winning by
+ !!
+
+
+