138 lines
4.8 KiB
SQL
138 lines
4.8 KiB
SQL
-- Attach a new database with the specified name
|
|
ATTACH DATABASE 'food.db' AS food;
|
|
ATTACH DATABASE 'import.db' AS src;
|
|
-- ATTACH DATABASE 'food10k.db.orig' AS src;
|
|
ATTACH DATABASE ':memory:' AS cache;
|
|
-- ATTACH DATABASE 'memory.db' AS cache;
|
|
|
|
SELECT time(), "Creating tables and temporary tables.";
|
|
|
|
CREATE TABLE IF NOT EXISTS food.product (
|
|
id INTEGER PRIMARY KEY,
|
|
_id TEXT,
|
|
name TEXT,
|
|
created_t INTEGER,
|
|
last_modified_t INTEGER,
|
|
countries TEXT,
|
|
creator_id INTEGER,
|
|
brand_owner_id INTEGER,
|
|
nutrition_grades
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS food.creator (
|
|
creator_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
creator TEXT
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS cache.creator (
|
|
creator_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
creator TEXT
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS food.brand_owner (
|
|
brand_owner_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
brand_owner TEXT
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS food.product_nutriment_temp (
|
|
product_id INTEGER,
|
|
nutriment_key TEXT,
|
|
nutriment_value ANY
|
|
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS food.product_nutriment (
|
|
product_id INTEGER,
|
|
nutriment_id INTEGER,
|
|
nutriment_value ANY
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS food.nutriment (
|
|
nutriment_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
nutriment TEXT
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS cache.brand_owner (
|
|
brand_owner_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
brand_owner TEXT
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS cache.product (
|
|
id INTEGER PRIMARY KEY,
|
|
_id TEXT,
|
|
name TEXT,
|
|
created_t INTEGER,
|
|
last_modified_t INTEGER,
|
|
countries TEXT,
|
|
creator TEXT,
|
|
brand_owner TEXT,
|
|
nutrition_grades
|
|
);
|
|
|
|
SELECT time(), "Reading and caching base data.";
|
|
|
|
INSERT INTO cache.product (id, _id, name, created_t, last_modified_t, countries, creator, brand_owner, nutrition_grades) SELECT ID,
|
|
json_extract(data, '$._id'), json_extract(data, '$.product_name'),
|
|
json_extract(data, '$.created_t'), json_extract(data, '$.last_modified_t'),
|
|
json_extract(data, '$.countries'), json_extract(data, '$.creator'), json_extract(data, '$.brand_owner'),
|
|
json_extract(data, '$.nutrition_grades')
|
|
from foodraw;
|
|
|
|
|
|
SELECT time(), "Inserting cached data into creator table.";
|
|
|
|
INSERT INTO food.creator (creator )SELECT DISTINCT creator from cache.product ORDER BY creator;
|
|
INSERT INTO cache.creator (creator )SELECT DISTINCT creator from cache.product ORDER BY creator;
|
|
|
|
SELECT time(), "Inserting cached data into brand_owner table.";
|
|
|
|
INSERT INTO food.brand_owner (brand_owner )SELECT DISTINCT brand_owner from cache.product ORDER BY brand_owner;
|
|
INSERT INTO cache.brand_owner (brand_owner )SELECT DISTINCT brand_owner from cache.product ORDER BY brand_owner;
|
|
|
|
|
|
SELECT time(), "Inserting cached data into product table.";
|
|
|
|
INSERT INTO food.product (id, _id, name, created_t, last_modified_t, countries, creator_id, brand_owner_id, nutrition_grades)
|
|
SELECT id, _id, name, created_t, last_modified_t, countries, creator.creator_id as creator_id, brand_owner.brand_owner_id as brand_owner_id, nutrition_grades
|
|
FROM cache.product
|
|
LEFT JOIN cache.creator on cache.product.creator = cache.creator.creator
|
|
LEFT JOIN cache.brand_owner on cache.product.brand_owner = cache.brand_owner.brand_owner
|
|
where cache.product.name is not null and cache.product.name != "";
|
|
|
|
CREATE VIEW food.product_view as
|
|
SELECT id, _id, name, created_t, last_modified_t, countries, nutrition_grades, brand_owner.brand_owner, creator.creator FROM product
|
|
LEFT JOIN brand_owner on product.brand_owner_id = brand_owner.brand_owner_id
|
|
LEFT JOIN creator on product.creator_id = creator.creator_id
|
|
;
|
|
|
|
SELECT time(), "Reading nutriments and writing product_nutriment_temp table.";
|
|
|
|
INSERT INTO food.product_nutriment_temp ( product_id, nutriment_key, nutriment_value) select foodraw.id, key, value
|
|
from foodraw, json_each( data ->> '$.nutriments' );
|
|
|
|
INSERT INTO food.nutriment (nutriment) SELECT DISTINCT nutriment_key from food.product_nutriment_temp order by nutriment_key;
|
|
|
|
SELECT time(), "Writing product_nutriment table.";
|
|
|
|
INSERT INTO food.product_nutriment (product_id, nutriment_id, nutriment_value)
|
|
SELECT product_id, nutriment_id, nutriment_value from product_nutriment_temp JOIN nutriment on product_nutriment_temp.nutriment_key = nutriment.nutriment
|
|
WHERE nutriment_value != ""
|
|
;
|
|
|
|
CREATE VIEW food.nutriment_view as
|
|
SELECT product_id, nutriment, nutriment_value from product_nutriment NATURAL JOIN nutriment;
|
|
|
|
DROP TABLE food.product_nutriment_temp;
|
|
|
|
CREATE INDEX product_nutriment_product_product_id on product_nutriment(product_id);
|
|
CREATE INDEX product_nutriment_product_nutriment_id on product_nutriment(nutriment_id);
|
|
CREATE INDEX product_creator_id on product(creator_id);
|
|
CREATE INDEX product_brandowner_id on product(brand_owner_id);
|
|
CREATE INDEX product_name on product(name);
|
|
|
|
|
|
|
|
DETACH DATABASE food;
|
|
DETACH DATABASE src;
|
|
DETACH DATABASE cache;
|