├── .env ├── .gitignore ├── Dockerfile ├── README.md ├── docker-compose.yml └── docker-entrypoint └── initdb.d ├── 10-initdb.sql.gz ├── 20-initgraph.sql └── 30-regress_data.sql /.env: -------------------------------------------------------------------------------- 1 | DB_NAME=northwind 2 | DB_USER=postgres 3 | DB_PASSWORD=postgres -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | var/ -------------------------------------------------------------------------------- /Dockerfile: -------------------------------------------------------------------------------- 1 | FROM apache/age 2 | 3 | # Install Python 3 and plpython3u 4 | RUN apt-get update \ 5 | && apt-get install -y --no-install-recommends --no-install-suggests \ 6 | python3 \ 7 | postgresql-plpython3-16 \ 8 | && rm -rf /var/lib/apt/lists/* 9 | 10 | # The rest of the configuration remains the same 11 | CMD ["postgres", "-c", "shared_preload_libraries=age"] -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Apache AGE Starter 2 | 3 | This repository is designed to get people started using the Apache AGE plugin for Postgres. 4 | 5 | - Utilizes Docker Compose to stand up a version of PostgreSQL 11 with Apache AGE compiled and installed [sorrell/agensgraph-extension](https://hub.docker.com/repository/docker/sorrell/agensgraph-extension) 6 | - Restores a Northwind DB on initial `docker-compose up` 7 | - Creates helper functions for loading graph nodes from existing tables 8 | - Creates vertices/edges from Northwind DB data on initial `docker-compose up` 9 | 10 | ## Getting started 11 | 12 | All you should have to do to get started is 13 | 14 | - Clone this repository 15 | - Run `docker-compose up` 16 | - Set your `search_path` in the client you connect with 17 | 18 | To connect to the database, make sure you connect on port 5435, or change the docker-compose.yml to forward to a port you'd prefer. AGE should already be loaded. 19 | 20 | Once you are connected to the database you need to set your `search_path` by either using the helper function `graph_path()` or use the `SET` cmd. 21 | 22 | `SELECT graph_path();` 23 | 24 | or 25 | 26 | `SET search_path = ag_catalog, "$user", public;` 27 | 28 | ## Querying data 29 | 30 | To query some of the data, utilize the `northwind_graph`. Below is an example query that displays a hierarchy of who reports to who. 31 | 32 | ```sql 33 | SELECT * FROM cypher('northwind_graph', $$ 34 | MATCH (n:employee)-[r:REPORTS_TO]->(m:employee) 35 | RETURN n.lastname, n.title, m.lastname, m.title 36 | $$) AS (subord_lastname agtype, subord_title agtype, mgr_lastname agtype, mgr_title agtype); 37 | 38 | ------ RESULTS 39 | -----------------+----------------------------+--------------+------------------------- 40 | subord_lastname | subord_title | mgr_lastname | mgr_title 41 | -----------------+----------------------------+--------------+------------------------- 42 | "Davolio" | "Sales Representative" | "Fuller" | "Vice President, Sales" 43 | "Leverling" | "Sales Representative" | "Fuller" | "Vice President, Sales" 44 | "Peacock" | "Sales Representative" | "Fuller" | "Vice President, Sales" 45 | "Buchanan" | "Sales Manager" | "Fuller" | "Vice President, Sales" 46 | "Suyama" | "Sales Representative" | "Buchanan" | "Sales Manager" 47 | "King" | "Sales Representative" | "Buchanan" | "Sales Manager" 48 | "Callahan" | "Inside Sales Coordinator" | "Fuller" | "Vice President, Sales" 49 | "Dodsworth" | "Sales Representative" | "Buchanan" | "Sales Manager" 50 | -----------------+----------------------------+--------------+------------------------- 51 | (8 rows) 52 | ``` 53 | 54 | -------------------------------------------------------------------------------- /docker-compose.yml: -------------------------------------------------------------------------------- 1 | services: 2 | postgres: 3 | build: . 4 | ports: 5 | - 5435:5432 6 | env_file: 7 | - ./.env 8 | environment: 9 | POSTGRES_DB: ${DB_NAME} 10 | POSTGRES_PASSWORD: ${DB_PASSWORD} 11 | POSTGRES_USER: ${DB_USER} 12 | volumes: 13 | - ./docker-entrypoint/initdb.d:/docker-entrypoint-initdb.d:ro 14 | - ./var/lib/postgres:/var/lib/postgresql/16/main:delegated 15 | -------------------------------------------------------------------------------- /docker-entrypoint/initdb.d/10-initdb.sql.gz: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/sorrell/age-compose/155ed6bb778c93b14e935c870b912f0034460fff/docker-entrypoint/initdb.d/10-initdb.sql.gz -------------------------------------------------------------------------------- /docker-entrypoint/initdb.d/20-initgraph.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION graph_path() 2 | RETURNS void AS $$ 3 | BEGIN 4 | SET search_path = ag_catalog, "$user", public; 5 | END; 6 | $$ LANGUAGE plpgsql; 7 | 8 | CREATE EXTENSION plpython3u; 9 | 10 | CREATE FUNCTION load_graph_from_table(node_name text, source_table_name text, graph_name text DEFAULT null) 11 | RETURNS text AS $$ 12 | import re 13 | def unquote_keys_json(query_result): 14 | regex = r'\"([^\"]*)\":' 15 | subst = '\\1:' 16 | return re.sub(regex, subst, query_result, 0, re.MULTILINE) 17 | def get_graph_name(graph_name): 18 | current_graph = graph_name 19 | if not graph_name: 20 | res = plpy.execute("SELECT current_setting('age.current_graph');"); 21 | current_graph = res[0]["current_setting"] 22 | return current_graph 23 | def main(graph_name): 24 | row_count = 0 25 | query = 'SELECT to_jsonb({src1}) FROM {src2}'.format(src1=source_table_name, src2=source_table_name) 26 | graph = get_graph_name(graph_name) 27 | for row in plpy.cursor(query): 28 | row_count = row_count + 1 29 | json_unquoted_keys = unquote_keys_json(row['to_jsonb']) 30 | graph_query = (("SELECT * from cypher('{graph_name}', ^^CREATE (a:{node_name} ".format(graph_name=graph, node_name=node_name) 31 | + json_unquoted_keys 32 | + ")^^) as (a agtype)") 33 | .replace("^", "$")) 34 | plpy.execute(graph_query) 35 | return "Successfully loaded {node} node from {tbl} table ({records} records)".format(node=node_name, tbl=source_table_name, records=row_count) 36 | return main(graph_name) 37 | $$ LANGUAGE plpython3u; 38 | 39 | -- Create and Load AGE extension 40 | CREATE EXTENSION age; 41 | LOAD 'age'; 42 | SET search_path = ag_catalog, "$user", public; 43 | 44 | 45 | -- Create graph 46 | SELECT create_graph('northwind_graph'); 47 | 48 | -- Set northwind_graph as default 49 | SET age.current_graph='northwind_graph'; 50 | 51 | -- Create vertices/nodes from relational tables 52 | SELECT load_graph_from_table('category', 'categories'); 53 | SELECT load_graph_from_table('customer', 'customers'); 54 | SELECT load_graph_from_table('employee', 'employees'); 55 | SELECT load_graph_from_table('order', 'orders'); 56 | SELECT load_graph_from_table('ordersdetail', 'orders_details'); 57 | SELECT load_graph_from_table('product', 'products'); 58 | SELECT load_graph_from_table('region', 'regions'); 59 | SELECT load_graph_from_table('shipper', 'shippers'); 60 | SELECT load_graph_from_table('supplier', 'suppliers'); 61 | SELECT load_graph_from_table('territory', 'territories'); 62 | 63 | 64 | 65 | -- Create edges/relationships 66 | DO $$ BEGIN RAISE NOTICE 'CREATING Order Details Relationship'; END $$; 67 | 68 | SELECT * FROM cypher('northwind_graph', $$ 69 | MATCH (n:order),(m:product),(d:ordersdetail) 70 | WHERE n.orderid=d.orderid 71 | AND m.productid=d.productid 72 | CREATE (n)-[r:ORDERS {unitprice:d.unitprice, quantity:d.quantity, discount:d.discount}]->(m) 73 | RETURN toString(count(r)) + ' relations created.' 74 | $$) AS (a agtype); 75 | 76 | DO $$ BEGIN RAISE NOTICE 'CREATING Employee-Mgr Relationship'; END $$; 77 | SELECT * FROM cypher('northwind_graph', $$ 78 | MATCH (n:employee),(m:employee) 79 | WHERE m.employeeid=n.reportto 80 | CREATE (n)-[r:REPORTS_TO]->(m) 81 | RETURN toString(count(r)) + ' relations created.' 82 | $$) AS (a agtype); 83 | 84 | DO $$ BEGIN RAISE NOTICE 'CREATING Supplier Relationship'; END $$; 85 | SELECT * FROM cypher('northwind_graph', $$ 86 | MATCH (n:supplier),(m:product) 87 | WHERE m.supplierid=n.supplierid 88 | CREATE (n)-[r:SUPPLIES]->(m) 89 | RETURN toString(count(r)) + ' relations created.' 90 | $$) AS (a agtype); 91 | 92 | DO $$ BEGIN RAISE NOTICE 'CREATING Product Category Relationship'; END $$; 93 | SELECT * FROM cypher('northwind_graph', $$ 94 | MATCH (n:product),(m:category) 95 | WHERE n.categoryid=m.categoryid 96 | CREATE (n)-[r:PART_OF]->(m) 97 | RETURN toString(count(r)) + ' relations created.' 98 | $$) AS (a agtype); 99 | 100 | DO $$ BEGIN RAISE NOTICE 'CREATING Customer Purchase Relationship'; END $$; 101 | SELECT * FROM cypher('northwind_graph', $$ 102 | MATCH (n:customer),(m:order) 103 | WHERE m.customerid=n.customerid 104 | CREATE (n)-[r:PURCHASED]->(m) 105 | RETURN toString(count(r)) + ' relations created.' 106 | $$) AS (a agtype); 107 | 108 | DO $$ BEGIN RAISE NOTICE 'CREATING Employee-Sales Relationship'; END $$; 109 | SELECT * FROM cypher('northwind_graph', $$ 110 | MATCH (n:employee),(m:order) 111 | WHERE m.employeeid=n.employeeid 112 | CREATE (n)-[r:SOLD]->(m) 113 | RETURN toString(count(r)) + ' relations created.' 114 | $$) AS (a agtype); -------------------------------------------------------------------------------- /docker-entrypoint/initdb.d/30-regress_data.sql: -------------------------------------------------------------------------------- 1 | SET search_path = ag_catalog, "$user", public; 2 | 3 | SET age.current_graph='northwind_graph'; 4 | 5 | SELECT create_vlabel('northwind_graph','City'); 6 | 7 | SELECT load_labels_from_file('northwind_graph', 'City', 8 | '/age/regress/age_load/data/cities.csv', true); 9 | 10 | SELECT create_vlabel('northwind_graph','Country'); 11 | SELECT load_labels_from_file('northwind_graph', 12 | 'Country', 13 | '/age/regress/age_load/data/countries.csv'); 14 | 15 | SELECT create_elabel('northwind_graph','has_city'); 16 | SELECT load_edges_from_file('northwind_graph', 'has_city', 17 | '/age/regress/age_load/data/edges.csv'); --------------------------------------------------------------------------------