Skip to content

Commit ca68cf5

Browse files
committed
Create a set of code snippets for using Graph on Cloud Spanner
1 parent 3c91a01 commit ca68cf5

File tree

1 file changed

+375
-0
lines changed

1 file changed

+375
-0
lines changed

samples/samples/graph_snippets.py

Lines changed: 375 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,375 @@
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 graph operations using
18+
Cloud Spanner.
19+
20+
For more information, see the README.rst under /spanner.
21+
"""
22+
23+
import argparse
24+
import base64
25+
import datetime
26+
import decimal
27+
import json
28+
import logging
29+
import time
30+
31+
from google.cloud import spanner
32+
from google.cloud.spanner_admin_instance_v1.types import spanner_instance_admin
33+
from google.cloud.spanner_v1 import DirectedReadOptions, param_types
34+
from google.cloud.spanner_v1.data_types import JsonObject
35+
from google.protobuf import field_mask_pb2 # type: ignore
36+
from testdata import singer_pb2
37+
38+
OPERATION_TIMEOUT_SECONDS = 240
39+
40+
41+
# [START spanner_create_instance]
42+
def create_instance(instance_id):
43+
"""Creates an instance."""
44+
from google.cloud.spanner_admin_instance_v1.types import \
45+
spanner_instance_admin
46+
47+
spanner_client = spanner.Client()
48+
49+
config_name = "{}/instanceConfigs/regional-us-central1".format(
50+
spanner_client.project_name
51+
)
52+
53+
operation = spanner_client.instance_admin_api.create_instance(
54+
parent=spanner_client.project_name,
55+
instance_id=instance_id,
56+
instance=spanner_instance_admin.Instance(
57+
config=config_name,
58+
display_name="This is a display name.",
59+
node_count=1,
60+
labels={
61+
"cloud_spanner_samples": "true",
62+
"sample_name": "snippets-create_instance-explicit",
63+
"created": str(int(time.time())),
64+
},
65+
),
66+
)
67+
68+
print("Waiting for operation to complete...")
69+
operation.result(OPERATION_TIMEOUT_SECONDS)
70+
71+
print("Created instance {}".format(instance_id))
72+
73+
74+
# [END spanner_create_instance]
75+
76+
77+
# [START spanner_create_database_with_property_graph]
78+
def create_database_with_property_graph(instance_id, database_id):
79+
"""Creates a database, tables and a property graph for sample data."""
80+
from google.cloud.spanner_admin_database_v1.types import \
81+
spanner_database_admin
82+
83+
spanner_client = spanner.Client()
84+
database_admin_api = spanner_client.database_admin_api
85+
86+
request = spanner_database_admin.CreateDatabaseRequest(
87+
parent=database_admin_api.instance_path(spanner_client.project, instance_id),
88+
create_statement=f"CREATE DATABASE `{database_id}`",
89+
extra_statements=[
90+
"""CREATE TABLE Person (
91+
id INT64 NOT NULL,
92+
name STRING(MAX),
93+
gender STRING(40),
94+
birthday TIMESTAMP,
95+
country STRING(MAX),
96+
city STRING(MAX),
97+
) PRIMARY KEY (id)""",
98+
"""CREATE TABLE Account (
99+
id INT64 NOT NULL,
100+
create_time TIMESTAMP,
101+
is_blocked BOOL,
102+
nick_name STRING(MAX),
103+
) PRIMARY KEY (id)""",
104+
"""CREATE TABLE PersonOwnAccount (
105+
id INT64 NOT NULL,
106+
account_id INT64 NOT NULL,
107+
create_time TIMESTAMP,
108+
FOREIGN KEY (account_id)
109+
REFERENCES Account (id)
110+
) PRIMARY KEY (id, account_id),
111+
INTERLEAVE IN PARENT Person ON DELETE CASCADE""",
112+
"""CREATE TABLE AccountTransferAccount (
113+
id INT64 NOT NULL,
114+
to_id INT64 NOT NULL,
115+
amount FLOAT64,
116+
create_time TIMESTAMP NOT NULL,
117+
order_number STRING(MAX),
118+
FOREIGN KEY (to_id) REFERENCES Account (id)
119+
) PRIMARY KEY (id, to_id, create_time),
120+
INTERLEAVE IN PARENT Account ON DELETE CASCADE""",
121+
"""CREATE OR REPLACE PROPERTY GRAPH FinGraph
122+
NODE TABLES (Account, Person)
123+
EDGE TABLES (
124+
PersonOwnAccount
125+
SOURCE KEY(id) REFERENCES Person(id)
126+
DESTINATION KEY(account_id) REFERENCES Account(id)
127+
LABEL Owns,
128+
AccountTransferAccount
129+
SOURCE KEY(id) REFERENCES Account(id)
130+
DESTINATION KEY(to_id) REFERENCES Account(id)
131+
LABEL Transfers)""",
132+
],
133+
)
134+
135+
operation = database_admin_api.create_database(request=request)
136+
137+
print("Waiting for operation to complete...")
138+
database = operation.result(OPERATION_TIMEOUT_SECONDS)
139+
140+
print(
141+
"Created database {} on instance {}".format(
142+
database.name,
143+
database_admin_api.instance_path(spanner_client.project, instance_id),
144+
)
145+
)
146+
147+
148+
# [END spanner_create_database_with_property_graph]
149+
150+
151+
# [START spanner_insert_graph_data]
152+
def insert_data(instance_id, database_id):
153+
"""Inserts sample data into the given database.
154+
155+
The database and tables must already exist and can be created using
156+
`create_database_with_property_graph`.
157+
"""
158+
spanner_client = spanner.Client()
159+
instance = spanner_client.instance(instance_id)
160+
database = instance.database(database_id)
161+
162+
with database.batch() as batch:
163+
batch.insert(
164+
table="Person",
165+
columns=("id", "name", "country", "city"),
166+
values=[
167+
(1, "Izumi", "USA", "Mountain View"),
168+
(2, "Tal", "FR", "Paris"),
169+
],
170+
)
171+
172+
batch.insert(
173+
table="Account",
174+
columns=("id", "create_time", "is_blocked", "nick_name"),
175+
values=[
176+
(1, '2014-09-27T11:17:42.18Z', False, "Savings"),
177+
(2, '2008-07-11T12:30:00.45Z', False, "Checking"),
178+
],
179+
)
180+
181+
print("Inserted data.")
182+
183+
184+
# [END spanner_insert_graph_data]
185+
186+
187+
# [START spanner_insert_graph_data_with_dml]
188+
def insert_data_with_dml(instance_id, database_id):
189+
"""Inserts sample data into the given database using a DML statement."""
190+
191+
# instance_id = "your-spanner-instance"
192+
# database_id = "your-spanner-db-id"
193+
194+
spanner_client = spanner.Client()
195+
instance = spanner_client.instance(instance_id)
196+
database = instance.database(database_id)
197+
198+
def insert_owns(transaction):
199+
row_ct = transaction.execute_update(
200+
"INSERT INTO PersonOwnAccount (id, account_id, create_time) "
201+
" VALUES"
202+
"(1, 1, '2014-09-28T09:23:31.45Z'),"
203+
"(2, 2, '2008-07-12T04:31:18.16Z')"
204+
)
205+
206+
print("{} record(s) inserted into PersonOwnAccount.".format(row_ct))
207+
208+
def insert_transfers(transaction):
209+
row_ct = transaction.execute_update(
210+
"INSERT INTO AccountTransferAccount (id, to_id, amount, create_time, order_number) "
211+
" VALUES"
212+
"(1, 2, 900, '2024-06-24T10:11:31.26Z', '3LXCTB'),"
213+
"(2, 1, 100, '2024-07-01T12:23:28.11Z', '4MYRTQ')"
214+
)
215+
216+
print("{} record(s) inserted into AccountTransferAccount.".format(row_ct))
217+
218+
219+
database.run_in_transaction(insert_owns)
220+
database.run_in_transaction(insert_transfers)
221+
222+
223+
# [END spanner_insert_graph_data_with_dml]
224+
225+
226+
# [START spanner_query_graph_data]
227+
def query_data(instance_id, database_id):
228+
"""Queries sample data from the database using GQL."""
229+
spanner_client = spanner.Client()
230+
instance = spanner_client.instance(instance_id)
231+
database = instance.database(database_id)
232+
233+
with database.snapshot() as snapshot:
234+
results = snapshot.execute_sql(
235+
"""Graph FinGraph
236+
MATCH (a:Person)-[o:Owns]->()-[t:Transfers]->()<-[p:Owns]-(b:Person)
237+
RETURN a.name AS sender, b.name AS receiver, t.amount, t.create_time AS transfer_at"""
238+
)
239+
240+
for row in results:
241+
print("sender: {}, receiver: {}, amount: {}, transfer_at: {}".format(*row))
242+
243+
244+
# [END spanner_query_graph_data]
245+
246+
247+
# [START spanner_with_graph_query_data_with_parameter]
248+
def query_data_with_parameter(instance_id, database_id):
249+
"""Queries sample data from the database using SQL with a parameter."""
250+
251+
# instance_id = "your-spanner-instance"
252+
# database_id = "your-spanner-db-id"
253+
spanner_client = spanner.Client()
254+
instance = spanner_client.instance(instance_id)
255+
database = instance.database(database_id)
256+
257+
with database.snapshot() as snapshot:
258+
results = snapshot.execute_sql(
259+
"""Graph FinGraph
260+
MATCH (a:Person)-[o:Owns]->()-[t:Transfers]->()<-[p:Owns]-(b:Person)
261+
WHERE t.amount > @min
262+
RETURN a.name AS sender, b.name AS receiver, t.amount, t.create_time AS transfer_at""",
263+
params={"min": 500},
264+
param_types={"min": spanner.param_types.INT64},
265+
)
266+
267+
for row in results:
268+
print("sender: {}, receiver: {}, amount: {}, transfer_at: {}".format(*row))
269+
270+
271+
# [END spanner_with_graph_query_data_with_parameter]
272+
273+
274+
# [START spanner_delete_data]
275+
def delete_data(instance_id, database_id):
276+
"""Deletes sample data from the given database.
277+
278+
The database, table, and data must already exist and can be created using
279+
`create_database` and `insert_data`.
280+
"""
281+
spanner_client = spanner.Client()
282+
instance = spanner_client.instance(instance_id)
283+
database = instance.database(database_id)
284+
285+
# Delete individual rows
286+
ownerships_to_delete = spanner.KeySet(keys=[[1, 1], [2, 2]])
287+
288+
# Delete a range of rows where the column key is >=3 and <5
289+
transfers_range = spanner.KeyRange(start_closed=[1], end_open=[3])
290+
transfers_to_delete = spanner.KeySet(ranges=[transfers_range])
291+
292+
with database.batch() as batch:
293+
batch.delete("PersonOwnAccount", ownerships_to_delete)
294+
batch.delete("AccountTransferAccount", transfers_to_delete)
295+
296+
print("Deleted data.")
297+
298+
299+
# [END spanner_delete_data]
300+
301+
# [START spanner_delete_graph_data_with_dml]
302+
def delete_data_with_dml(instance_id, database_id):
303+
"""Deletes sample data from the database using a DML statement."""
304+
305+
# instance_id = "your-spanner-instance"
306+
# database_id = "your-spanner-db-id"
307+
308+
spanner_client = spanner.Client()
309+
instance = spanner_client.instance(instance_id)
310+
database = instance.database(database_id)
311+
312+
def delete_persons(transaction):
313+
row_ct = transaction.execute_update(
314+
"DELETE FROM Person WHERE True"
315+
)
316+
317+
print("{} record(s) deleted.".format(row_ct))
318+
319+
def delete_accounts(transaction):
320+
row_ct = transaction.execute_update(
321+
"DELETE FROM Account AS a WHERE EXTRACT(YEAR FROM DATE(a.create_time)) >= 2000"
322+
)
323+
324+
print("{} record(s) deleted.".format(row_ct))
325+
326+
database.run_in_transaction(delete_accounts)
327+
database.run_in_transaction(delete_persons)
328+
329+
330+
# [END spanner_delete_graph_data_with_dml]
331+
332+
333+
if __name__ == "__main__": # noqa: C901
334+
parser = argparse.ArgumentParser(
335+
description=__doc__, formatter_class=argparse.RawDescriptionHelpFormatter
336+
)
337+
parser.add_argument("instance_id", help="Your Cloud Spanner instance ID.")
338+
parser.add_argument(
339+
"--database-id", help="Your Cloud Spanner database ID.", default="example_db"
340+
)
341+
342+
subparsers = parser.add_subparsers(dest="command")
343+
subparsers.add_parser("create_instance", help=create_instance.__doc__)
344+
subparsers.add_parser(
345+
"create_database_with_property_graph",
346+
help=create_database_with_property_graph.__doc__)
347+
subparsers.add_parser("insert_data", help=insert_data.__doc__)
348+
subparsers.add_parser("insert_data_with_dml", help=insert_data_with_dml.__doc__)
349+
subparsers.add_parser("query_data", help=query_data.__doc__)
350+
subparsers.add_parser(
351+
"query_data_with_parameter", help=query_data_with_parameter.__doc__
352+
)
353+
354+
subparsers.add_parser("delete_data", help=delete_data.__doc__)
355+
subparsers.add_parser("delete_data_with_dml", help=delete_data_with_dml.__doc__)
356+
357+
args = parser.parse_args()
358+
359+
if args.command == "create_instance":
360+
create_instance(args.instance_id)
361+
elif args.command == "create_database_with_property_graph":
362+
create_database_with_property_graph(args.instance_id, args.database_id)
363+
elif args.command == "insert_data":
364+
insert_data(args.instance_id, args.database_id)
365+
elif args.command == "insert_data_with_dml":
366+
insert_data_with_dml(args.instance_id, args.database_id)
367+
elif args.command == "query_data":
368+
query_data(args.instance_id, args.database_id)
369+
elif args.command == "query_data_with_parameter":
370+
query_data_with_parameter(args.instance_id, args.database_id)
371+
elif args.command == "delete_data":
372+
delete_data(args.instance_id, args.database_id)
373+
elif args.command == "delete_data_with_dml":
374+
delete_data_with_dml(args.instance_id, args.database_id)
375+

0 commit comments

Comments
 (0)