Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

docs: add samples for PostgreSQL #1700

Merged
merged 9 commits into from
Apr 21, 2022
4 changes: 4 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -264,6 +264,10 @@ Samples are in the [`samples/`](https://github.com/googleapis/java-spanner/tree/
| Get Instance Config Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/GetInstanceConfigSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/GetInstanceConfigSample.java) |
| List Databases Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/ListDatabasesSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/ListDatabasesSample.java) |
| List Instance Configs Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/ListInstanceConfigsSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/ListInstanceConfigsSample.java) |
| Pg Batch Dml Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/PgBatchDmlSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/PgBatchDmlSample.java) |
| Pg Case Sensitivity Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/PgCaseSensitivitySample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/PgCaseSensitivitySample.java) |
| Pg Interleaved Table Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/PgInterleavedTableSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/PgInterleavedTableSample.java) |
| Pg Partitioned Dml Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/PgPartitionedDmlSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/PgPartitionedDmlSample.java) |
| Query Information Schema Database Options Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/QueryInformationSchemaDatabaseOptionsSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/QueryInformationSchemaDatabaseOptionsSample.java) |
| Query With Json Parameter Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/QueryWithJsonParameterSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/QueryWithJsonParameterSample.java) |
| Query With Numeric Parameter Sample | [source code](https://github.com/googleapis/java-spanner/blob/main/samples/snippets/src/main/java/com/example/spanner/QueryWithNumericParameterSample.java) | [![Open in Cloud Shell][shell_img]](https://console.cloud.google.com/cloudshell/open?git_repo=https://github.com/googleapis/java-spanner&page=editor&open_in_editor=samples/snippets/src/main/java/com/example/spanner/QueryWithNumericParameterSample.java) |
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
/*
* Copyright 2022 Google Inc.
*
* 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.spanner;

// [START spanner_postgresql_batch_dml]

import com.google.cloud.spanner.DatabaseClient;
import com.google.cloud.spanner.DatabaseId;
import com.google.cloud.spanner.Spanner;
import com.google.cloud.spanner.SpannerOptions;
import com.google.cloud.spanner.Statement;
import java.util.Arrays;

class PgBatchDmlSample {

static void batchDml() {
// TODO(developer): Replace these variables before running the sample.
String projectId = "my-project";
String instanceId = "my-instance";
String databaseId = "my-database";

batchDml(projectId, instanceId, databaseId);
}

static void batchDml(String projectId, String instanceId, String databaseId) {
try (Spanner spanner =
SpannerOptions.newBuilder()
.setProjectId(projectId)
.build()
.getService()) {
DatabaseClient client =
spanner.getDatabaseClient(DatabaseId.of(projectId, instanceId, databaseId));

// Spanner PostgreSQL supports BatchDML statements. This will batch multiple DML statements
// into one request, which reduces the number of round trips that is needed for multiple DML
// statements.
long[] updateCounts =
client
.readWriteTransaction()
.run(
transaction ->
transaction.batchUpdate(
Arrays.asList(
Statement.newBuilder(
"INSERT INTO Singers (SingerId, FirstName, LastName) "
+ "VALUES ($1, $2, $3)")
// Use 'p1' to bind to the parameter with index 1 etc.
.bind("p1")
.to(1L)
.bind("p2")
.to("Alice")
.bind("p3")
.to("Henderson")
.build(),
Statement.newBuilder(
"INSERT INTO Singers (SingerId, FirstName, LastName) "
+ "VALUES ($1, $2, $3)")
// Use 'p1' to bind to the parameter with index 1 etc.
.bind("p1")
.to(2L)
.bind("p2")
.to("Bruce")
.bind("p3")
.to("Allison")
.build())));
long totalUpdateCount = Arrays.stream(updateCounts).sum();
System.out.printf("Inserted %d singers\n", totalUpdateCount);
}
}
}
// [END spanner_postgresql_batch_dml]
Original file line number Diff line number Diff line change
@@ -0,0 +1,154 @@
/*
* Copyright 2022 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.spanner;

// [START spanner_postgresql_identifier_case_sensitivity]

import com.google.api.gax.longrunning.OperationFuture;
import com.google.cloud.spanner.DatabaseAdminClient;
import com.google.cloud.spanner.DatabaseClient;
import com.google.cloud.spanner.DatabaseId;
import com.google.cloud.spanner.Mutation;
import com.google.cloud.spanner.ResultSet;
import com.google.cloud.spanner.Spanner;
import com.google.cloud.spanner.SpannerExceptionFactory;
import com.google.cloud.spanner.SpannerOptions;
import com.google.cloud.spanner.Statement;
import com.google.spanner.admin.database.v1.UpdateDatabaseDdlMetadata;
import java.util.Collections;
import java.util.concurrent.ExecutionException;

public class PgCaseSensitivitySample {

static void pgCaseSensitivity() {
// TODO(developer): Replace these variables before running the sample.
final String projectId = "my-project";
final String instanceId = "my-instance";
final String databaseId = "my-database";
pgCaseSensitivity(projectId, instanceId, databaseId);
}

static void pgCaseSensitivity(String projectId, String instanceId, String databaseId) {
try (Spanner spanner =
SpannerOptions.newBuilder()
.setProjectId(projectId)
.build()
.getService()) {
final DatabaseAdminClient databaseAdminClient = spanner.getDatabaseAdminClient();

// Spanner PostgreSQL follows the case sensitivity rules of PostgreSQL. This means that:
// 1. Identifiers that are not double-quoted are folded to lower case.
// 2. Identifiers that are double-quoted retain their case and are case-sensitive.
// See https://www.postgresql.org/docs/current/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS
// for more information.
final OperationFuture<Void, UpdateDatabaseDdlMetadata> updateOperation =
databaseAdminClient.updateDatabaseDdl(
instanceId,
databaseId,
Collections.singleton(
"CREATE TABLE Singers ("
// SingerId will be folded to `singerid`.
+ " SingerId bigint NOT NULL PRIMARY KEY,"
// FirstName and LastName are double-quoted and will therefore retain their
// mixed case and are case-sensitive. This means that any statement that
// references any of these columns must use double quotes.
+ " \"FirstName\" varchar(1024) NOT NULL,"
+ " \"LastName\" varchar(1024) NOT NULL"
+ ")"),
null);
updateOperation.get();

DatabaseClient client =
spanner.getDatabaseClient(DatabaseId.of(projectId, instanceId, databaseId));

client.write(
Collections.singleton(
Mutation.newInsertBuilder("Singers")
.set("singerid")
.to(1L)
// Column names in mutations are always case-insensitive, regardless whether the
// columns were double-quoted or not during creation.
.set("firstname")
.to("Bruce")
.set("lastname")
.to("Allison")
.build()));

try (ResultSet singers =
client
.singleUse()
.executeQuery(
Statement.of("SELECT SingerId, \"FirstName\", \"LastName\" FROM Singers"))) {
while (singers.next()) {
System.out.printf(
"SingerId: %d, FirstName: %s, LastName: %s\n",
// SingerId is automatically folded to lower case. Accessing the column by its name in
// a result set must therefore use all lower-case letters.
singers.getLong("singerid"),
// FirstName and LastName were double-quoted during creation, and retain their mixed
// case when returned in a result set.
singers.getString("FirstName"),
singers.getString("LastName"));
}
}

// Aliases are also identifiers, and specifying an alias in double quotes will make the alias
// retain its case.
try (ResultSet singers =
client
.singleUse()
.executeQuery(
Statement.of(
"SELECT "
+ "singerid AS \"SingerId\", "
+ "concat(\"FirstName\", ' '::varchar, \"LastName\") AS \"FullName\" "
+ "FROM Singers"))) {
while (singers.next()) {
System.out.printf(
"SingerId: %d, FullName: %s\n",
// The aliases are double-quoted and therefore retains their mixed case.
singers.getLong("SingerId"), singers.getString("FullName"));
}
}

// DML statements must also follow the PostgreSQL case rules.
client
.readWriteTransaction()
.run(
transaction ->
transaction.executeUpdate(
Statement.newBuilder(
"INSERT INTO Singers (SingerId, \"FirstName\", \"LastName\") "
+ "VALUES ($1, $2, $3)")
.bind("p1")
.to(2L)
.bind("p2")
.to("Alice")
.bind("p3")
.to("Bruxelles")
.build()));
} catch (ExecutionException e) {
// If the operation failed during execution, expose the cause.
throw SpannerExceptionFactory.asSpannerException(e.getCause());
} catch (InterruptedException e) {
// Throw when a thread is waiting, sleeping, or otherwise occupied,
// and the thread is interrupted, either before or during the activity.
throw SpannerExceptionFactory.propagateInterrupt(e);
}
}
}
// [END spanner_postgresql_identifier_case_sensitivity]
Original file line number Diff line number Diff line change
@@ -0,0 +1,81 @@
/*
* Copyright 2022 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.spanner;

// [START spanner_postgresql_interleaved_table]

import com.google.api.gax.longrunning.OperationFuture;
import com.google.cloud.spanner.DatabaseAdminClient;
import com.google.cloud.spanner.Spanner;
import com.google.cloud.spanner.SpannerExceptionFactory;
import com.google.cloud.spanner.SpannerOptions;
import com.google.spanner.admin.database.v1.UpdateDatabaseDdlMetadata;
import java.util.Arrays;
import java.util.concurrent.ExecutionException;

public class PgInterleavedTableSample {

static void pgInterleavedTable() {
// TODO(developer): Replace these variables before running the sample.
final String projectId = "my-project";
final String instanceId = "my-instance";
final String databaseId = "my-database";
pgInterleavedTable(projectId, instanceId, databaseId);
}

static void pgInterleavedTable(String projectId, String instanceId, String databaseId) {
try (Spanner spanner =
SpannerOptions.newBuilder()
.setProjectId(projectId)
.build()
.getService()) {
final DatabaseAdminClient databaseAdminClient = spanner.getDatabaseAdminClient();

// The Spanner PostgreSQL dialect extends the PostgreSQL dialect with certain Spanner
// specific features, such as interleaved tables.
// See https://cloud.google.com/spanner/docs/postgresql/data-definition-language#create_table
// for the full CREATE TABLE syntax.
final OperationFuture<Void, UpdateDatabaseDdlMetadata> updateOperation =
databaseAdminClient.updateDatabaseDdl(
instanceId,
databaseId,
Arrays.asList(
"CREATE TABLE Singers ("
+ " SingerId bigint NOT NULL PRIMARY KEY,"
+ " FirstName varchar(1024) NOT NULL,"
+ " LastName varchar(1024) NOT NULL"
+ ")",
"CREATE TABLE Albums ("
+ " SingerId bigint NOT NULL,"
+ " AlbumId bigint NOT NULL,"
+ " Title varchar(1024) NOT NULL,"
+ " PRIMARY KEY (SingerId, AlbumId)"
+ ") INTERLEAVE IN PARENT Singers ON DELETE CASCADE"),
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Do we have sample for drop? One of the benefit is that we only support cascade drop for interleaved table.

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What exactly do you mean? I don't think we support cascade drop, only cascade delete. Or is that what you meant?

Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

sorry, yep, delete.

null);
updateOperation.get();
System.out.println("Created interleaved table hierarchy using PostgreSQL dialect");
} catch (ExecutionException e) {
// If the operation failed during execution, expose the cause.
throw SpannerExceptionFactory.asSpannerException(e.getCause());
} catch (InterruptedException e) {
// Throw when a thread is waiting, sleeping, or otherwise occupied,
// and the thread is interrupted, either before or during the activity.
throw SpannerExceptionFactory.propagateInterrupt(e);
}
}
}
// [END spanner_postgresql_interleaved_table]
Loading