Skip to content

Commit 56c75b3

Browse files
authored
Fixed Table Creation Issues
Reordered Table Creation to cater to Foreign Key declarations etc..
1 parent 975b6dc commit 56c75b3

File tree

1 file changed

+273
-16
lines changed

1 file changed

+273
-16
lines changed

Diff for: bulk-loading-northwind-csv.sql

+273-16
Original file line numberDiff line numberDiff line change
@@ -24,6 +24,7 @@ DROP TABLE "csv_bl"."Northwind"."suppliers" ;
2424
DROP TABLE "csv_bl"."Northwind"."employee_territories" ;
2525
DROP TABLE "csv_bl"."Northwind"."territories";
2626
DROP TABLE "csv_bl"."Northwind"."employees" ;
27+
DROP TABLE "csv_bl"."Northwind"."manager" ;
2728
DROP TABLE "csv_bl"."Northwind"."regions" ;
2829
DROP TABLE "csv_bl"."Northwind"."shippers" ;
2930

@@ -52,7 +53,7 @@ CSV_REGISTER('../vad', 'territories.csv') ;
5253

5354
-- Check that DB.DBA.csv_load_list table contains CSV documents to loaded
5455

55-
SELECT * FROM "DB"."DBA"."csv_load_list" ;
56+
SELECT TOP 5 * FROM "DB"."DBA"."csv_load_list" ;
5657

5758

5859
-- Run CSV Bulk Loader
@@ -64,21 +65,30 @@ CSV_LOADER_RUN () ;
6465

6566
SELECT * FROM "DB"."DBA"."csv_load_list" ;
6667

68+
-- Make Manager Table from Query against Employees Table
6769

70+
CREATE TABLE "csv_bl"."Northwind"."manager"
71+
AS SELECT DISTINCT *
72+
FROM "csv_bl"."Northwind"."employees" WHERE "reportsTo" IS NOT NULL WITH DATA ;
73+
6874
-- Confirm Tables have been successfully created by CSV Bulk Loader
6975

70-
SELECT * FROM "csv_bl"."Northwind"."categories" ;
71-
SELECT * FROM "csv_bl"."Northwind"."customers" ;
72-
SELECT * FROM "csv_bl"."Northwind"."employees" ;
73-
SELECT * FROM "csv_bl"."Northwind"."employee_territories" ;
74-
SELECT * FROM "csv_bl"."Northwind"."order_details" ;
75-
SELECT * FROM "csv_bl"."Northwind"."orders" ;
76-
SELECT * FROM "csv_bl"."Northwind"."products" ;
77-
SELECT * FROM "csv_bl"."Northwind"."regions" ;
78-
SELECT * FROM "csv_bl"."Northwind"."shippers" ;
79-
SELECT * FROM "csv_bl"."Northwind"."suppliers" ;
80-
SELECT * FROM "csv_bl"."Northwind"."territories" ;
76+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."categories" ;
77+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."customers" ;
78+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."manager" ;
79+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."employees" ;
80+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."employee_territories" ;
81+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."order_details" ;
82+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."orders" ;
83+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."products" ;
84+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."regions" ;
85+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."shippers" ;
86+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."suppliers" ;
87+
SELECT TOP 5 * FROM "csv_bl"."Northwind"."territories" ;
88+
8189

90+
91+
8292
-- ADD Foreign Keys to each table.
8393
-- Works on the assumption of Northwind CSV files in ~virtuoso/vad directory (folder) .
8494

@@ -98,25 +108,38 @@ SELECT TOP 5 * FROM "csv_bl"."Northwind"."customers" ;
98108

99109

100110

111+
-- MANAGERS Table
112+
113+
ALTER TABLE "csv_bl"."Northwind"."manager"
114+
MODIFY PRIMARY KEY ("employeeID", "reportsTo") ;
115+
116+
101117
-- ALTER EMPLOYEES TABLE
102118

103119

104120
ALTER TABLE "csv_bl"."Northwind"."employees"
105121
MODIFY PRIMARY KEY ("employeeID") ;
106122

