Voc Tutorial

VOC The MonetDB/SQL tutorial is based on the material published in the book J.R. Bruijn, F.S. Gaastra and I. Schaar, Dutch-Asiatic Shipping in the 17th and 18th Centuries, which gives an account of the trips made to the East and ships returned safely (or wrecked on the way). A total of 8000 records are provided. They include information about ship name and type, captain, the arrival/departure of harbors along the route, personnel accounts, and anecdotal information.

Get going quickly on Linux involves starting the MonetDB Daemon. It runs in the background and facilitates, amongst others, management of local/remote servers. The daemon is controlled by the application monetdb. See its documentation for all details.

The monetdbd is not available on Windows, but for these systems a default database called demo is made ready by default see.

Here we demonstrate a simple session involving creation of a database, loading data, and querying.

shell> monetdbd create /path/to/mydbfarm
shell> monetdbd start /path/to/mydbfarm
shell> monetdb create voc
shell> monetdb release voc
shell> mclient -u monetdb -d voc
password:<monetdb>
Welcome to mclient, the MonetDB/SQL interactive terminal (Oct2014-SP1)
Database: MonetDB v11.19.7 (Oct2014-SP1), 'mapi:monetdb://localhost:50000/voc'
Type \q to quit, \? for a list of available commands
auto commit mode: on

sql> SELECT 'hello world';
+---------------+
| single_value  |
+===============+
| hello world   |
+---------------+
1 tuple (0.530ms)

sql> \q

The command \q or end-of-file signal terminates the connection with the server. Exploring the wealth of functionality offered by MonetDB/SQL is best started using a toy database. For this we use the VOC database which provides a peephole view into the administrative system of an early multi-national company, the Vereenigde geoctrooieerde Oostindische Compagnie (VOC for short - The (Dutch) East Indian Company) established on March 20, 1602. Download the VOC dataset voc_dump.zip (543K) gz (543K) bz2 (372K) which is a compressed file with SQL statements. After the file has been extracted, load its contents into MonetDB using mclient. Before you load the VOC data set, it is advised to introduce a user different from the omnipresent default monetdb. The new user is given his own schema for the MonetDB database. Assuming you have started MonetDB with SQL module, proceed as follows:

shell> mclient -u monetdb -d voc
password:<monetdb>

sql> CREATE USER "voc" WITH PASSWORD 'voc' NAME 'VOC Explorer' SCHEMA "sys";
sql> CREATE SCHEMA "voc" AUTHORIZATION "voc";
sql> ALTER USER "voc" SET SCHEMA "voc";

sql> \q

To illustrate the use of the newly created account and schema, the following example connects and creates a table, which is dropped afterwards by aborting the transaction.

shell> mclient -u voc -d voc
password:<voc>

sql> START TRANSACTION;
auto commit mode: off

sql> CREATE TABLE test (id int, data varchar(30));
operation successful (0.722ms)

sql> \d
TABLE voc.test

sql> \d test
CREATE TABLE "voc"."test" (
    "id"   INTEGER,
    "data" VARCHAR(30)
);
sql> CREATE TABLE "voc"."test" ("id" int, "data" varchar(30));
sql> ROLLBACK;
auto commit mode: on

sql> \d

Importing the voc_dump.sql file into the database can be done using the textual client interface. Some alternative ways are as follows:

1: shell> mclient -u voc -d voc voc_dump.sql
password:<voc>
2: shell> mclient -u voc -d voc < voc_dump.sql
password:<voc>
3: shell> mclient -u voc -d voc
password:<voc>
sql> \< /full/path/to/voc_dump.sql

The VOC data set contains data for around 8000 voyages.

sql> \d
TABLE  voc.craftsmen
TABLE  voc.impotenten
TABLE  voc.invoices
TABLE  voc.passengers
TABLE  voc.seafarers
TABLE  voc.soldiers
TABLE  voc.total
TABLE  voc.voyages

Let's check out the data we just loaded. First, count the number of rows the voyages table.

sql> SELECT count(*) FROM voyages;
+------+
| L1   |
+======+
| 8131 |
+------+

The set consists of 8 tables, which are all bound to each other using FOREIGN KEY relationships. The voyages table is the main table, which all others refer to. Every table, except invoices has a PRIMARY KEY defined over the columns number and number_sup. Since the invoices table holds zero or more invoices per voyage (identified by number, number_sub) a PRIMARY KEY constraint is not possible. The tables craftsmen, impotenten, passengers, seafarers, and soldiers all share the same columns. We can define a VIEW that combines them all into one big table, to make them easier to access.

sql> CREATE VIEW onboard_people AS
     SELECT * FROM (
     SELECT 'craftsmen' AS type, craftsmen.* FROM craftsmen
     UNION ALL
     SELECT 'impotenten' AS type, impotenten.* FROM impotenten
     UNION ALL
     SELECT 'passengers' AS type, passengers.* FROM passengers
     UNION ALL
     SELECT 'seafarers' AS type, seafarers.* FROM seafarers
     UNION ALL
     SELECT 'soldiers' AS type, soldiers.* FROM soldiers
     UNION ALL
     SELECT 'total' AS type, total.* FROM total
     ) AS onboard_people_table;

The new view will show up and we can just use it as a normal table, to for instance calculate the number of records for each group of people:

sql> \d
TABLE  voc.craftsmen
TABLE  voc.impotenten
TABLE  voc.invoices
VIEW   voc.onboard_people
TABLE  voc.passengers
TABLE  voc.seafarers
TABLE  voc.soldiers
TABLE  voc.total
TABLE  voc.voyages

sql> SELECT type, COUNT(*) AS total
     FROM onboard_people GROUP BY type ORDER BY type;
+------------+-------+
| type       | total |
+============+=======+
| craftsmen  |  2349 |
| impotenten |   938 |
| passengers |  2813 |
| seafarers  |  4468 |
| soldiers   |  4177 |
| total      |  2467 |
+------------+-------+

Let's see how many impotenten we have in the dataset:

sql> SELECT count(*) FROM impotenten;
+------+
| L1   |
+======+
|  938 |
+------+

It is possible to play with the set in many ways, to find out several things that took place during the voyages of the ships, or the money that was earned. A few examples are shown below:

sql> SELECT COUNT(*) FROM voyages
     WHERE particulars LIKE '%_recked%';
+------+
| L1   |
+======+
|  358 |
+------+

sql> SELECT chamber, CAST(AVG(invoice) AS integer) AS average
     FROM invoices
     WHERE invoice IS NOT NULL
     GROUP BY chamber
     ORDER BY average DESC;
+---------+---------+
| chamber | average |
+=========+=========+
| A | 282996 |
| Z | 259300 |
| H | 150182 |
| R | 149628 |
| D | 149522 |
| E | 149518 |
| null | 83309 |
+---------+---------+

sql> CREATE VIEW extended_onboard AS
     SELECT number, number_sup, trip, trip_sup,
      onboard_at_departure, death_at_cape,
      left_at_cape, onboard_at_cape,
      death_during_voyage, onboard_at_arrival,
      death_during_voyage - left_at_cape AS death_at_arrival
     FROM onboard_people;

sql> \d
TABLE  voc.craftsmen
VIEW   voc.extended_onboard
TABLE  voc.impotenten
TABLE  voc.invoices
VIEW   voc.onboard_people
TABLE  voc.passengers
TABLE  voc.seafarers
TABLE  voc.soldiers
TABLE  voc.total
TABLE  voc.voyages