diff --git a/samples/features/readme.md b/samples/features/readme.md index 54139895..ca70fb4b 100644 --- a/samples/features/readme.md +++ b/samples/features/readme.md @@ -20,6 +20,10 @@ Built-in JSON functions enable you to easily parse and query JSON data stored in Built-in temporal functions enable you to easily track history of changes in a table, go back in history, and analyze historical data. +[Graph Tables](sql-graph) + +Graph tables enable you to add a non-relational capability to your database. + ## Samples for Business Intelligence features within SQL Server [Reporting Services (SSRS)](reporting-services) diff --git a/samples/features/sql-graph/Graph.Customers.csv b/samples/features/sql-graph/Graph.Customers.csv new file mode 100644 index 00000000..f81d6c51 Binary files /dev/null and b/samples/features/sql-graph/Graph.Customers.csv differ diff --git a/samples/features/sql-graph/README.md b/samples/features/sql-graph/README.md new file mode 100644 index 00000000..56e56e75 Binary files /dev/null and b/samples/features/sql-graph/README.md differ diff --git a/samples/features/sql-graph/create_graph_tables.sql b/samples/features/sql-graph/create_graph_tables.sql new file mode 100644 index 00000000..93e1fda1 --- /dev/null +++ b/samples/features/sql-graph/create_graph_tables.sql @@ -0,0 +1,333 @@ +-- clean database +DROP TABLE IF EXISTS Graph.Customers; +DROP TABLE IF EXISTS Graph.StockItems; +DROP TABLE IF EXISTS Graph.Suppliers; + +DROP TABLE IF EXISTS Graph.OrderLines_CustomersToStockItems; +DROP TABLE IF EXISTS Graph.OrderLines_StockItemsToCustomers; + +DROP TABLE IF EXISTS Graph.InvoiceLines_CustomersToStockItems; +DROP TABLE IF EXISTS Graph.InvoiceLines_StockItemsToCustomers; + +DROP TABLE IF EXISTS Graph.PurchaseOrderLines_SuppliersToStockItems; +DROP TABLE IF EXISTS Graph.PurchaseOrderLines_StockItemsToSuppliers; + +DROP SCHEMA IF EXISTS Graph; +go + +-- define schema +CREATE SCHEMA Graph; +go + +/* SALES schema */ +-- create node table for Sales.Customers +CREATE TABLE Graph.Customers ( + CustomerID int, + CustomerName nvarchar(100), + BillToCustomerID int, + CustomerCategoryID int, + BuyingGroupID int, + PrimaryContactPersonID int, + AlternateContactPersonID int, + DeliveryMethodID int, + DeliveryCityID int, + PostalCityID int, + CreditLimit decimal(18,2), + AccountOpenedDate date, + StandardDiscountPercentage decimal(18,3), + IsStatementSent bit, + IsOnCreditHold bit, + PaymentDays int, + PhoneNumber nvarchar(20), + WebsiteURL nvarchar(256), + DeliveryAddressLine1 nvarchar(60), + DeliveryAddressLine2 nvarchar(60), + DeliveryPostalCode nvarchar(10), + DeliveryLocation geography, + PostalAddressLine1 nvarchar(60), + PostalAddressLine2 nvarchar(60), + PostalPostalCode nvarchar(10), + LastEditedBy int, + ValidFrom datetime2, + ValidTo datetime2 +) AS NODE; + +-- create edge table for Sales.Orders and Sales.Orderlines +-- LINK: CUSTOMERS -->> STOCKITEMS +CREATE TABLE Graph.OrderLines_CustomersToStockItems ( + + -- from Sales.Orders + OrderID int, + CustomerID int, + SalespersonPersonID int, + PickedByPersonID int, + ContactPersonID int, + BackorderOrderID int, + OrderDate date, + ExpectedDeliveryDate date, + CustomerPurchaseOrderNumber nvarchar(20), + IsUndersupplyBackordered bit, + Comments nvarchar(max), + DeliveryInstructions nvarchar(max), + InternalComments nvarchar(max), + + -- from Sales.OrderLines + StockItemID int, + Description nvarchar(100), + PackageTypeID int, + Quantity int, + UnitPrice decimal(18,2), + TaxRate decimal(18,3), + PickedQuantity int, + PickingCompletedWhen datetime2, + LastEditedBy int, + LastEditedWhen datetime2 +) AS EDGE; + +-- create edge table for Sales.Invoices and Sales.InvoiceLines +-- LINK: CUSTOMERS -->> STOCKITEMS +CREATE TABLE Graph.InvoiceLines_CustomersToStockItems ( + + -- from Sales.Invoices + InvoiceID int, + CustomerID int, + BillToCustomerID int, + OrderID int, + DeliveryMethodID int, + ContactPersonID int, + AccountsPersonID int, + SalespersonPersonID int, + PackedByPersonID int, + InvoiceDate date, + CustomerPurchaseOrderNumber nvarchar(20), + IsCreditNote bit, + CreditNoteReason nvarchar(max), + Comments nvarchar(max), + DeliveryInstructions nvarchar(max), + InternalComments nvarchar(max), + TotalDryItems int, + TotalChillerItems int, + DeliveryRun nvarchar(5), + RunPosition nvarchar(5), + ReturnedDeliveryData nvarchar(max), + ConfirmedDeliveryTime datetime2, + ConfirmedReceivedBy nvarchar(4000), + + -- from Sales.InvoiceLines + InvoiceLineID int, + StockItemID int, + Description nvarchar(100), + PackageTypeID int, + Quantity int, + UnitPrice decimal(18,3), + TaxRate decimal(18,2), + TaxAmount decimal(18,2), + LineProfit decimal(18,2), + ExtendedPrice decimal(18,2), + LastEditedBy int, + LastEditedWhen datetime2 +) AS EDGE; + + +-- create edge table for Sales.Orders and Sales.Orderlines +-- LINK: STOCKITEMS -->> CUSTOMERS +CREATE TABLE Graph.OrderLines_StockItemsToCustomers ( + + -- from Sales.Orders + OrderID int, + CustomerID int, + SalespersonPersonID int, + PickedByPersonID int, + ContactPersonID int, + BackorderOrderID int, + OrderDate date, + ExpectedDeliveryDate date, + CustomerPurchaseOrderNumber nvarchar(20), + IsUndersupplyBackordered bit, + Comments nvarchar(max), + DeliveryInstructions nvarchar(max), + InternalComments nvarchar(max), + + -- from Sales.OrderLines + StockItemID int, + Description nvarchar(100), + PackageTypeID int, + Quantity int, + UnitPrice decimal(18,2), + TaxRate decimal(18,3), + PickedQuantity int, + PickingCompletedWhen datetime2, + LastEditedBy int, + LastEditedWhen datetime2 +) AS EDGE; + +-- create edge table for Sales.Invoices and Sales.InvoiceLines +-- LINK: STOCKITEMS -->> CUSTOMERS +CREATE TABLE Graph.InvoiceLines_StockItemsToCustomers ( + + -- from Sales.Invoices + InvoiceID int, + CustomerID int, + BillToCustomerID int, + OrderID int, + DeliveryMethodID int, + ContactPersonID int, + AccountsPersonID int, + SalespersonPersonID int, + PackedByPersonID int, + InvoiceDate date, + CustomerPurchaseOrderNumber nvarchar(20), + IsCreditNote bit, + CreditNoteReason nvarchar(max), + Comments nvarchar(max), + DeliveryInstructions nvarchar(max), + InternalComments nvarchar(max), + TotalDryItems int, + TotalChillerItems int, + DeliveryRun nvarchar(5), + RunPosition nvarchar(5), + ReturnedDeliveryData nvarchar(max), + ConfirmedDeliveryTime datetime2, + ConfirmedReceivedBy nvarchar(4000), + + -- from Sales.InvoiceLines + InvoiceLineID int, + StockItemID int, + Description nvarchar(100), + PackageTypeID int, + Quantity int, + UnitPrice decimal(18,3), + TaxRate decimal(18,2), + TaxAmount decimal(18,2), + LineProfit decimal(18,2), + ExtendedPrice decimal(18,2), + LastEditedBy int, + LastEditedWhen datetime2 +) AS EDGE; + + +/* WAREHOUSE schema */ +-- create node table for Warehouse.StockItems +CREATE TABLE Graph.StockItems ( + StockItemID int, + StockItemName nvarchar(100), + SupplierID int, + ColorID int, + UnitPackageID int, + OuterPackageID int, + Brand nvarchar(50), + Size nvarchar(20), + LeadTimeDays int, + QuantityPerOuter int, + IsChillerStock bit, + Barcode nvarchar(50), + TaxRate decimal(18,3), + UnitPrice decimal(18,2), + RecommendedRetailPrice decimal(18,2), + TypicalWeightPerUnit decimal(5,2), + MarketingComments nvarchar(max), + InternalComments nvarchar(max), + Photo varbinary(max), + CustomFields nvarchar(max), + Tags nvarchar(max), + SearchDetails nvarchar(max), + LastEditedBy int, + ValidFrom datetime2, + ValidTo datetime2 +) AS NODE; + +/* PURCHASING schema */ +-- create node table for Purchasing.Suppliers +CREATE TABLE Graph.Suppliers ( + SupplierID int, + SupplierName nvarchar(100), + SupplierCategoryID int, + PrimaryContactPersonID int, + AlternateContactPersonID int, + DeliveryMethodID int, + DeliveryCityID int, + PostalCityID int, + SupplierReference nvarchar(20), + BankAccountName nvarchar(50), + BankAccountBranch nvarchar(50), + BankAccountCode nvarchar(20), + BankAccountNumber nvarchar(20), + BankInternationalCode nvarchar(20), + PaymentDays int, + InternalComments nvarchar(max), + PhoneNumber nvarchar(20), + FaxNumber nvarchar(20), + WebsiteURL nvarchar(256), + DeliveryAddressLine1 nvarchar(60), + DeliveryAddressLine2 nvarchar(60), + DeliveryPostalCode nvarchar(10), + DeliveryLocation geography, + PostalAddressLine1 nvarchar(60), + PostalAddressLine2 nvarchar(60), + PostalPostalCode nvarchar(10), + LastEditedBy int, + ValidFrom datetime2, + ValidTo datetime2 +) AS NODE + +-- create edge table for Purchasing.PurchaseOrders and Purchasing.PurchaseOrderLines +-- LINK: SUPPLIERS -->> STOCKITEMS +CREATE TABLE Graph.PurchaseOrderLines_SuppliersToStockItems ( + + -- from Purchasing.PurchaseOrders + PurchaseOrderID int, + SupplierID int, + OrderDate date, + DeliveryMethodID int, + ContactPersonID int, + ExpectedDeliveryDate date, + SupplierReference nvarchar(20), + IsOrderFinalized bit, + Comments nvarchar(max), + InternalComments nvarchar(max), + + -- from Purchasing.PurchaseOrderLines + PurchaseOrderLineID int, + StockItemID int, + OrderedOuters int, + Description nvarchar(100), + ReceivedOuters int, + PackageTypeID int, + ExpectedUnitPricePerOuter decimal(18,2), + LastReceiptDate date, + IsOrderLineFinalized bit, + LastEditedBy int, + LastEditedWhen datetime2 +) AS EDGE; + +-- create edge table for Purchasing.PurchaseOrders and Purchasing.PurchaseOrderLines +-- LINK: STOCKITEMS -->> SUPPLIERS +CREATE TABLE Graph.PurchaseOrderLines_StockItemsToSuppliers ( + + -- from Purchasing.PurchaseOrders + PurchaseOrderID int, + SupplierID int, + OrderDate date, + DeliveryMethodID int, + ContactPersonID int, + ExpectedDeliveryDate date, + SupplierReference nvarchar(20), + IsOrderFinalized bit, + Comments nvarchar(max), + InternalComments nvarchar(max), + + -- from Purchasing.PurchaseOrderLines + PurchaseOrderLineID int, + StockItemID int, + OrderedOuters int, + Description nvarchar(100), + ReceivedOuters int, + PackageTypeID int, + ExpectedUnitPricePerOuter decimal(18,2), + LastReceiptDate date, + IsOrderLineFinalized bit, + LastEditedBy int, + LastEditedWhen datetime2 +) AS EDGE; + +go diff --git a/samples/features/sql-graph/csv_as_node.py b/samples/features/sql-graph/csv_as_node.py new file mode 100644 index 00000000..b7bced52 --- /dev/null +++ b/samples/features/sql-graph/csv_as_node.py @@ -0,0 +1,46 @@ +# -*- coding: utf-8 -*- +import os +from optparse import OptionParser + +def main(input_file_path, schema, table): + + # create the output file in the same directory as the input file + output_file_path = os.path.splitext(input_file_path)[0] + '_as_node' + '.csv' + + # you may have to change the encoding + with open(input_file_path, mode='r', encoding = 'utf-16le', newline='') as input_file, \ + open(output_file_path, mode='w', encoding = 'utf-16le', newline='') as output_file: + + line = input_file.readline() + line_number = 0 + + # read each line of the input file, add a $node_id column and write down the result on the output file + while line: + if line_number == 0: + newline = '\ufeff' + '{"type":"node","schema":"' + schema + '","table":"' + table + '","id":' + str(line_number) + '}\t' + line[1:] + else: + newline = '{"type":"node","schema":"' + schema + '","table":"' + table + '","id":' + str(line_number) + '}\t' + line + output_file.write(newline) + line_number += 1 + line = input_file.readline() + +if __name__ == '__main__': + + parser = OptionParser() + + parser.add_option("-f", "--file", action="store", type="string", dest="input_file_name") + parser.add_option("-s", "--schema", action="store", type="string", dest="schema") + parser.add_option("-t", "--table", action="store", type="string", dest="table") + + (options, args) = parser.parse_args() + + # retrieve options if not provided by the user + if (options.input_file_name == None): + options.name = input('Please enter the full path to the csv file you will import as a node table:') + if (options.schema == None): + options.name = input('Please enter the SQL schema of the node table you will populate:') + if (options.table == None): + options.name = input('Please enter the SQL name of the node table you are populate:') + + main(options.input_file_name, options.schema, options.table) + diff --git a/samples/features/sql-graph/csv_as_node.sql b/samples/features/sql-graph/csv_as_node.sql new file mode 100644 index 00000000..a6d0715d --- /dev/null +++ b/samples/features/sql-graph/csv_as_node.sql @@ -0,0 +1,82 @@ +/* +Bulk insert a csv file using bcp +*/ + +-- CREATE TABLE +DROP TABLE IF EXISTS Graph.Customers; + +CREATE TABLE Graph.Customers( + CustomerID int, + CustomerName nvarchar(100) not null, + BillToCustomerID int not null, + CustomerCategoryID int not null, + BuyingGroupID int null, + PrimaryContactPersonID int not null, + AlternateContactPersonID int null, + DeliveryMethodID int not null, + DeliveryCityID int not null, + PostalCityID int not null, + CreditLimit decimal(18, 2) null, + AccountOpenedDate date not null, + StandardDiscountPercentage decimal(18, 3) not null, + IsStatementSent bit not null, + IsOnCreditHold bit not null, + PaymentDays int not null, + PhoneNumber nvarchar(20) not null, + FaxNumber nvarchar(20) null, + DeliveryRun nvarchar(5) null, + RunPosition nvarchar(5) null, + WebsiteURL nvarchar(256) not null, + DeliveryAddressLine1 nvarchar(60) not null, + DeliveryAddressLine2 nvarchar(60) null, + DeliveryPostalCode nvarchar(10) not null, + DeliveryLocation geography null, + PostalAddressLine1 nvarchar(60) not null, + PostalAddressLine2 nvarchar(60) null, + PostalPostalCode nvarchar(10) not null, + LastEditedBy int not null, + ValidFrom datetime2(7) not null, + ValidTo datetime2(7) not null +) AS NODE; +go + +-- to improve performance, disable default indexes +ALTER INDEX ALL ON Graph.Customers disable; +go + +/* SQL Server only +-- to improve performance, set the recovery mode to bulk_logged +USE master; +go + +ALTER DATABASE [WideWorldImporters-Standard] +SET recovery bulk_logged; +go +*/ + +/* +:: From a windows command line, run the following commands. +:: The first line retrieves [WideWorldImporters-Standard].[Sales].[Customers] as a csv file. +bcp [WideWorldImporters-Standard].[Sales].[Customers] out "E:\Graph Examples\Graph.Customers.csv" -w -U {userName}@{serverName} -S tcp:{serverName}.database.windows.net -P {password} +:: +:: The second line inserts a column $node_id into the csv file +python csv_as_node.py -f "E:\\Graph Examples\\Graph.Customers.csv" -s "Graph" -t "Customers" +:: +:: The third and last line inserts the newly created csv file "E:\Graph Examples\Graph.Customers_as_node.csv" into [WideWorldImporters-Standard].[Graph].[Customers] +bcp [WideWorldImporters-Standard].[Graph].[Customers] in "E:\Graph Examples\Graph.Customers_as_node.csv" -w -U {userName}@{serverName} -S tcp:{serverName}.database.windows.net -P {password} +*/ + +/* SQL Server only +ALTER DATABASE [WideWorldImporters-Standard] +SET recovery full; +go + +USE [WideWorldImporters-Standard]; +go +*/ + +ALTER INDEX ALL ON Graph.Customers rebuild; +go + +select * from Graph.Customers; +go diff --git a/samples/features/sql-graph/customers_who_bought_this_also_bought.sql b/samples/features/sql-graph/customers_who_bought_this_also_bought.sql new file mode 100644 index 00000000..d9faaac0 --- /dev/null +++ b/samples/features/sql-graph/customers_who_bought_this_also_bought.sql @@ -0,0 +1,27 @@ +/* +Customer who bought this also bought this +Using graph tables +Using regular tables +*/ + +-- using graph tables +SELECT DISTINCT s2.StockItemName +FROM Graph.StockItems AS s1, Graph.OrderLines_CustomersToStockItems, Graph.Customers, Graph.OrderLines_StockItemsToCustomers, Graph.StockItems AS s2 +WHERE MATCH (s1 - (OrderLines_StockItemsToCustomers) -> Customers and Customers - (OrderLines_CustomersToStockItems) -> s2) + and s1.StockItemName = 'Chocolate frogs 250g' +ORDER BY s2.StockItemName +go + +-- using regular tables +SELECT DISTINCT s2.StockItemName +FROM (select StockItemID, StockItemName FROM Warehouse.StockItems ) AS s1 + join (select StockItemID, OrderID FROM Sales.OrderLines) AS q1 ON q1.StockItemID = s1.StockItemID + join (select OrderID, CustomerID FROM Sales.Orders) AS q2 ON q1.OrderID = q2.OrderID + join (select CustomerID, OrderID FROM Sales.Orders) AS q3 ON q2.CustomerID = q3.CustomerID + join (select OrderID, StockItemID FROM Sales.Orderlines) AS q4 ON q3.OrderID = q4.OrderID + join (select StockItemID, StockItemName FROM Warehouse.StockItems ) AS s2 ON q4.StockItemID = s2.StockItemID +WHERE s1.StockItemName = 'Chocolate frogs 250g' +ORDER BY s2.StockItemName +go + + diff --git a/samples/features/sql-graph/graph_layout.png b/samples/features/sql-graph/graph_layout.png new file mode 100644 index 00000000..0997f3bf Binary files /dev/null and b/samples/features/sql-graph/graph_layout.png differ diff --git a/samples/features/sql-graph/openrowset_bulk_insert.sql b/samples/features/sql-graph/openrowset_bulk_insert.sql new file mode 100644 index 00000000..26e1892b --- /dev/null +++ b/samples/features/sql-graph/openrowset_bulk_insert.sql @@ -0,0 +1,148 @@ +/* +Bulk insert using OPENROWSET +SQL Server only +*/ + +/* SETUP. Download [WideWorldImporters-Standard].Sales.Customers as a csv file and create the related format file +:: From a windows command line, run the following commands +bcp [WideWorldImporters-Standard].Sales.Customers out "E:\Graph Examples\Graph.Customers.csv" -w -U {userName}@{serverName} -S tcp:{serverName}.database.windows.net -P {password} +bcp [WideWorldImporters-Standard].Sales.Customers format nul -x -f "E:\Graph Examples\Graph.Customers_format.xml" -w -U {userName}@{serverName} -S tcp:{serverName}.database.windows.net -P {password} +*/ + +-- create node table +DROP TABLE IF EXISTS Graph.Customers; +GO + +CREATE TABLE Graph.Customers( + CustomerID int, + CustomerName nvarchar(100) not null, + BillToCustomerID int not null, + CustomerCategoryID int not null, + BuyingGroupID int null, + PrimaryContactPersonID int not null, + AlternateContactPersonID int null, + DeliveryMethodID int not null, + DeliveryCityID int not null, + PostalCityID int not null, + CreditLimit decimal(18, 2) null, + AccountOpenedDate date not null, + StandardDiscountPercentage decimal(18, 3) not null, + IsStatementSent bit not null, + IsOnCreditHold bit not null, + PaymentDays int not null, + PhoneNumber nvarchar(20) not null, + FaxNumber nvarchar(20) null, + DeliveryRun nvarchar(5) null, + RunPosition nvarchar(5) null, + WebsiteURL nvarchar(256) not null, + DeliveryAddressLine1 nvarchar(60) not null, + DeliveryAddressLine2 nvarchar(60) null, + DeliveryPostalCode nvarchar(10) not null, + DeliveryLocation geography null, + PostalAddressLine1 nvarchar(60) not null, + PostalAddressLine2 nvarchar(60) null, + PostalPostalCode nvarchar(10) not null, + LastEditedBy int not null, + ValidFrom datetime2(7) not null, + ValidTo datetime2(7) not null +) AS NODE; +GO + +-- to improve performance, disable default indexes and SET the recovery mode to bulk_logged +ALTER INDEX ALL ON Graph.Customers disable; +GO + +USE master; +GO + +ALTER DATABASE [WideWorldImporters-Standard] +SET recovery bulk_logged; +GO + +USE [WideWorldImporters-Standard]; +GO + +INSERT INTO Graph.Customers ( + CustomerID, + CustomerName, + BillToCustomerID, + CustomerCategoryID, + BuyingGroupID, + PrimaryContactPersonID, + AlternateContactPersonID, + DeliveryMethodID, + DeliveryCityID, + PostalCityID, + CreditLimit, + AccountOpenedDate, + StandardDiscountPercentage, + IsStatementSent, + IsOnCreditHold, + PaymentDays, + PhoneNumber, + FaxNumber, + DeliveryRun, + RunPosition, + WebsiteURL, + DeliveryAddressLine1, + DeliveryAddressLine2, + DeliveryPostalCode, + DeliveryLocation, + PostalAddressLine1, + PostalAddressLine2, + PostalPostalCode, + LastEditedBy, + ValidFrom, + ValidTo +) +SELECT + CustomerID, + CustomerName, + BillToCustomerID, + CustomerCategoryID, + BuyingGroupID, + PrimaryContactPersonID, + AlternateContactPersonID, + DeliveryMethodID, + DeliveryCityID, + PostalCityID, + CreditLimit, + AccountOpenedDate, + StandardDiscountPercentage, + IsStatementSent, + IsOnCreditHold, + PaymentDays, + PhoneNumber, + FaxNumber, + DeliveryRun, + RunPosition, + WebsiteURL, + DeliveryAddressLine1, + DeliveryAddressLine2, + DeliveryPostalCode, + DeliveryLocation, + PostalAddressLine1, + PostalAddressLine2, + PostalPostalCode, + LastEditedBy, + ValidFrom, + ValidTo +FROM OPENROWSET ( + bulk 'E:\Graph Examples\Graph.Customers.csv', formatfile = 'E:\Graph Examples\Graph.Customers_format.xml' +) as temp; + +USE master; +GO + +ALTER DATABASE [WideWorldImporters-Standard] +SET RECOVERY FULL; +GO + +USE [WideWorldImporters-Standard]; +GO + +ALTER INDEX ALL ON Graph.Customers rebuild; +GO + +SELECT * FROM Graph.Customers; +GO diff --git a/samples/features/sql-graph/populate_graph_tables.sql b/samples/features/sql-graph/populate_graph_tables.sql new file mode 100644 index 00000000..4e683113 --- /dev/null +++ b/samples/features/sql-graph/populate_graph_tables.sql @@ -0,0 +1,645 @@ +/* POPULATE NODE TABLES */ + +-- for performance purposes, disable default indexes on edge and node tables. + ALTER INDEX ALL ON Graph.Customers disable; + ALTER INDEX ALL ON Graph.Suppliers disable; + ALTER INDEX ALL ON Graph.StockItems disable; + + ALTER INDEX ALL ON Graph.InvoiceLines_CustomersToStockItems disable; + ALTER INDEX ALL ON Graph.InvoiceLines_StockItemsToCustomers disable; + ALTER INDEX ALL ON Graph.OrderLines_CustomersToStockItems disable; + ALTER INDEX ALL ON Graph.OrderLines_StockItemsToCustomers disable; + ALTER INDEX ALL ON Graph.PurchaseOrderLines_StockItemsToSuppliers disable; + ALTER INDEX ALL ON Graph.PurchaseOrderLines_SuppliersToStockItems disable; + GO + +-- populate node table Graph.Customers from Sales.Customers +INSERT INTO Graph.Customers ( + CustomerID, + CustomerName, + BillToCustomerID, + CustomerCategoryID, + BuyingGroupID, + PrimaryContactPersonID, + AlternateContactPersonID, + DeliveryMethodID, + DeliveryCityID, + PostalCityID, + CreditLimit, + AccountOpenedDate, + StandardDiscountPercentage, + IsStatementSent, + IsOnCreditHold, + PaymentDays, + PhoneNumber, + WebsiteURL, + DeliveryAddressLine1, + DeliveryAddressLine2, + DeliveryPostalCode, + DeliveryLocation, + PostalAddressLine1, + PostalAddressLine2, + PostalPostalCode, + LastEditedBy, + ValidFrom, + ValidTo +) SELECT + CustomerID, + CustomerName, + BillToCustomerID, + CustomerCategoryID, + BuyingGroupID, + PrimaryContactPersonID, + AlternateContactPersonID, + DeliveryMethodID, + DeliveryCityID, + PostalCityID, + CreditLimit, + AccountOpenedDate, + StandardDiscountPercentage, + IsStatementSent, + IsOnCreditHold, + PaymentDays, + PhoneNumber, + WebsiteURL, + DeliveryAddressLine1, + DeliveryAddressLine2, + DeliveryPostalCode, + DeliveryLocation, + PostalAddressLine1, + PostalAddressLine2, + PostalPostalCode, + LastEditedBy, + ValidFrom, + ValidTo +FROM Sales.Customers; + +-- populate node table Graph.StockItems from Warehouse.StockItems +INSERT INTO Graph.StockItems ( + StockItemID, + StockItemName, + SupplierID, + ColorID, + UnitPackageID, + OuterPackageID, + Size, + LeadTimeDays, + QuantityPerOuter, + IsChillerStock, + Barcode, + TaxRate, + UnitPrice, + RecommendedRetailPrice, + TypicalWeightPerUnit, + MarketingComments, + InternalComments, + Photo, + CustomFields, + Tags, + SearchDetails, + LastEditedBy, + ValidFrom, + ValidTo +) SELECT + StockItemID, + StockItemName, + SupplierID, + ColorID, + UnitPackageID, + OuterPackageID, + Size, + LeadTimeDays, + QuantityPerOuter, + IsChillerStock, + Barcode, + TaxRate, + UnitPrice, + RecommendedRetailPrice, + TypicalWeightPerUnit, + MarketingComments, + InternalComments, + Photo, + CustomFields, + Tags, + SearchDetails, + LastEditedBy, + ValidFrom, + ValidTo +FROM Warehouse.StockItems; + +-- populate node table Graph.Suppliers from Purchasing.Suppliers +INSERT INTO Graph.Suppliers ( + SupplierID, + SupplierName, + SupplierCategoryID, + PrimaryContactPersonID, + AlternateContactPersonID, + DeliveryMethodID, + DeliveryCityID, + PostalCityID, + SupplierReference, + BankAccountName, + BankAccountBranch, + BankAccountCode, + BankAccountNumber, + BankInternationalCode, + PaymentDays, + InternalComments, + PhoneNumber, + FaxNumber, + WebsiteURL, + DeliveryAddressLine1, + DeliveryAddressLine2, + DeliveryPostalCode, + DeliveryLocation, + PostalAddressLine1, + PostalAddressLine2, + PostalPostalCode, + LastEditedBy, + ValidFrom, + ValidTo +) SELECT + SupplierID, + SupplierName, + SupplierCategoryID, + PrimaryContactPersonID, + AlternateContactPersonID, + DeliveryMethodID, + DeliveryCityID, + PostalCityID, + SupplierReference, + BankAccountName, + BankAccountBranch, + BankAccountCode, + BankAccountNumber, + BankInternationalCode, + PaymentDays, + InternalComments, + PhoneNumber, + FaxNumber, + WebsiteURL, + DeliveryAddressLine1, + DeliveryAddressLine2, + DeliveryPostalCode, + DeliveryLocation, + PostalAddressLine1, + PostalAddressLine2, + PostalPostalCode, + LastEditedBy, + ValidFrom, + ValidTo +FROM Purchasing.Suppliers; + +go + + +/* POPULATE EDGE TABLES */ +-- populate edge table Graph.OrderLines_CustomersToStockItems from Sales.Orders and Sales.Orders +INSERT INTO Graph.OrderLines_CustomersToStockItems ( + $from_id, + $to_id, + + -- from Sales.Orders + OrderID, + CustomerID, + SalespersonPersonID, + PickedByPersonID, + ContactPersonID, + BackorderOrderID, + OrderDate, + ExpectedDeliveryDate, + CustomerPurchaseOrderNumber, + IsUndersupplyBackordered, + Comments, + DeliveryInstructions, + InternalComments, + + -- from Sales.OrderLines + StockItemID, + Description, + PackageTypeID, + Quantity, + UnitPrice, + TaxRate, + PickedQuantity, + PickingCompletedWhen, + LastEditedBy, + LastEditedWhen +) SELECT + a1.n1, + a2.n2, + + -- from Sales.Orders + Sales.Orders.OrderID, + Sales.Orders.CustomerID, + Sales.Orders.SalespersonPersonID, + Sales.Orders.PickedByPersonID, + Sales.Orders.ContactPersonID, + Sales.Orders.BackorderOrderID, + Sales.Orders.OrderDate, + Sales.Orders.ExpectedDeliveryDate, + Sales.Orders.CustomerPurchaseOrderNumber, + Sales.Orders.IsUndersupplyBackordered, + Sales.Orders.Comments, + Sales.Orders.DeliveryInstructions, + Sales.Orders.InternalComments, + + -- from Sales.OrderLines + Sales.OrderLines.StockItemID, + Sales.OrderLines.Description, + Sales.OrderLines.PackageTypeID, + Sales.OrderLines.Quantity, + Sales.OrderLines.UnitPrice, + Sales.OrderLines.TaxRate, + Sales.OrderLines.PickedQuantity, + Sales.OrderLines.PickingCompletedWhen, + Sales.OrderLines.LastEditedBy, + Sales.OrderLines.LastEditedWhen +FROM Sales.Orders join Sales.OrderLines ON Sales.Orders.OrderID = Sales.OrderLines.OrderID + join (SELECT $node_id AS n1, CustomerID FROM Graph.Customers) AS a1 ON a1.CustomerID = Sales.Orders.CustomerID + join (SELECT $node_id AS n2, StockItemID FROM Graph.StockItems) AS a2 ON a2.StockItemID = Sales.OrderLines.StockItemID; + +-- populate edge table Graph.OrderLines_StockItemsToCustomers from Sales.Orders and Sales.Orders +INSERT INTO Graph.OrderLines_StockItemsToCustomers ( + $from_id, + $to_id, + + -- from Sales.Orders + OrderID, + CustomerID, + SalespersonPersonID, + PickedByPersonID, + ContactPersonID, + BackorderOrderID, + OrderDate, + ExpectedDeliveryDate, + CustomerPurchaseOrderNumber, + IsUndersupplyBackordered, + Comments, + DeliveryInstructions, + InternalComments, + + -- from Sales.OrderLines + StockItemID, + Description, + PackageTypeID, + Quantity, + UnitPrice, + TaxRate, + PickedQuantity, + PickingCompletedWhen, + LastEditedBy, + LastEditedWhen +) SELECT + a1.n1, + a2.n2, + + -- from Sales.Orders + Sales.Orders.OrderID, + Sales.Orders.CustomerID, + Sales.Orders.SalespersonPersonID, + Sales.Orders.PickedByPersonID, + Sales.Orders.ContactPersonID, + Sales.Orders.BackorderOrderID, + Sales.Orders.OrderDate, + Sales.Orders.ExpectedDeliveryDate, + Sales.Orders.CustomerPurchaseOrderNumber, + Sales.Orders.IsUndersupplyBackordered, + Sales.Orders.Comments, + Sales.Orders.DeliveryInstructions, + Sales.Orders.InternalComments, + + -- from Sales.OrderLines + Sales.OrderLines.StockItemID, + Sales.OrderLines.Description, + Sales.OrderLines.PackageTypeID, + Sales.OrderLines.Quantity, + Sales.OrderLines.UnitPrice, + Sales.OrderLines.TaxRate, + Sales.OrderLines.PickedQuantity, + Sales.OrderLines.PickingCompletedWhen, + Sales.OrderLines.LastEditedBy, + Sales.OrderLines.LastEditedWhen +FROM Sales.Orders join Sales.OrderLines ON Sales.Orders.OrderID = Sales.OrderLines.OrderID + join (SELECT $node_id AS n1, StockItemID FROM Graph.StockItems) AS a1 ON a1.StockItemID = Sales.OrderLines.StockItemID + join (SELECT $node_id AS n2, CustomerID FROM Graph.Customers) AS a2 ON a2.CustomerID = Sales.Orders.CustomerID; + +-- populate edge table Graph.InvoiceLines_CustomersToStockItems from Sales.InvoiceLines and Sales.InvoiceLines +INSERT INTO Graph.InvoiceLines_CustomersToStockItems ( + $from_id, + $to_id, + + -- from Sales.Invoices + InvoiceID, + CustomerID, + BillToCustomerID, + OrderID, + DeliveryMethodID, + ContactPersonID, + AccountsPersonID, + SalespersonPersonID, + PackedByPersonID, + InvoiceDate, + CustomerPurchaseOrderNumber, + IsCreditNote, + CreditNoteReason, + Comments, + DeliveryInstructions, + InternalComments, + TotalDryItems, + TotalChillerItems, + DeliveryRun, + RunPosition, + ReturnedDeliveryData, + ConfirmedDeliveryTime, + ConfirmedReceivedBy, + + -- from Sales.InvoiceLines + InvoiceLineID, + StockItemID, + Description, + PackageTypeID, + Quantity, + UnitPrice, + TaxRate, + TaxAmount, + LineProfit, + ExtendedPrice, + LastEditedBy, + LastEditedWhen +) SELECT + a1.n1, + a2.n2, + + -- from Sales.Invoices + Sales.Invoices.InvoiceID, + Sales.Invoices.CustomerID, + Sales.Invoices.BillToCustomerID, + Sales.Invoices.OrderID, + Sales.Invoices.DeliveryMethodID, + Sales.Invoices.ContactPersonID, + Sales.Invoices.AccountsPersonID, + Sales.Invoices.SalespersonPersonID, + Sales.Invoices.PackedByPersonID, + Sales.Invoices.InvoiceDate, + Sales.Invoices.CustomerPurchaseOrderNumber, + Sales.Invoices.IsCreditNote, + Sales.Invoices.CreditNoteReason, + Sales.Invoices.Comments, + Sales.Invoices.DeliveryInstructions, + Sales.Invoices.InternalComments, + Sales.Invoices.TotalDryItems, + Sales.Invoices.TotalChillerItems, + Sales.Invoices.DeliveryRun, + Sales.Invoices.RunPosition, + Sales.Invoices.ReturnedDeliveryData, + Sales.Invoices.ConfirmedDeliveryTime, + Sales.Invoices.ConfirmedReceivedBy, + + -- from Sales.InvoiceLines + Sales.InvoiceLines.InvoiceLineID, + Sales.InvoiceLines.StockItemID, + Sales.InvoiceLines.Description, + Sales.InvoiceLines.PackageTypeID, + Sales.InvoiceLines.Quantity, + Sales.InvoiceLines.UnitPrice, + Sales.InvoiceLines.TaxRate, + Sales.InvoiceLines.TaxAmount, + Sales.InvoiceLines.LineProfit, + Sales.InvoiceLines.ExtendedPrice, + Sales.InvoiceLines.LastEditedBy, + Sales.InvoiceLines.LastEditedWhen +FROM Sales.Invoices join Sales.InvoiceLines ON Sales.Invoices.InvoiceID = Sales.InvoiceLines.InvoiceID + join (SELECT $node_id AS n1, CustomerID FROM Graph.Customers) AS a1 ON a1.CustomerID = Sales.Invoices.CustomerID + join (SELECT $node_id AS n2, StockItemID FROM Graph.StockItems) AS a2 ON a2.StockItemID = Sales.InvoiceLines.StockItemID; + +-- populate edge table Graph.InvoiceLines_StockItemsToCustomers from Sales.InvoiceLines and Sales.InvoiceLines +INSERT INTO Graph.InvoiceLines_StockItemsToCustomers ( + $from_id, + $to_id, + + -- from Sales.Invoices + InvoiceID, + CustomerID, + BillToCustomerID, + OrderID, + DeliveryMethodID, + ContactPersonID, + AccountsPersonID, + SalespersonPersonID, + PackedByPersonID, + InvoiceDate, + CustomerPurchaseOrderNumber, + IsCreditNote, + CreditNoteReason, + Comments, + DeliveryInstructions, + InternalComments, + TotalDryItems, + TotalChillerItems, + DeliveryRun, + RunPosition, + ReturnedDeliveryData, + ConfirmedDeliveryTime, + ConfirmedReceivedBy, + + -- from Sales.InvoiceLines + InvoiceLineID, + StockItemID, + Description, + PackageTypeID, + Quantity, + UnitPrice, + TaxRate, + TaxAmount, + LineProfit, + ExtendedPrice, + LastEditedBy, + LastEditedWhen +) SELECT + a1.n1, + a2.n2, + + -- from Sales.Invoices + Sales.Invoices.InvoiceID, + Sales.Invoices.CustomerID, + Sales.Invoices.BillToCustomerID, + Sales.Invoices.OrderID, + Sales.Invoices.DeliveryMethodID, + Sales.Invoices.ContactPersonID, + Sales.Invoices.AccountsPersonID, + Sales.Invoices.SalespersonPersonID, + Sales.Invoices.PackedByPersonID, + Sales.Invoices.InvoiceDate, + Sales.Invoices.CustomerPurchaseOrderNumber, + Sales.Invoices.IsCreditNote, + Sales.Invoices.CreditNoteReason, + Sales.Invoices.Comments, + Sales.Invoices.DeliveryInstructions, + Sales.Invoices.InternalComments, + Sales.Invoices.TotalDryItems, + Sales.Invoices.TotalChillerItems, + Sales.Invoices.DeliveryRun, + Sales.Invoices.RunPosition, + Sales.Invoices.ReturnedDeliveryData, + Sales.Invoices.ConfirmedDeliveryTime, + Sales.Invoices.ConfirmedReceivedBy, + + -- from Sales.InvoiceLines + Sales.InvoiceLines.InvoiceLineID, + Sales.InvoiceLines.StockItemID, + Sales.InvoiceLines.Description, + Sales.InvoiceLines.PackageTypeID, + Sales.InvoiceLines.Quantity, + Sales.InvoiceLines.UnitPrice, + Sales.InvoiceLines.TaxRate, + Sales.InvoiceLines.TaxAmount, + Sales.InvoiceLines.LineProfit, + Sales.InvoiceLines.ExtendedPrice, + Sales.InvoiceLines.LastEditedBy, + Sales.InvoiceLines.LastEditedWhen +FROM Sales.Invoices join Sales.InvoiceLines ON Sales.Invoices.InvoiceID = Sales.InvoiceLines.InvoiceID + join (SELECT $node_id AS n1, StockItemID FROM Graph.StockItems) AS a1 ON a1.StockItemID = Sales.InvoiceLines.StockItemID + join (SELECT $node_id AS n2, CustomerID FROM Graph.Customers) AS a2 ON a2.CustomerID = Sales.Invoices.CustomerID; + + +-- populate edge table Graph.PurchaseOrderLines_StockItemsToSuppliers from Purchasing.PurchaseOrders and Purchasing.PurchaseOrderLines +INSERT INTO Graph.PurchaseOrderLines_StockItemsToSuppliers ( + $from_id, + $to_id, + + -- from Purchasing.PurchaseOrders + PurchaseOrderID, + SupplierID, + OrderDate, + DeliveryMethodID, + ContactPersonID, + ExpectedDeliveryDate, + SupplierReference, + IsOrderFinalized, + Comments, + InternalComments, + + -- from Purchasing.PurchaseOrderLines + PurchaseOrderLineID, + StockItemID, + OrderedOuters, + Description, + ReceivedOuters, + PackageTypeID, + ExpectedUnitPricePerOuter, + LastReceiptDate, + IsOrderLineFinalized, + LastEditedBy, + LastEditedWhen +) SELECT + a1.n1, + a2.n2, + + -- from Purchasing.PurchaseOrders. + Purchasing.PurchaseOrders.PurchaseOrderID, + Purchasing.PurchaseOrders.SupplierID, + Purchasing.PurchaseOrders.OrderDate, + Purchasing.PurchaseOrders.DeliveryMethodID, + Purchasing.PurchaseOrders.ContactPersonID, + Purchasing.PurchaseOrders.ExpectedDeliveryDate, + Purchasing.PurchaseOrders.SupplierReference, + Purchasing.PurchaseOrders.IsOrderFinalized, + Purchasing.PurchaseOrders.Comments, + Purchasing.PurchaseOrders.InternalComments, + + -- from Purchasing.PurchaseOrderLines + Purchasing.PurchaseOrderLines.PurchaseOrderLineID, + Purchasing.PurchaseOrderLines.StockItemID, + Purchasing.PurchaseOrderLines.OrderedOuters, + Purchasing.PurchaseOrderLines.Description, + Purchasing.PurchaseOrderLines.ReceivedOuters, + Purchasing.PurchaseOrderLines.PackageTypeID, + Purchasing.PurchaseOrderLines.ExpectedUnitPricePerOuter, + Purchasing.PurchaseOrderLines.LastReceiptDate, + Purchasing.PurchaseOrderLines.IsOrderLineFinalized, + Purchasing.PurchaseOrderLines.LastEditedBy, + Purchasing.PurchaseOrderLines.LastEditedWhen +FROM Purchasing.PurchaseOrders join Purchasing.PurchaseOrderLines ON Purchasing.PurchaseOrders.PurchaseOrderID = Purchasing.PurchaseOrderLines.PurchaseOrderID + join (SELECT $node_id AS n1, StockItemID FROM Graph.StockItems) AS a1 ON a1.StockItemID = Purchasing.PurchaseOrderLines.StockItemID + join (SELECT $node_id AS n2, SupplierID FROM Graph.Suppliers) AS a2 ON a2.SupplierID = Purchasing.PurchaseOrders.SupplierID; + +-- populate edge table Graph.PurchaseOrderLines_SuppliersToStockItems from Purchasing.PurchaseOrders and Purchasing.PurchaseOrderLines +INSERT INTO Graph.PurchaseOrderLines_SuppliersToStockItems ( + $from_id, + $to_id, + + -- from Purchasing.PurchaseOrders + PurchaseOrderID, + SupplierID, + OrderDate, + DeliveryMethodID, + ContactPersonID, + ExpectedDeliveryDate, + SupplierReference, + IsOrderFinalized, + Comments, + InternalComments, + + -- from Purchasing.PurchaseOrderLines + PurchaseOrderLineID, + StockItemID, + OrderedOuters, + Description, + ReceivedOuters, + PackageTypeID, + ExpectedUnitPricePerOuter, + LastReceiptDate, + IsOrderLineFinalized, + LastEditedBy, + LastEditedWhen +) SELECT + a1.n1, + a2.n2, + + -- from Purchasing.PurchaseOrders. + Purchasing.PurchaseOrders.PurchaseOrderID, + Purchasing.PurchaseOrders.SupplierID, + Purchasing.PurchaseOrders.OrderDate, + Purchasing.PurchaseOrders.DeliveryMethodID, + Purchasing.PurchaseOrders.ContactPersonID, + Purchasing.PurchaseOrders.ExpectedDeliveryDate, + Purchasing.PurchaseOrders.SupplierReference, + Purchasing.PurchaseOrders.IsOrderFinalized, + Purchasing.PurchaseOrders.Comments, + Purchasing.PurchaseOrders.InternalComments, + + -- from Purchasing.PurchaseOrderLines + Purchasing.PurchaseOrderLines.PurchaseOrderLineID, + Purchasing.PurchaseOrderLines.StockItemID, + Purchasing.PurchaseOrderLines.OrderedOuters, + Purchasing.PurchaseOrderLines.Description, + Purchasing.PurchaseOrderLines.ReceivedOuters, + Purchasing.PurchaseOrderLines.PackageTypeID, + Purchasing.PurchaseOrderLines.ExpectedUnitPricePerOuter, + Purchasing.PurchaseOrderLines.LastReceiptDate, + Purchasing.PurchaseOrderLines.IsOrderLineFinalized, + Purchasing.PurchaseOrderLines.LastEditedBy, + Purchasing.PurchaseOrderLines.LastEditedWhen +FROM Purchasing.PurchaseOrders join Purchasing.PurchaseOrderLines ON Purchasing.PurchaseOrders.PurchaseOrderID = Purchasing.PurchaseOrderLines.PurchaseOrderID + join (SELECT $node_id AS n1, SupplierID FROM Graph.Suppliers) AS a1 ON a1.SupplierID = Purchasing.PurchaseOrders.SupplierID + join (SELECT $node_id AS n2, StockItemID FROM Graph.StockItems) AS a2 ON a2.StockItemID = Purchasing.PurchaseOrderLines.StockItemID; + +GO + +/* +Rebuild default indexes on node table. We advise against rebuilding default indexes on edge tables unless you eant to create a global view of all edge tables. +Add nonclustered indexes +*/ +ALTER INDEX ALL ON Graph.Customers rebuild; +ALTER INDEX ALL ON Graph.Suppliers rebuild; +ALTER INDEX ALL ON Graph.StockItems rebuild; +GO + +CREATE INDEX IX_InvoiceLines_CustomersToStockItems ON Graph.InvoiceLines_CustomersToStockItems ($from_id, $to_id); +CREATE INDEX IX_InvoiceLines_StockItemsToCustomers ON Graph.InvoiceLines_StockItemsToCustomers ($from_id, $to_id); +CREATE INDEX IX_OrderLines_CustomersToStockItems ON Graph.OrderLines_CustomersToStockItems ($from_id, $to_id); +CREATE INDEX IX_OrderLines_StockItemsToCustomers ON Graph.OrderLines_StockItemsToCustomers ($from_id, $to_id); +CREATE INDEX IX_PurchaseOrderLines_StockItemsToSuppliers ON Graph.PurchaseOrderLines_StockItemsToSuppliers ($from_id, $to_id); +CREATE INDEX IX_PurchaseOrderLines_SuppliersToStockItems ON Graph.PurchaseOrderLines_SuppliersToStockItems ($from_id, $to_id); +GO diff --git a/samples/features/sql-graph/top_10_buyers.sql b/samples/features/sql-graph/top_10_buyers.sql new file mode 100644 index 00000000..4ef64fbb --- /dev/null +++ b/samples/features/sql-graph/top_10_buyers.sql @@ -0,0 +1,25 @@ +/* +Find the top 10 buyers who purchased a specific item ordered by how much they spent +Using graph tables +Using regular tables +*/ + +-- using graph tables +SELECT top (10) sum(OrderLines_StockItemsToCustomers.UnitPrice * OrderLines_StockItemsToCustomers.Quantity) AS TotalSpendingOnItem, CustomerName, Customers.CustomerID +FROM Graph.Customers, Graph.OrderLines_StockItemsToCustomers, Graph.StockItems +WHERE MATCH (StockItems - (OrderLines_StockItemsToCustomers) -> Customers) + and StockItems.StockItemName = 'Chocolate frogs 250g' +GROUP BY Customers.CustomerID, Customers.CustomerName +ORDER BY TotalSpendingOnItem DESC, Customers.CustomerName ; +go + +-- using regular tables +SELECT top (10) sum(q2.UnitPrice * q2.Quantity) AS TotalSpendingOnItem, q4.CustomerName, q4.CustomerID +FROM (SELECT StockItemID, StockItemName FROM Warehouse.StockItems) AS q1 + join (SELECT StockItemID, OrderID, Quantity, UnitPrice FROM Sales.OrderLines) AS q2 ON q1.StockItemID = q2.StockItemID + join (SELECT OrderID, CustomerID FROM Sales.Orders) AS q3 ON q2.OrderID = q3.OrderID + join (SELECT CustomerID, CustomerName FROM Sales.Customers) AS q4 ON q3.CustomerID = q4.CustomerID +WHERE q1.StockItemName = 'Chocolate frogs 250g' +GROUP BY q4.CustomerID, q4.CustomerName +ORDER BY TotalSpendingOnItem DESC, q4.CustomerName ; +go