diff --git a/cmd/deltadb/delta.svg b/cmd/deltadb/delta.svg
index 9a889d5af..fc306b246 100644
--- a/cmd/deltadb/delta.svg
+++ b/cmd/deltadb/delta.svg
@@ -56,7 +56,7 @@
*
-
+
model
model
@@ -256,8 +256,96 @@
-
+
+citation
+
+citation
+
+🔑
+
+citation_id
+
+ℕ
+
+*
+
+
+
+key
+
+ⓐ
+
+*
+
+
+
+author
+
+ⓐ
+
+*
+
+
+
+year
+
+ℝ
+
+*
+
+
+
+title
+
+ⓐ
+
+*
+
+
+
+published
+
+ⓐ
+
+
+
+
+volume
+
+ⓐ
+
+
+
+
+pages
+
+ⓐ
+
+
+
+
+doi
+
+ⓐ
+
+
+
+
+link
+
+ⓐ
+
+
+
+
+retrieved
+
+ⓐ
+
+
+
+
component
component
@@ -354,7 +442,7 @@
-
+
datum
datum
@@ -376,7 +464,7 @@
*
-
+
feature
feature
@@ -443,7 +531,7 @@
*
-
+
site
site
@@ -543,7 +631,7 @@
-
+
firmware
firmware
@@ -603,7 +691,7 @@
-
+
foundation_type
foundation_type
@@ -625,7 +713,7 @@
*
-
+
geology
geology
@@ -647,7 +735,7 @@
*
-
+
make
make
@@ -669,7 +757,7 @@
*
-
+
mark
mark
@@ -759,7 +847,7 @@
-
+
mark_network
mark_network
@@ -795,7 +883,7 @@
-
+
network
network
@@ -847,7 +935,7 @@
-
+
mark_type
mark_type
@@ -869,26 +957,26 @@
*
-
+
method
-
-method
-
-🔑
-
-method_id
-
-ℕ
-
-*
-
-
-
-method
-
-ⓐ
-
-*
+
+method
+
+🔑
+
+method_id
+
+ℕ
+
+*
+
+
+
+method
+
+ⓐ
+
+*
@@ -897,7 +985,7 @@
-
+
monument
monument
@@ -1027,7 +1115,7 @@
-
+
monument_type
monument_type
@@ -1055,7 +1143,7 @@
-
+
point
point
@@ -1155,7 +1243,7 @@
-
+
sample
sample
@@ -1258,7 +1346,7 @@
-
+
station
station
@@ -1356,7 +1444,7 @@
-
+
station_network
station_network
@@ -1398,7 +1486,7 @@
-
+
visibility
visibility
diff --git a/meta/sqlite/asset.go b/meta/sqlite/asset.go
new file mode 100644
index 000000000..358e617e1
--- /dev/null
+++ b/meta/sqlite/asset.go
@@ -0,0 +1,195 @@
+package sqlite
+
+import (
+ "fmt"
+)
+
+const makeCreate = `
+DROP TABLE IF EXISTS make;
+CREATE TABLE IF NOT EXISTS make (
+ make_id INTEGER PRIMARY KEY NOT NULL,
+ make TEXT NOT NULL,
+ UNIQUE (make)
+);`
+
+var mmake = Table{
+ Create: makeCreate,
+ Select: func() string {
+ return "SELECT make_id FROM make WHERE make = ?"
+ },
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO make (make) VALUES (?);"
+ },
+
+ Fields: []string{"Make"},
+}
+
+const modelCreate = `
+DROP TABLE IF EXISTS model;
+CREATE TABLE IF NOT EXISTS model (
+ model_id INTEGER PRIMARY KEY NOT NULL,
+ make_id INTEGER NOT NULL,
+ model TEXT NOT NULL,
+ FOREIGN KEY (make_id) REFERENCES make (make_id),
+ UNIQUE (make_id, model)
+);`
+
+var model = Table{
+ Create: modelCreate,
+ Select: func() string {
+ return fmt.Sprintf("SELECT model_id FROM model WHERE make_id = (%s) AND model = ?", mmake.Select())
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO model (make_id, model) VALUES ((%s), ?);", mmake.Select())
+ },
+ Fields: []string{"Make", "Model"},
+}
+
+const assetCreate = `
+DROP TABLE IF EXISTS asset;
+CREATE TABLE IF NOT EXISTS asset (
+ asset_id INTEGER PRIMARY KEY NOT NULL,
+ model_id INTEGER NOT NULL,
+ serial TEXT NOT NULL,
+ number TEXT DEFAULT "" NOT NULL,
+ notes TEXT DEFAULT "" NOT NULL,
+ FOREIGN KEY (model_id) REFERENCES model (model_id),
+ UNIQUE (model_id,serial)
+);`
+
+var asset = Table{
+ Create: assetCreate,
+ Select: func() string {
+ return fmt.Sprintf("SELECT asset_id FROM asset WHERE model_id = (%s) AND serial = ?", model.Select())
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO asset (model_id, serial, number, notes) VALUES ((%s), ?, ?, ?);", model.Select())
+ },
+ Fields: []string{"Make", "Model", "Serial", "Number", "Notes"},
+}
+
+const firmwareCreate = `
+DROP TABLE IF EXISTS firmware;
+CREATE TABLE IF NOT EXISTS firmware (
+ firmware_id INTEGER PRIMARY KEY NOT NULL,
+ asset_id INTEGER NOT NULL,
+ version TEXT NOT NULL,
+ notes TEXT NOT NULL,
+ start_date DATETIME NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date DATETIME NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ FOREIGN KEY (asset_id) REFERENCES asset (asset_id),
+ UNIQUE (asset_id, start_date, end_date)
+);
+CREATE TRIGGER IF NOT EXISTS no_overlap_on_firmware BEFORE INSERT ON firmware
+WHEN EXISTS (
+ SELECT * FROM firmware
+ WHERE datetime(start_date) <= datetime(NEW.end_date)
+ AND datetime(end_date) > datetime(NEW.start_date)
+ AND asset_id = NEW.asset_id
+)
+BEGIN
+ SELECT RAISE(FAIL, "overlapping intervals on firmware");
+END;
+`
+
+var firmware = Table{
+ Create: firmwareCreate,
+ Select: func() string {
+ return fmt.Sprintf("SELECT firmware_id FROM firmware WHERE asset_id = (%s) AND start_date = ? AND end_date = ?",
+ asset.Select())
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO firmware (asset_id, version, notes, start_date, end_date) VALUES ((%s), ?, ?, ?, ?);",
+ asset.Select())
+ },
+ Fields: []string{"Make", "Model", "Serial", "Version", "Notes", "Start Date", "End Date"},
+}
+
+const channelCreate = `
+DROP TABLE IF EXISTS channel;
+CREATE TABLE IF NOT EXISTS channel (
+ channel_id INTEGER PRIMARY KEY NOT NULL,
+ model_id INTEGER NOT NULL,
+ channel_type TEXT NOT NULL,
+ number REAL DEFAULT 0 NOT NULL,
+ sampling_rate REAL NOT NULL,
+ response TEXT DEFAULT "" NOT NULL,
+ FOREIGN KEY (model_id) REFERENCES model (model_id),
+ UNIQUE(model_id, channel_type, number, sampling_rate)
+);
+`
+
+var channel = Table{
+ Create: channelCreate,
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO channel (model_id, channel_type, number, sampling_rate, response) VALUES ((%s), ?, ?, ?, ?);",
+ model.Select())
+ },
+ Fields: []string{"Make", "Model", "Type", "Number", "SamplingRate", "Response"},
+}
+
+const componentCreate = `
+DROP TABLE IF EXISTS component;
+CREATE TABLE IF NOT EXISTS component (
+ component_id INTEGER PRIMARY KEY NOT NULL,
+ model_id INTEGER NOT NULL,
+ component_type TEXT NULL,
+ number REAL NOT NULL,
+ source TEXT NULL,
+ subsource TEXT NOT NULL,
+ dip REAL NOT NULL,
+ azimuth REAL NOT NULL,
+ types TEXT NOT NULL,
+ sampling_rate REAL NULL,
+ response TEXT NOT NULL,
+ FOREIGN KEY (model_id) REFERENCES model (model_id),
+ UNIQUE(model_id, number, source, subsource, sampling_rate)
+);
+`
+
+var component = Table{
+ Create: componentCreate,
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO component (model_id, component_type, number, source, subsource, dip, azimuth, types, sampling_rate, response) VALUES ((%s), ?, ?, ?, ?, ?, ?, ?, ?, ?);",
+ model.Select())
+ },
+ Fields: []string{"Make", "Model", "Type", "Number", "Source", "Subsource", "Dip", "Azimuth", "Types", "Sampling Rate", "Response"},
+}
+
+const calibrationCreate = `
+DROP TABLE IF EXISTS calibration;
+CREATE TABLE IF NOT EXISTS calibration (
+ calibration_id INTEGER PRIMARY KEY NOT NULL,
+ asset_id INTEGER NOT NULL,
+ number TEXT NOT NULL,
+ scale_factor REAL DEFAULT 1.0 NOT NULL,
+ scale_bias REAL DEFAULT 0.0 NOT NULL,
+ scale_absolute REAL DEFAULT 0.0 NOT NULL,
+ frequency REAL NULL,
+ start_date DATETIME NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date DATETIME NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ FOREIGN KEY (asset_id) REFERENCES asset (asset_id),
+ UNIQUE(asset_id, number, start_date, end_date)
+);
+CREATE TRIGGER IF NOT EXISTS no_overlap_on_calibration BEFORE INSERT ON calibration
+WHEN EXISTS (
+ SELECT * FROM calibration
+ WHERE datetime(start_date) <= datetime(NEW.end_date)
+ AND datetime(end_date) > datetime(NEW.start_date)
+ AND asset_id = NEW.asset_id
+ AND number = NEW.number
+)
+BEGIN
+ SELECT RAISE(FAIL, "overlapping intervals on calibration");
+END;
+`
+
+var calibration = Table{
+ Create: calibrationCreate,
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO calibration (asset_id, number, scale_factor, scale_bias, scale_absolute, frequency, start_date, end_date) VALUES ((%s), ?, ?, ?, ?, ?, ?, ?);",
+ asset.Select(),
+ )
+ },
+ Fields: []string{"Make", "Model", "Serial", "Number", "Scale Factor", "Scale Bias", "Scale Absolute", "Frequency", "Start Date", "End Date"},
+}
diff --git a/meta/sqlite/db.go b/meta/sqlite/db.go
index bfd9843ca..663a18186 100644
--- a/meta/sqlite/db.go
+++ b/meta/sqlite/db.go
@@ -80,15 +80,20 @@ func (d DB) Init(ctx context.Context, list []meta.TableList) error {
for _, l := range list {
switch l.Table.Name() {
- /*
- case "Placename":
- if err := d.exec(ctx, tx, placenameCreate); err != nil {
- return err
- }
- if err := d.prepare(ctx, tx, placenameInsert(), columns(l, placenameFields(), nil, "")...); err != nil {
- return err
- }
- */
+ case "Placename":
+ if err := d.exec(ctx, tx, placename.Create); err != nil {
+ return err
+ }
+ if err := d.prepare(ctx, tx, placename.Insert(), placename.Columns(l)...); err != nil {
+ return err
+ }
+ case "Citation":
+ if err := d.exec(ctx, tx, citation.Create); err != nil {
+ return err
+ }
+ if err := d.prepare(ctx, tx, citation.Insert(), citation.Columns(l)...); err != nil {
+ return err
+ }
case "Asset":
if err := d.exec(ctx, tx, makeCreate); err != nil {
return err
@@ -411,13 +416,6 @@ func (d DB) Init(ctx context.Context, list []meta.TableList) error {
if err := d.prepare(ctx, tx, connectionInsert(), columns(l, connectionFields(), nil, "")...); err != nil {
return err
}
- case "Citation":
- if err := d.exec(ctx, tx, citationCreate); err != nil {
- return err
- }
- if err := d.prepare(ctx, tx, citationInsert(), columns(l, citationFields(), nil, "")...); err != nil {
- return err
- }
case "Gauge":
if err := d.exec(ctx, tx, gaugeCreate); err != nil {
return err
diff --git a/meta/sqlite/mark.go b/meta/sqlite/mark.go
index 9b8245f9e..ca001cbd3 100644
--- a/meta/sqlite/mark.go
+++ b/meta/sqlite/mark.go
@@ -1,58 +1,228 @@
package sqlite
import (
- "context"
- "database/sql"
-
- "github.com/GeoNet/delta/meta"
+ "fmt"
)
-func Marks(ctx context.Context, db *sql.DB, opts ...QueryOpt) ([]meta.Mark, error) {
-
- query := `SELECT Code,Network,Igs,Name,Latitude,Longitude,Elevation,Datum,Start,End FROM Mark`
- if len(opts) > 0 {
- query += " WHERE "
- }
- for n, opt := range opts {
- if n > 0 {
- query += " AND "
- }
- query += opt.K(n)
- }
- query += ";"
-
- stmt, err := db.PrepareContext(ctx, query)
- if err != nil {
- return nil, err
- }
- defer stmt.Close()
-
- var args []any
- for _, opt := range opts {
- args = append(args, opt.V())
- }
- results, err := stmt.QueryContext(ctx, args...)
- if err != nil {
- return nil, err
- }
- defer results.Close()
-
- marks := make([]meta.Mark, 0)
- for results.Next() {
- var mark meta.Mark
- var igs string
- if err := results.Scan(&mark.Code, &mark.Network, &igs, &mark.Name, &mark.Latitude, &mark.Longitude, &mark.Elevation, &mark.Datum, &mark.Start, &mark.End); err != nil {
- return nil, err
- }
- if b, ok := ParseBool(igs); ok {
- mark.Igs = b
- }
- marks = append(marks, mark)
- }
-
- if err = results.Err(); err != nil {
- return nil, err
- }
-
- return marks, nil
+const bedrockCreate = `
+DROP TABLE IF EXISTS bedrock;
+CREATE TABLE IF NOT EXISTS bedrock (
+ bedrock_id INTEGER PRIMARY KEY NOT NULL,
+ bedrock TEXT NOT NULL,
+ UNIQUE (bedrock)
+);`
+
+var bedrock = Table{
+ Create: bedrockCreate,
+ Select: func() string {
+ return "SELECT bedrock_id FROM bedrock WHERE bedrock = ?"
+ },
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO bedrock (bedrock) VALUES (?);"
+ },
+ Fields: []string{"Bedrock"},
+}
+
+const markTypeCreate = `
+DROP TABLE IF EXISTS mark_type;
+CREATE TABLE IF NOT EXISTS mark_type (
+ mark_type_id INTEGER PRIMARY KEY NOT NULL,
+ mark_type TEXT NOT NULL,
+ UNIQUE (mark_type)
+);`
+
+var markType = Table{
+ Create: markTypeCreate,
+ Select: func() string {
+ return "SELECT mark_type_id FROM mark_type WHERE mark_type = ?"
+ },
+
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO mark_type (mark_type) VALUES (?);"
+ },
+
+ Fields: []string{"Mark Type"},
+}
+
+const monumentTypeCreate = `
+DROP TABLE IF EXISTS monument_type;
+CREATE TABLE IF NOT EXISTS monument_type (
+ monument_type_id INTEGER PRIMARY KEY NOT NULL,
+ monument_type TEXT NOT NULL,
+ UNIQUE (monument_type)
+);`
+
+var monumentType = Table{
+ Create: monumentTypeCreate,
+ Select: func() string {
+ return "SELECT monument_type_id FROM monument_type WHERE monument_type = ?"
+ },
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO monument_type (monument_type) VALUES (?);"
+ },
+ Fields: []string{"Type"},
+}
+
+const foundationTypeCreate = `
+DROP TABLE IF EXISTS foundation_type;
+CREATE TABLE IF NOT EXISTS foundation_type (
+ foundation_type_id INTEGER PRIMARY KEY NOT NULL,
+ foundation_type TEXT NOT NULL,
+ UNIQUE (foundation_type)
+);`
+
+var foundationType = Table{
+ Create: foundationTypeCreate,
+ Select: func() string {
+ return "SELECT foundation_type_id FROM foundation_type WHERE foundation_type = ?"
+ },
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO foundation_type (foundation_type) VALUES (?);"
+ },
+ Fields: []string{"Foundation Type"},
+}
+
+const geologyCreate = `
+DROP TABLE IF EXISTS geology;
+CREATE TABLE IF NOT EXISTS geology (
+ geology_id INTEGER PRIMARY KEY NOT NULL,
+ geology TEXT NOT NULL,
+ UNIQUE (geology)
+);`
+
+var geology = Table{
+ Create: geologyCreate,
+ Select: func() string {
+ return "SELECT geology_id FROM geology WHERE geology = ?"
+ },
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO geology (geology) VALUES (?);"
+ },
+ Fields: []string{"Geology"},
+}
+
+const markCreate = `
+DROP TABLE IF EXISTS mark;
+CREATE TABLE IF NOT EXISTS mark (
+ mark_id INTEGER PRIMARY KEY NOT NULL,
+ datum_id INTEGER NOT NULL,
+ mark TEXT NOT NULL,
+ igs BOOLEAN NOT NULL,
+ name TEXT NOT NULL,
+ latitude REAL NOT NULL,
+ longitude REAL NOT NULL,
+ elevation REAL DEFAULT 0 NOT NULL,
+ start_date NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ FOREIGN KEY (datum_id) REFERENCES datum (datum_id),
+ UNIQUE (mark)
+);`
+
+var mark = Table{
+ Create: markCreate,
+ Select: func() string {
+ return "SELECT mark_id FROM mark WHERE mark = ?"
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO mark (datum_id, mark, igs, name, latitude, longitude, elevation, start_date, end_date) VALUES ((%s), ?, ?, ?, ?, ?, ?, ?, ?);",
+ datum.Select(),
+ )
+ },
+
+ Fields: []string{"Datum", "Mark", "Igs", "Name", "Latitude", "Longitude", "Elevation", "Start Date", "End Date"},
+}
+
+const markNetworkCreate = `
+DROP TABLE IF EXISTS mark_network;
+CREATE TABLE IF NOT EXISTS mark_network (
+ mark_network_id INTEGER PRIMARY KEY NOT NULL,
+ mark_id INTEGER NOT NULL,
+ network_id INTEGER NOT NULL,
+ FOREIGN KEY (mark_id) REFERENCES mark (mark_id),
+ FOREIGN KEY (network_id) REFERENCES network (network_id),
+ UNIQUE (mark_id, network_id)
+);`
+
+var markNetwork = Table{
+ Create: markNetworkCreate,
+ Select: func() string {
+ return fmt.Sprintf("SELECT mark_network_id FROM mark_network WHERE mark_id = (%s) AND network_id = (%s)",
+ mark.Select(), network.Select(),
+ )
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO mark_network (mark_id, network_id) VALUES ((%s), (%s));",
+ mark.Select(), network.Select(),
+ )
+ },
+ Fields: []string{"Mark", "Network"},
+}
+
+func markNetworkNotNulls() []string {
+ return []string{"Mark", "Network"}
+}
+
+const monumentCreate = `
+DROP TABLE IF EXISTS monument;
+CREATE TABLE IF NOT EXISTS monument (
+ monument_id INTEGER PRIMARY KEY NOT NULL,
+ mark_id INTEGER NOT NULL,
+ mark_type_id INTEGER NOT NULL,
+ monument_type_id INTEGER NOT NULL,
+ foundation_type_id INTEGER NOT NULL,
+ bedrock_id INTEGER NOT NULL,
+ geology_id INTEGER NOT NULL,
+ domes_number TEXT NOT NULL,
+ ground_relationship REAL NOT NULL,
+ foundation_depth REAL NOT NULL,
+ start_date NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ FOREIGN KEY (mark_id) REFERENCES mark (mark_id),
+ FOREIGN KEY (mark_type_id) REFERENCES mark_type (mark_type_id),
+ FOREIGN KEY (monument_type_id) REFERENCES monument_type (monument_type_id),
+ FOREIGN KEY (foundation_type_id) REFERENCES foundation_type (foundation_type_id),
+ FOREIGN KEY (bedrock_id) REFERENCES bedrock (bedrock_id),
+ FOREIGN KEY (geology_id) REFERENCES geology (geology_id),
+ UNIQUE (mark_id)
+);`
+
+var monument = Table{
+ Create: monumentCreate,
+ Select: func() string {
+ return fmt.Sprintf("SELECT monument_id FROM monument WHERE mark_id = (%s)", mark.Select())
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO monument (mark_id, mark_type_id, monument_type_id, foundation_type_id, bedrock_id, geology_id, domes_number, ground_relationship, foundation_depth, start_date, end_date) VALUES ((%s), (%s), (%s), (%s), (%s), (%s), ?, ?, ?, ?, ?);",
+ mark.Select(), markType.Select(), monumentType.Select(), foundationType.Select(), bedrock.Select(), geology.Select(),
+ )
+ },
+ Fields: []string{"Mark", "Mark Type", "Type", "Foundation Type", "Bedrock", "Geology", "Domes Number", "Ground Relationship", "Foundation Depth", "Start Date", "End Date"},
+}
+
+const visibilityCreate = `
+DROP TABLE IF EXISTS visibility;
+CREATE TABLE IF NOT EXISTS visibility (
+ visibility_id INTEGER PRIMARY KEY NOT NULL,
+ mark_id INTEGER NOT NULL,
+ sky_visibility TEXT NOT NULL,
+ start_date DATETIME NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date DATETIME NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ FOREIGN KEY (mark_id) REFERENCES mark (mark_id),
+ UNIQUE(mark_id, sky_visibility, start_date, end_date)
+);
+`
+
+var visibility = Table{
+ Create: visibilityCreate,
+ Select: func() string {
+ return fmt.Sprintf("SELECT visibility_id FROM visibility WHERE mark_id = (%s) AND start_date = ? AND end_date = ?",
+ mark.Select(),
+ )
+ },
+ Insert: func() string {
+ return fmt.Sprintf("INSERT OR IGNORE INTO visibility (mark_id, sky_visibility, start_date, end_date) VALUES ((%s), ?, ?, ?);",
+ mark.Select(),
+ )
+ },
+ Fields: []string{"Mark", "Sky Visibility", "Start Date", "End Date"},
}
diff --git a/meta/sqlite/reference.go b/meta/sqlite/reference.go
new file mode 100644
index 000000000..fb0f33e46
--- /dev/null
+++ b/meta/sqlite/reference.go
@@ -0,0 +1,50 @@
+package sqlite
+
+const placenameCreate = `
+DROP TABLE IF EXISTS placename;
+CREATE TABLE IF NOT EXISTS placename (
+ placename_id INTEGER PRIMARY KEY NOT NULL,
+ name TEXT NOT NULL,
+ latitude REAL NOT NULL,
+ longitude REAL NOT NULL,
+ level REAL NOT NULL,
+ UNIQUE(name)
+);
+`
+
+var placename = Table{
+ Create: placenameCreate,
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO placename (name, latitude, longitude, level) VALUES (?, ?, ?, ?);"
+ },
+ Fields: []string{"Name", "Latitude", "Longitude", "Level"},
+}
+
+const citationCreate = `
+DROP TABLE IF EXISTS citation;
+CREATE TABLE IF NOT EXISTS citation (
+ citation_id INTEGER PRIMARY KEY NOT NULL,
+ key TEXT NOT NULL,
+ author TEXT NOT NULL,
+ year REAL NOT NULL,
+ title TEXT NOT NULL,
+ published TEXT NULL,
+ volume TEXT NULL,
+ pages TEXT NULL,
+ doi TEXT NULL,
+ link TEXT NULL,
+ retrieved TEXT NULL,
+ UNIQUE(key)
+);
+`
+
+var citation = Table{
+ Create: citationCreate,
+ Select: func() string {
+ return "SELECT citation_id FROM citation WHERE key = ?"
+ },
+ Insert: func() string {
+ return "INSERT OR IGNORE INTO citation (key, author, year, title, published, volume, pages, doi, link, retrieved) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?);"
+ },
+ Fields: []string{"Key", "Author", "Year", "Title", "Published", "Volume", "Pages", "DOI", "Link", "Retrieved"},
+}
diff --git a/meta/sqlite/station.go b/meta/sqlite/station.go
index c7c2e0539..eb9bfcd39 100644
--- a/meta/sqlite/station.go
+++ b/meta/sqlite/station.go
@@ -75,8 +75,8 @@ CREATE TABLE IF NOT EXISTS station (
longitude REAL NOT NULL,
elevation REAL DEFAULT 0 NOT NULL,
depth REAL DEFAULT 0 NOT NULL,
- start_date NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
- end_date NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ start_date DATETIME NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date DATETIME NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
FOREIGN KEY (datum_id) REFERENCES datum (datum_id),
UNIQUE (station)
);`
@@ -128,8 +128,8 @@ CREATE TABLE IF NOT EXISTS site (
elevation REAL DEFAULT 0 NOT NULL,
depth REAL DEFAULT 0 NOT NULL,
survey TEXT DEFAULT "Unknown" NOT NULL,
- start_date NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
- end_date NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ start_date DATETIME NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date DATETIME NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
FOREIGN KEY (station_id) REFERENCES station (station_id),
FOREIGN KEY (datum_id) REFERENCES datum (datum_id),
UNIQUE (station_id, location)
@@ -211,16 +211,16 @@ CREATE TABLE IF NOT EXISTS point (
elevation REAL DEFAULT 0 NOT NULL,
depth REAL DEFAULT 0 NOT NULL,
survey TEXT DEFAULT "Unknown" NOT NULL,
- start_date NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
- end_date NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
+ start_date DATETIME NOT NULL CHECK (start_date IS strftime('%Y-%m-%dT%H:%M:%SZ', start_date)),
+ end_date DATETIME NOT NULL CHECK (end_date IS strftime('%Y-%m-%dT%H:%M:%SZ', end_date)),
FOREIGN KEY (sample_id) REFERENCES sample (sample_id),
FOREIGN KEY (datum_id) REFERENCES datum (datum_id),
UNIQUE (sample_id, location)
);
-CREATE TRIGGER IF NOT EXISTS site_too_soon BEFORE INSERT ON point
+CREATE TRIGGER IF NOT EXISTS point_too_soon BEFORE INSERT ON point
WHEN NEW.start_date < (SELECT sample.start_date FROM sample WHERE sample.sample_id = new.sample_id)
BEGIN
- SELECT RAISE(FAIL, "site too soon for sample");
+ SELECT RAISE(FAIL, "point too soon for sample");
END;
CREATE TRIGGER IF NOT EXISTS site_too_late BEFORE INSERT ON point
WHEN NEW.end_date > (SELECT sample.end_date FROM sample WHERE sample.sample_id = new.sample_id)
diff --git a/network/stations.csv b/network/stations.csv
index 66a6ea76a..b682a52b6 100644
--- a/network/stations.csv
+++ b/network/stations.csv
@@ -593,7 +593,7 @@ AICS,SM,Aickens,-42.768185088,171.624357133,268,,WGS84,2003-08-18T00:00:00Z,2008
AIRO,XX,Airedale,-45.00131,170.91063,262,,WGS84,2014-09-18T00:00:00Z,2015-04-15T02:00:00Z
AKCZ,SI,Akaroa Harbour,-43.8721,172.90983,374.2,,WGS84,2012-03-01T00:00:00Z,9999-01-01T00:00:00Z
AKFZ,RA,Atkinson Farm,-36.605669,174.522439,94,,WGS84,2023-03-21T02:06:00Z,9999-01-01T00:00:00Z
-AKLS,SM,Auckland University,-36.85365,174.76983,70,,WGA84,2023-06-23T01:07:00Z,9999-01-01T00:00:00Z
+AKLS,SM,Auckland University,-36.85365,174.76983,70,,WGS84,2023-06-23T01:07:00Z,9999-01-01T00:00:00Z
AKSS,SM,Akaroa School,-43.81091,172.96349,13,,WGS84,2011-08-25T00:00:00Z,2020-07-06T22:21:00Z
AKUS,SM,Auckland University School of Engineering,-36.853158207,174.770451257,50,,WGS84,2002-06-19T00:00:00Z,2017-02-16T01:00:00Z
ALLC,XX,Allen Road,-38.416928536,175.473483976,575,,WGS84,2001-02-13T16:17:00Z,2001-07-07T18:55:00Z
@@ -1537,7 +1537,7 @@ NZD,TD,Offshore Bay of Plenty Kermadec,-36.0998,178.6037,0,2445,WGS84,2021-07-23
NZE,TD,Offshore East Cape Kermadec,-36.049,-177.708,0,5779,WGS84,2019-12-18T17:00:00Z,9999-01-01T00:00:00Z
NZF,TD,Offshore Raoul Island Kermadec,-29.6826,-175.0125,0,5060,WGS84,2019-12-17T00:00:00Z,9999-01-01T00:00:00Z
NZG,TD,Offshore Tongatapu Tonga,-23.3517,-173.4018,0,5741,WGS84,2020-09-10T00:00:00Z,9999-01-01T00:00:00Z
-NZH,TD,Offshore Niue Tonga,-20.0885,-171.8630,0,5531,WGS84,2020-09-04T00:00:00Z,9999-01-01T00:00:00Z
+NZH,TD,Offshore Niue Tonga,-20.0885,-171.8630,0,5531,WGS84,2020-09-03T22:24:30Z,9999-01-01T00:00:00Z
NZI,TD,Offshore Samoa Tonga,-16.8890,-171.1905,0,5237,WGS84,2020-09-08T00:00:00Z,9999-01-01T00:00:00Z
NZJ,TD,Offshore Norfolk Island New Hebrides,-26.6672,163.9549,0,1912,WGS84,2021-07-09T00:00:00Z,9999-01-01T00:00:00Z
NZK,TD,Offshore New Caledonia New Hebrides,-24.3093,169.4988,0,2098,WGS84,2021-07-15T00:00:00Z,9999-01-01T00:00:00Z
@@ -1967,7 +1967,7 @@ TOK,OE,Tokyo,-35.684741727,139.758118639,21,,WGS84,1875-06-01T00:00:00Z,9999-01-
TOKS,SM,Te Oka Bay Road SW Banks Peninsula,-43.82243,172.78084,577,,WGS84,2013-03-19T00:00:00Z,9999-01-01T00:00:00Z
TON,NZ,Tongariro,-39.201044242,175.538181851,1120,,WGS84,1945-10-01T00:00:00Z,1966-04-23T00:00:00Z
TON1,XX,Tongariro 1,-39.1319,175.6153,1491,,NZGD2000,2012-07-20T00:00:00Z,2013-06-07T00:00:00Z
-TON2,XX,Tongariro 2,-39.10857758,175.6731,1521,,WGS84,2012-07-20T21:30:00Z,2012-10-12T00:00:00Z
+TON2,XX,Tongariro 2,-39.10857758,175.6731,1521,,WGS84,2012-07-20T21:30:00Z,2012-11-21T00:00:00Z
TON3,XX,Tongariro 3,-39.1357,175.7106,1236,,WGS84,2012-07-20T00:00:00Z,2013-06-07T00:00:00Z
TON4,XX,Tongariro 4,-39.0779,175.6762,836,,NZGD2000,2012-04-20T00:00:00Z,2013-06-07T00:00:00Z
TON7,XX,Tongariro 7,-39.1283,175.6548,1727,,WGS84,2012-08-22T00:00:00Z,2013-06-07T00:00:00Z