Skip to content

Commit c25376c

Browse files
docs: samples and tests for admin database APIs (#1099)
* docs: samples and tests for admin database APIs * rebase branch with main * remove backup samples * add more database samples * remove unused import * add more samples * incorporate suggestions * fix tests * incorporate suggestions * fix tests * remove parallel run --------- Co-authored-by: Sri Harsha CH <[email protected]>
1 parent 5410c32 commit c25376c

File tree

4 files changed

+1552
-7
lines changed

4 files changed

+1552
-7
lines changed

samples/samples/admin/pg_samples.py

Lines changed: 351 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,351 @@
1+
#!/usr/bin/env python
2+
3+
# Copyright 2024 Google, Inc.
4+
#
5+
# Licensed under the Apache License, Version 2.0 (the "License");
6+
# you may not use this file except in compliance with the License.
7+
# You may obtain a copy of the License at
8+
#
9+
# http://www.apache.org/licenses/LICENSE-2.0
10+
#
11+
# Unless required by applicable law or agreed to in writing, software
12+
# distributed under the License is distributed on an "AS IS" BASIS,
13+
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
14+
# See the License for the specific language governing permissions and
15+
# limitations under the License.
16+
17+
"""This application demonstrates how to do basic operations using Cloud
18+
Spanner PostgreSql dialect.
19+
For more information, see the README.rst under /spanner.
20+
"""
21+
from google.cloud import spanner
22+
from google.cloud.spanner_admin_database_v1.types.common import DatabaseDialect
23+
24+
OPERATION_TIMEOUT_SECONDS = 240
25+
26+
27+
# [START spanner_postgresql_create_database]
28+
def create_database(instance_id, database_id):
29+
"""Creates a PostgreSql database and tables for sample data."""
30+
31+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
32+
33+
spanner_client = spanner.Client()
34+
instance = spanner_client.instance(instance_id)
35+
36+
request = spanner_database_admin.CreateDatabaseRequest(
37+
parent=instance.name,
38+
create_statement=f'CREATE DATABASE "{database_id}"',
39+
database_dialect=DatabaseDialect.POSTGRESQL,
40+
)
41+
42+
operation = spanner_client.database_admin_api.create_database(request=request)
43+
44+
print("Waiting for operation to complete...")
45+
database = operation.result(OPERATION_TIMEOUT_SECONDS)
46+
47+
create_table_using_ddl(database.name)
48+
print("Created database {} on instance {}".format(database_id, instance_id))
49+
50+
51+
def create_table_using_ddl(database_name):
52+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
53+
54+
spanner_client = spanner.Client()
55+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
56+
database=database_name,
57+
statements=[
58+
"""CREATE TABLE Singers (
59+
SingerId bigint NOT NULL,
60+
FirstName character varying(1024),
61+
LastName character varying(1024),
62+
SingerInfo bytea,
63+
FullName character varying(2048)
64+
GENERATED ALWAYS AS (FirstName || ' ' || LastName) STORED,
65+
PRIMARY KEY (SingerId)
66+
)""",
67+
"""CREATE TABLE Albums (
68+
SingerId bigint NOT NULL,
69+
AlbumId bigint NOT NULL,
70+
AlbumTitle character varying(1024),
71+
PRIMARY KEY (SingerId, AlbumId)
72+
) INTERLEAVE IN PARENT Singers ON DELETE CASCADE""",
73+
],
74+
)
75+
operation = spanner_client.database_admin_api.update_database_ddl(request)
76+
operation.result(OPERATION_TIMEOUT_SECONDS)
77+
78+
79+
# [END spanner_postgresql_create_database]
80+
81+
82+
def create_table_with_datatypes(instance_id, database_id):
83+
"""Creates a table with supported datatypes."""
84+
# [START spanner_postgresql_create_table_with_datatypes]
85+
# instance_id = "your-spanner-instance"
86+
# database_id = "your-spanner-db-id"
87+
88+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
89+
90+
spanner_client = spanner.Client()
91+
instance = spanner_client.instance(instance_id)
92+
database = instance.database(database_id)
93+
94+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
95+
database=database.name,
96+
statements=[
97+
"""CREATE TABLE Venues (
98+
VenueId BIGINT NOT NULL,
99+
VenueName character varying(100),
100+
VenueInfo BYTEA,
101+
Capacity BIGINT,
102+
OutdoorVenue BOOL,
103+
PopularityScore FLOAT8,
104+
Revenue NUMERIC,
105+
LastUpdateTime SPANNER.COMMIT_TIMESTAMP NOT NULL,
106+
PRIMARY KEY (VenueId))"""
107+
],
108+
)
109+
operation = spanner_client.database_admin_api.update_database_ddl(request)
110+
111+
print("Waiting for operation to complete...")
112+
operation.result(OPERATION_TIMEOUT_SECONDS)
113+
114+
print(
115+
"Created Venues table on database {} on instance {}".format(
116+
database_id, instance_id
117+
)
118+
)
119+
# [END spanner_postgresql_create_table_with_datatypes]
120+
121+
122+
# [START spanner_postgresql_add_column]
123+
def add_column(instance_id, database_id):
124+
"""Adds a new column to the Albums table in the example database."""
125+
126+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
127+
128+
spanner_client = spanner.Client()
129+
instance = spanner_client.instance(instance_id)
130+
database = instance.database(database_id)
131+
132+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
133+
database=database.name,
134+
statements=["ALTER TABLE Albums ADD COLUMN MarketingBudget BIGINT"],
135+
)
136+
operation = spanner_client.database_admin_api.update_database_ddl(request)
137+
138+
print("Waiting for operation to complete...")
139+
operation.result(OPERATION_TIMEOUT_SECONDS)
140+
141+
print("Added the MarketingBudget column.")
142+
143+
144+
# [END spanner_postgresql_add_column]
145+
146+
147+
# [START spanner_postgresql_jsonb_add_column]
148+
def add_jsonb_column(instance_id, database_id):
149+
"""
150+
Alters Venues tables in the database adding a JSONB column.
151+
You can create the table by running the `create_table_with_datatypes`
152+
sample or by running this DDL statement against your database:
153+
CREATE TABLE Venues (
154+
VenueId BIGINT NOT NULL,
155+
VenueName character varying(100),
156+
VenueInfo BYTEA,
157+
Capacity BIGINT,
158+
OutdoorVenue BOOL,
159+
PopularityScore FLOAT8,
160+
Revenue NUMERIC,
161+
LastUpdateTime SPANNER.COMMIT_TIMESTAMP NOT NULL,
162+
PRIMARY KEY (VenueId))
163+
"""
164+
# instance_id = "your-spanner-instance"
165+
# database_id = "your-spanner-db-id"
166+
167+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
168+
169+
spanner_client = spanner.Client()
170+
instance = spanner_client.instance(instance_id)
171+
database = instance.database(database_id)
172+
173+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
174+
database=database.name,
175+
statements=["ALTER TABLE Venues ADD COLUMN VenueDetails JSONB"],
176+
)
177+
178+
operation = spanner_client.database_admin_api.update_database_ddl(request)
179+
180+
print("Waiting for operation to complete...")
181+
operation.result(OPERATION_TIMEOUT_SECONDS)
182+
183+
print(
184+
'Altered table "Venues" on database {} on instance {}.'.format(
185+
database_id, instance_id
186+
)
187+
)
188+
189+
190+
# [END spanner_postgresql_jsonb_add_column]
191+
192+
193+
# [START spanner_postgresql_create_storing_index]
194+
def add_storing_index(instance_id, database_id):
195+
"""Adds an storing index to the example database."""
196+
197+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
198+
199+
spanner_client = spanner.Client()
200+
instance = spanner_client.instance(instance_id)
201+
database = instance.database(database_id)
202+
203+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
204+
database=database.name,
205+
statements=[
206+
"CREATE INDEX AlbumsByAlbumTitle2 ON Albums(AlbumTitle)"
207+
"INCLUDE (MarketingBudget)"
208+
],
209+
)
210+
211+
operation = spanner_client.database_admin_api.update_database_ddl(request)
212+
213+
print("Waiting for operation to complete...")
214+
operation.result(OPERATION_TIMEOUT_SECONDS)
215+
216+
print("Added the AlbumsByAlbumTitle2 index.")
217+
218+
219+
# [END spanner_postgresql_create_storing_index]
220+
221+
222+
# [START spanner_postgresql_create_sequence]
223+
def create_sequence(instance_id, database_id):
224+
"""Creates the Sequence and insert data"""
225+
226+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
227+
228+
spanner_client = spanner.Client()
229+
instance = spanner_client.instance(instance_id)
230+
database = instance.database(database_id)
231+
232+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
233+
database=database.name,
234+
statements=[
235+
"CREATE SEQUENCE Seq BIT_REVERSED_POSITIVE",
236+
"""CREATE TABLE Customers (
237+
CustomerId BIGINT DEFAULT nextval('Seq'),
238+
CustomerName character varying(1024),
239+
PRIMARY KEY (CustomerId)
240+
)""",
241+
],
242+
)
243+
operation = spanner_client.database_admin_api.update_database_ddl(request)
244+
print("Waiting for operation to complete...")
245+
operation.result(OPERATION_TIMEOUT_SECONDS)
246+
247+
print(
248+
"Created Seq sequence and Customers table, where the key column CustomerId uses the sequence as a default value on database {} on instance {}".format(
249+
database_id, instance_id
250+
)
251+
)
252+
253+
def insert_customers(transaction):
254+
results = transaction.execute_sql(
255+
"INSERT INTO Customers (CustomerName) VALUES "
256+
"('Alice'), "
257+
"('David'), "
258+
"('Marc') "
259+
"RETURNING CustomerId"
260+
)
261+
for result in results:
262+
print("Inserted customer record with Customer Id: {}".format(*result))
263+
print(
264+
"Number of customer records inserted is {}".format(
265+
results.stats.row_count_exact
266+
)
267+
)
268+
269+
database.run_in_transaction(insert_customers)
270+
271+
272+
# [END spanner_postgresql_create_sequence]
273+
274+
275+
# [START spanner_postgresql_alter_sequence]
276+
def alter_sequence(instance_id, database_id):
277+
"""Alters the Sequence and insert data"""
278+
279+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
280+
281+
spanner_client = spanner.Client()
282+
instance = spanner_client.instance(instance_id)
283+
database = instance.database(database_id)
284+
285+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
286+
database=database.name,
287+
statements=["ALTER SEQUENCE Seq SKIP RANGE 1000 5000000"],
288+
)
289+
operation = spanner_client.database_admin_api.update_database_ddl(request)
290+
291+
print("Waiting for operation to complete...")
292+
operation.result(OPERATION_TIMEOUT_SECONDS)
293+
294+
print(
295+
"Altered Seq sequence to skip an inclusive range between 1000 and 5000000 on database {} on instance {}".format(
296+
database_id, instance_id
297+
)
298+
)
299+
300+
def insert_customers(transaction):
301+
results = transaction.execute_sql(
302+
"INSERT INTO Customers (CustomerName) VALUES "
303+
"('Lea'), "
304+
"('Cataline'), "
305+
"('Smith') "
306+
"RETURNING CustomerId"
307+
)
308+
for result in results:
309+
print("Inserted customer record with Customer Id: {}".format(*result))
310+
print(
311+
"Number of customer records inserted is {}".format(
312+
results.stats.row_count_exact
313+
)
314+
)
315+
316+
database.run_in_transaction(insert_customers)
317+
318+
319+
# [END spanner_postgresql_alter_sequence]
320+
321+
322+
# [START spanner_postgresql_drop_sequence]
323+
def drop_sequence(instance_id, database_id):
324+
"""Drops the Sequence"""
325+
326+
from google.cloud.spanner_admin_database_v1.types import spanner_database_admin
327+
328+
spanner_client = spanner.Client()
329+
instance = spanner_client.instance(instance_id)
330+
database = instance.database(database_id)
331+
332+
request = spanner_database_admin.UpdateDatabaseDdlRequest(
333+
database=database.name,
334+
statements=[
335+
"ALTER TABLE Customers ALTER COLUMN CustomerId DROP DEFAULT",
336+
"DROP SEQUENCE Seq",
337+
],
338+
)
339+
operation = spanner_client.database_admin_api.update_database_ddl(request)
340+
341+
print("Waiting for operation to complete...")
342+
operation.result(OPERATION_TIMEOUT_SECONDS)
343+
344+
print(
345+
"Altered Customers table to drop DEFAULT from CustomerId column and dropped the Seq sequence on database {} on instance {}".format(
346+
database_id, instance_id
347+
)
348+
)
349+
350+
351+
# [END spanner_postgresql_drop_sequence]

0 commit comments

Comments
 (0)