107-
ALTER TABLE "csv_bl"."Northwind"."employees"
108-
ADD FOREIGN KEY ("employeeID") REFERENCES "csv_bl"."Northwind"."employees" ("employeeID") ;
109-
123+
-- ALTER TABLE "csv_bl"."Northwind"."employees"
124+
-- ADD FOREIGN KEY ("employeeID") REFERENCES "csv_bl"."Northwind"."employees" ("employeeID") ;
125+
126+
ALTER TABLE "csv_bl"."Northwind"."employees"
127+
-- ADD FOREIGN KEY ("employeeID","reportsTo") REFERENCES "csv_bl"."Northwind"."manager" ("employeeID","reportsTo");
128+
ADD FOREIGN KEY ("employeeID","reportsTo") REFERENCES "csv_bl"."Northwind"."manager" ("employeeID","reportsTo");
129+
110130
SELECT TOP 5 * FROM "csv_bl"."Northwind"."employees" ;
111131

112132

133+
134+
113135
-- ALTER EMPLOYEE TERRITORIES TABLE
114136

115137
ALTER TABLE "csv_bl"."Northwind"."employee_territories"
116138
MODIFY PRIMARY KEY ("employeeID","territoryID");
117139

118140
ALTER TABLE "csv_bl"."Northwind"."employee_territories"
119-
ADD FOREIGN KEY ("employeeID") REFERENCES "csv_bl"."Northwind"."employees" ("employeeID") ;
141+
ADD FOREIGN KEY ("employeeID") REFERENCES "csv_bl"."Northwind"."employees" ("employeeID") ;
142+
120143

121144
SELECT TOP 5 * FROM "csv_bl"."Northwind"."employee_territories" ;
122145

@@ -199,3 +222,237 @@ ALTER TABLE "csv_bl"."Northwind"."regions"
199222
SELECT TOP 5 * FROM "csv_bl"."Northwind"."territories" ;
200223

201224

