|
| 1 | +-- Drop BANK_GRAPH and tables if they exist |
| 2 | +DROP PROPERTY GRAPH BANK_GRAPH; |
| 3 | +DROP TABLE BANK_TRANSFERS; |
| 4 | +DROP TABLE BANK_ACCOUNTS; |
| 5 | + |
| 6 | +-- create BANK ACCOUNTS table |
| 7 | +CREATE TABLE BANK_ACCOUNTS ( |
| 8 | + ID NUMBER, |
| 9 | + NAME VARCHAR(400), |
| 10 | + BALANCE NUMBER(20,2) |
| 11 | +); |
| 12 | + |
| 13 | +-- create BANK_TRANSFERS table |
| 14 | +CREATE TABLE BANK_TRANSFERS ( |
| 15 | + TXN_ID NUMBER, |
| 16 | + SRC_ACCT_ID NUMBER, |
| 17 | + DST_ACCT_ID NUMBER, |
| 18 | + DESCRIPTION VARCHAR(400), |
| 19 | + AMOUNT NUMBER |
| 20 | +); |
| 21 | + |
| 22 | +-- Add constraints |
| 23 | +ALTER TABLE BANK_ACCOUNTS ADD PRIMARY KEY (ID); |
| 24 | +ALTER TABLE BANK_TRANSFERS ADD PRIMARY KEY (TXN_ID); |
| 25 | +ALTER TABLE BANK_TRANSFERS MODIFY SRC_ACCT_ID REFERENCES BANK_ACCOUNTS (ID); |
| 26 | +ALTER TABLE BANK_TRANSFERS MODIFY DST_ACCT_ID REFERENCES BANK_ACCOUNTS (ID); |
| 27 | + |
| 28 | +-- Optionally verify constraints |
| 29 | +SELECT * FROM USER_CONS_COLUMNS WHERE table_name IN ('BANK_ACCOUNTS', 'BANK_TRANSFERS'); |
| 30 | + |
| 31 | +-- At this point, you should load the BANK_ACCOUNTS.csv and BANK_TRANSFERS.csv files into the BANK_ACCOUNTS and BANK_TRANSACTIONS tables respectively |
| 32 | +-- Create a property graph view on bank_accounts and bank_transfers |
| 33 | +CREATE PROPERTY GRAPH BANK_GRAPH |
| 34 | + VERTEX TABLES ( |
| 35 | + BANK_ACCOUNTS |
| 36 | + KEY (ID) |
| 37 | + PROPERTIES (ID, Name, Balance) |
| 38 | + ) |
| 39 | + EDGE TABLES ( |
| 40 | + BANK_TRANSFERS |
| 41 | + KEY (TXN_ID) |
| 42 | + SOURCE KEY (src_acct_id) REFERENCES BANK_ACCOUNTS(ID) |
| 43 | + DESTINATION KEY (dst_acct_id) REFERENCES BANK_ACCOUNTS(ID) |
| 44 | + PROPERTIES (src_acct_id, dst_acct_id, amount) |
| 45 | + ); |
| 46 | + |
| 47 | +-- This query shows the graphs available for the current user |
| 48 | +SELECT * FROM user_property_graphs; |
| 49 | + |
| 50 | +-- This query shows the DDL for the BANK_TRANSFERS graph |
| 51 | +SELECT dbms_metadata.get_ddl('PROPERTY_GRAPH', 'BANK_GRAPH') from dual; |
| 52 | + |
| 53 | +-- This query shows the elements for the BANK_TRANSFERS graph |
| 54 | +SELECT * FROM user_pg_elements WHERE graph_name='BANK_GRAPH'; |
| 55 | + |
| 56 | +-- This query shoes the labels and properties available in the BANK_TRANSFERS graph |
| 57 | +SELECT * FROM user_pg_label_properties WHERE graph_name='BANK_GRAPH'; |
| 58 | + |
| 59 | +-- Find the top 10 accounts by incoming transfers |
| 60 | +SELECT acct_id, COUNT(1) AS Num_Transfers |
| 61 | + FROM graph_table ( BANK_GRAPH |
| 62 | + MATCH (src) - [IS BANK_TRANSFERS] -> (dst) |
| 63 | + COLUMNS ( dst.id AS acct_id ) |
| 64 | + ) GROUP BY acct_id ORDER BY Num_Transfers DESC FETCH FIRST 10 ROWS ONLY; |
| 65 | + |
| 66 | +-- Find the top 10 accounts in the middle of a 2-hop chain of transfers |
| 67 | +SELECT acct_id, COUNT(1) AS Num_In_Middle |
| 68 | + FROM graph_table ( BANK_GRAPH |
| 69 | + MATCH (src) - [IS BANK_TRANSFERS] -> (via) - [IS BANK_TRANSFERS] -> (dst) |
| 70 | + COLUMNS ( via.id AS acct_id ) |
| 71 | + ) GROUP BY acct_id ORDER BY Num_In_Middle DESC FETCH FIRST 10 ROWS ONLY; |
| 72 | + |
| 73 | +-- List accounts that received a transfer from account 387 in 1, 2, or 3 hops |
| 74 | +SELECT account_id1, account_id2 |
| 75 | + FROM graph_table(BANK_GRAPH |
| 76 | + MATCH (v1)-[IS BANK_TRANSFERS]->{1,3}(v2) |
| 77 | + WHERE v1.id = 387 |
| 78 | + COLUMNS (v1.id AS account_id1, v2.id AS account_id2) |
| 79 | + ); |
| 80 | + |
| 81 | +-- Check if there are any 3-hop (triangles) transfers that start and end at the same account |
| 82 | +SELECT acct_id, COUNT(1) AS Num_Triangles |
| 83 | + FROM graph_table (BANK_GRAPH |
| 84 | + MATCH (src) - []->{3} (src) |
| 85 | + COLUMNS (src.id AS acct_id) |
| 86 | + ) GROUP BY acct_id ORDER BY Num_Triangles DESC; |
| 87 | + |
| 88 | +-- Check if there are any 4-hop transfers that start and end at the same account |
| 89 | +SELECT acct_id, COUNT(1) AS Num_4hop_Chains |
| 90 | + FROM graph_table (BANK_GRAPH |
| 91 | + MATCH (src) - []->{4} (src) |
| 92 | + COLUMNS (src.id AS acct_id) |
| 93 | + ) GROUP BY acct_id ORDER BY Num_4hop_Chains DESC; |
| 94 | + |
| 95 | +-- Check if there are any 5-hop transfers that start and end at the same account |
| 96 | +SELECT acct_id, COUNT(1) AS Num_5hop_Chains |
| 97 | + FROM graph_table (BANK_GRAPH |
| 98 | + MATCH (src) - []->{5} (src) |
| 99 | + COLUMNS (src.id AS acct_id) |
| 100 | + ) GROUP BY acct_id ORDER BY Num_5hop_Chains DESC; |
| 101 | + |
| 102 | +-- List some (any 10) accounts which had a 3 to 5 hop circular payment chain |
| 103 | +SELECT DISTINCT(account_id) |
| 104 | + FROM GRAPH_TABLE(BANK_GRAPH |
| 105 | + MATCH (v1)-[IS BANK_TRANSFERS]->{3,5}(v1) |
| 106 | + COLUMNS (v1.id AS account_id) |
| 107 | + ) FETCH FIRST 10 ROWS ONLY; |
| 108 | + |
| 109 | +-- Query accounts by number of 3 to 5 hops cycles in descending order. Show top 10. |
| 110 | +SELECT DISTINCT(account_id), COUNT(1) AS Num_Cycles |
| 111 | + FROM graph_table(BANK_GRAPH |
| 112 | + MATCH (v1)-[IS BANK_TRANSFERS]->{3, 5}(v1) |
| 113 | + COLUMNS (v1.id AS account_id) |
| 114 | + ) GROUP BY account_id ORDER BY Num_Cycles DESC FETCH FIRST 10 ROWS ONLY; |
| 115 | + |
| 116 | + |
| 117 | + |
| 118 | + |
| 119 | + |
| 120 | + |
| 121 | + |
| 122 | + |
| 123 | + |
| 124 | + |
| 125 | + |
| 126 | + |
| 127 | + |
| 128 | + |
| 129 | + |
| 130 | + |
| 131 | + |
| 132 | + |
| 133 | + |
| 134 | + |
| 135 | + |
| 136 | + |
| 137 | + |
0 commit comments