225+
-- Test Queries
226+
-- Works
227+
228+
SPARQL
229+
230+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
231+
232+
SELECT DISTINCT *
233+
FROM <http://demo.openlinksw.com/csv_bl#>
234+
WHERE {
235+
?s northwind:has_manager ?o .
236+
}
237+
;
238+
239+
240+
-- Fails when storage is Virtual only
241+
242+
SPARQL
243+
244+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
245+
246+
SELECT DISTINCT *
247+
# FROM <http://demo.openlinksw.com/csv_bl#>
248+
WHERE {
249+
?s northwind:has_manager ?o .
250+
}
251+
252+
;
253+
254+
-- Works due to existence of Physical Graphs
255+
256+
SPARQL
257+
258+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
259+
260+
SELECT DISTINCT *
261+
# FROM <http://demo.openlinksw.com/csv_bl#>
262+
# FROM <urn:demo.openlinksw.com:csv_bl>
263+
WHERE {
264+
?s northwind:has_manager ?o .
265+
}
266+
;
267+
268+
-- Sanity Checks
269+
270+
-- SQL
271+
272+
select DISTINCT B.employeeid, A.reportsTo
273+
from "csv_bl"."Northwind"."employees" A
274+
inner join "csv_bl"."Northwind"."employees" B on A.reportsTo = B.reportsTo
275+
order by 2 desc
276+
277+
-- SPARQL
278+
279+
SPARQL
280+
281+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
282+
283+
SELECT DISTINCT *
284+
# FROM <http://demo.openlinksw.com/csv_bl#>
285+
# FROM <urn:demo.openlinksw.com:csv_bl>
286+
WHERE {
287+
?s northwind:firstname ?name ;
288+
northwind:lastname ?lastName ;
289+
northwind:manager_of ?o.
290+
?o northwind:firstname ?mgrName ;
291+
northwind:lastname ?mgrlastName .
292+
}
293+
;
294+
295+
-- Total Orders by Employee
296+
297+
SPARQL
298+
299+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
300+
301+
SELECT ?employee ?name sum((?quantity * ?unitprice * (1 - ?discount))) as ?orderTotalByEmp
302+
# FROM <urn:demo.openlinksw.com:Demo>
303+
WHERE
304+
{
305+
?employee a northwind:employees ;
306+
northwind:firstname ?firstname ;
307+
northwind:lastname ?lastname ;
308+
BIND (concat(?firstname,' ', ?lastname) as ?name) .
309+
310+
?order northwind:has_employees ?employee .
311+
?order northwind:orders_of ?order_details.
312+
?order_details northwind:quantity ?quantity ;
313+
northwind:unitprice ?unitprice ;
314+
northwind:discount ?discount .
315+
}
316+
GROUP BY ?employee ?name
317+
ORDER BY desc(?orderTotalByEmp)
318+
319+
;
320+
321+
-- Total Sales by Employee Product
322+
323+
SPARQL
324+
325+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
326+
327+
SELECT ?employee ?name ?productName sum((?quantity * ?unitprice * (1 - ?discount))) as ?orderTotalByEmp
328+
# FROM <urn:demo.openlinksw.com:Demo>
329+
WHERE
330+
{
331+
?employee a northwind:employees ;
332+
northwind:firstname ?firstname ;
333+
northwind:lastname ?lastname .
334+
BIND (concat(?firstname,' ', ?lastname) as ?name) .
335+
336+
?order northwind:has_employees ?employee .
337+
?order northwind:orders_of ?order_details.
338+
?order_details northwind:quantity ?quantity ;
339+
northwind:unitprice ?unitprice ;
340+
northwind:discount ?discount ;
341+
northwind:has_products ?product .
342+
?product northwind:productname ?productName .
343+
344+
}
345+
;
346+
347+
348+
-- Employees associated with Product Orders that have "Chai" in product name
349+
350+
SPARQL
351+
352+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
353+
354+
SELECT DISTINCT *
355+
WHERE
356+
{
357+
?employee northwind:employees_of / northwind:orders_of / northwind:has_products ?o .
358+
?o northwind:productname ?name .
359+
?name bif:contains "Chai" .
360+
}
361+
;
362+
363+
-- Employees (using Property Paths) associated with Cross Product Orders that have "Chai" in product name
364+
365+
SPARQL
366+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
367+
368+
SELECT ?employee ?name count(?o2) AS ?count
369+
WHERE
370+
{
371+
{
372+
?employee northwind:employees_of / northwind:orders_of / northwind:has_products ?o .
373+
?o northwind:productname ?name .
374+
?name bif:contains "Chai" .
375+
}
376+
377+
{
378+
?employee2 northwind:employees_of / northwind:orders_of / northwind:has_products ?o2 .
379+
?o2 northwind:productname ?name2 .
380+
381+
}
382+
FILTER (?employee = ?employee2)
383+
}
384+
;
385+
386+
387+
-- SPARQL (using BI) Employees associated with Cross Product Orders that have "Chai" in product name
388+
389+
SPARQL
390+
391+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
392+
393+
SELECT ?employee ?o+>northwind:productname AS ?productName count(?o2+>northwind:productname) AS ?totalProductSalesCount
394+
WHERE
395+
{
396+
{
397+
?employee+>northwind:employees_of+>northwind:orders_of northwind:has_products ?o .
398+
?o northwind:productname ?name .
399+
?name bif:contains "Chai" .
400+
}
401+
402+
{
403+
?employee2+>northwind:employees_of+>northwind:orders_of northwind:has_products ?o2 .
404+
?o2 northwind:productname ?name2 .
405+
406+
}
407+
FILTER (?employee = ?employee2)
408+
}
409+
410+
ORDER BY DESC 3
411+
;
412+
413+
414+
-- Employees Orders Totals using Property Paths
415+
416+
417+
SPARQL
418+
419+
420+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
421+
422+
SELECT DISTINCT ?employee2 ?orderid ?unitprice ?quantity ?discount ((?unitprice * ?quantity) - ?discount) as ?total
423+
{
424+
?employee2 northwind:employees_of / northwind:orders_of / northwind:has_products ?o2 ;
425+
northwind:employees_of / northwind:orders_of / northwind:unitprice ?unitprice ;
426+
northwind:employees_of / northwind:orders_of / northwind:quantity ?quantity ;
427+
northwind:employees_of / northwind:orders_of / northwind:discount ?discount ;
428+
northwind:employees_of / northwind:orders_of / northwind:orderid ?orderid .
429+
?o2 northwind:productname ?name2 .
430+
431+
}
432+
;
433+
434+
435+
-- Employee and Cross Tab of "Chai" and other Products Ordered
436+
437+
SPARQL
438+
439+
PREFIX northwind: <http://demo.openlinksw.com/schemas/csv_bl/>
440+
441+
SELECT DISTINCT ?employee ?employee2 ?o ?name ?o2 ?name2
442+
WHERE
443+
{
444+
{
445+
?employee northwind:employees_of / northwind:orders_of / northwind:has_products ?o .
446+
?o northwind:productname ?name .
447+
?name bif:contains "Chai" .
448+
}
449+
450+
{
451+
?employee2 northwind:employees_of / northwind:orders_of / northwind:has_products ?o2 .
452+
?o2 northwind:productname ?name2 .
453+
filter not exists { ?o2 northwind:productname ?name2 . ?name2 bif:contains "Chai" } .
454+
}
455+
456+
FILTER ( ?employee = ?employee2)
457+
}
458+
;

0 commit comments

Comments
 (0)