Update schemas and reset scripts
This commit is contained in:
@@ -1,150 +1,154 @@
|
||||
-- Configuration tables schema
|
||||
|
||||
-- Stock threshold configurations
|
||||
CREATE TABLE IF NOT EXISTS stock_thresholds (
|
||||
id INT NOT NULL,
|
||||
CREATE TABLE stock_thresholds (
|
||||
id INTEGER NOT NULL,
|
||||
category_id BIGINT, -- NULL means default/global threshold
|
||||
vendor VARCHAR(100), -- NULL means applies to all vendors
|
||||
critical_days INT NOT NULL DEFAULT 7,
|
||||
reorder_days INT NOT NULL DEFAULT 14,
|
||||
overstock_days INT NOT NULL DEFAULT 90,
|
||||
low_stock_threshold INT NOT NULL DEFAULT 5,
|
||||
min_reorder_quantity INT NOT NULL DEFAULT 1,
|
||||
critical_days INTEGER NOT NULL DEFAULT 7,
|
||||
reorder_days INTEGER NOT NULL DEFAULT 14,
|
||||
overstock_days INTEGER NOT NULL DEFAULT 90,
|
||||
low_stock_threshold INTEGER NOT NULL DEFAULT 5,
|
||||
min_reorder_quantity INTEGER NOT NULL DEFAULT 1,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
UNIQUE KEY unique_category_vendor (category_id, vendor),
|
||||
INDEX idx_st_metrics (category_id, vendor)
|
||||
UNIQUE (category_id, vendor)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_st_metrics ON stock_thresholds(category_id, vendor);
|
||||
|
||||
-- Lead time threshold configurations
|
||||
CREATE TABLE IF NOT EXISTS lead_time_thresholds (
|
||||
id INT NOT NULL,
|
||||
CREATE TABLE lead_time_thresholds (
|
||||
id INTEGER NOT NULL,
|
||||
category_id BIGINT, -- NULL means default/global threshold
|
||||
vendor VARCHAR(100), -- NULL means applies to all vendors
|
||||
target_days INT NOT NULL DEFAULT 14,
|
||||
warning_days INT NOT NULL DEFAULT 21,
|
||||
critical_days INT NOT NULL DEFAULT 30,
|
||||
target_days INTEGER NOT NULL DEFAULT 14,
|
||||
warning_days INTEGER NOT NULL DEFAULT 21,
|
||||
critical_days INTEGER NOT NULL DEFAULT 30,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
UNIQUE KEY unique_category_vendor (category_id, vendor)
|
||||
UNIQUE (category_id, vendor)
|
||||
);
|
||||
|
||||
-- Sales velocity window configurations
|
||||
CREATE TABLE IF NOT EXISTS sales_velocity_config (
|
||||
id INT NOT NULL,
|
||||
CREATE TABLE sales_velocity_config (
|
||||
id INTEGER NOT NULL,
|
||||
category_id BIGINT, -- NULL means default/global threshold
|
||||
vendor VARCHAR(100), -- NULL means applies to all vendors
|
||||
daily_window_days INT NOT NULL DEFAULT 30,
|
||||
weekly_window_days INT NOT NULL DEFAULT 7,
|
||||
monthly_window_days INT NOT NULL DEFAULT 90,
|
||||
daily_window_days INTEGER NOT NULL DEFAULT 30,
|
||||
weekly_window_days INTEGER NOT NULL DEFAULT 7,
|
||||
monthly_window_days INTEGER NOT NULL DEFAULT 90,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
UNIQUE KEY unique_category_vendor (category_id, vendor),
|
||||
INDEX idx_sv_metrics (category_id, vendor)
|
||||
UNIQUE (category_id, vendor)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sv_metrics ON sales_velocity_config(category_id, vendor);
|
||||
|
||||
-- ABC Classification configurations
|
||||
CREATE TABLE IF NOT EXISTS abc_classification_config (
|
||||
id INT NOT NULL PRIMARY KEY,
|
||||
CREATE TABLE abc_classification_config (
|
||||
id INTEGER NOT NULL PRIMARY KEY,
|
||||
a_threshold DECIMAL(5,2) NOT NULL DEFAULT 20.0,
|
||||
b_threshold DECIMAL(5,2) NOT NULL DEFAULT 50.0,
|
||||
classification_period_days INT NOT NULL DEFAULT 90,
|
||||
classification_period_days INTEGER NOT NULL DEFAULT 90,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Safety stock configurations
|
||||
CREATE TABLE IF NOT EXISTS safety_stock_config (
|
||||
id INT NOT NULL,
|
||||
CREATE TABLE safety_stock_config (
|
||||
id INTEGER NOT NULL,
|
||||
category_id BIGINT, -- NULL means default/global threshold
|
||||
vendor VARCHAR(100), -- NULL means applies to all vendors
|
||||
coverage_days INT NOT NULL DEFAULT 14,
|
||||
coverage_days INTEGER NOT NULL DEFAULT 14,
|
||||
service_level DECIMAL(5,2) NOT NULL DEFAULT 95.0,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
UNIQUE KEY unique_category_vendor (category_id, vendor),
|
||||
INDEX idx_ss_metrics (category_id, vendor)
|
||||
UNIQUE (category_id, vendor)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_ss_metrics ON safety_stock_config(category_id, vendor);
|
||||
|
||||
-- Turnover rate configurations
|
||||
CREATE TABLE IF NOT EXISTS turnover_config (
|
||||
id INT NOT NULL,
|
||||
CREATE TABLE turnover_config (
|
||||
id INTEGER NOT NULL,
|
||||
category_id BIGINT, -- NULL means default/global threshold
|
||||
vendor VARCHAR(100), -- NULL means applies to all vendors
|
||||
calculation_period_days INT NOT NULL DEFAULT 30,
|
||||
calculation_period_days INTEGER NOT NULL DEFAULT 30,
|
||||
target_rate DECIMAL(10,2) NOT NULL DEFAULT 1.0,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
UNIQUE KEY unique_category_vendor (category_id, vendor)
|
||||
UNIQUE (category_id, vendor)
|
||||
);
|
||||
|
||||
-- Create table for sales seasonality factors
|
||||
CREATE TABLE IF NOT EXISTS sales_seasonality (
|
||||
month INT NOT NULL,
|
||||
CREATE TABLE sales_seasonality (
|
||||
month INTEGER NOT NULL,
|
||||
seasonality_factor DECIMAL(5,3) DEFAULT 0,
|
||||
last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (month),
|
||||
CHECK (month BETWEEN 1 AND 12),
|
||||
CHECK (seasonality_factor BETWEEN -1.0 AND 1.0)
|
||||
CONSTRAINT month_range CHECK (month BETWEEN 1 AND 12),
|
||||
CONSTRAINT seasonality_range CHECK (seasonality_factor BETWEEN -1.0 AND 1.0)
|
||||
);
|
||||
|
||||
-- Insert default global thresholds if not exists
|
||||
-- Insert default global thresholds
|
||||
INSERT INTO stock_thresholds (id, category_id, vendor, critical_days, reorder_days, overstock_days)
|
||||
VALUES (1, NULL, NULL, 7, 14, 90)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
critical_days = VALUES(critical_days),
|
||||
reorder_days = VALUES(reorder_days),
|
||||
overstock_days = VALUES(overstock_days);
|
||||
ON CONFLICT (id) DO UPDATE SET
|
||||
critical_days = EXCLUDED.critical_days,
|
||||
reorder_days = EXCLUDED.reorder_days,
|
||||
overstock_days = EXCLUDED.overstock_days;
|
||||
|
||||
INSERT INTO lead_time_thresholds (id, category_id, vendor, target_days, warning_days, critical_days)
|
||||
VALUES (1, NULL, NULL, 14, 21, 30)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
target_days = VALUES(target_days),
|
||||
warning_days = VALUES(warning_days),
|
||||
critical_days = VALUES(critical_days);
|
||||
ON CONFLICT (id) DO UPDATE SET
|
||||
target_days = EXCLUDED.target_days,
|
||||
warning_days = EXCLUDED.warning_days,
|
||||
critical_days = EXCLUDED.critical_days;
|
||||
|
||||
INSERT INTO sales_velocity_config (id, category_id, vendor, daily_window_days, weekly_window_days, monthly_window_days)
|
||||
VALUES (1, NULL, NULL, 30, 7, 90)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
daily_window_days = VALUES(daily_window_days),
|
||||
weekly_window_days = VALUES(weekly_window_days),
|
||||
monthly_window_days = VALUES(monthly_window_days);
|
||||
ON CONFLICT (id) DO UPDATE SET
|
||||
daily_window_days = EXCLUDED.daily_window_days,
|
||||
weekly_window_days = EXCLUDED.weekly_window_days,
|
||||
monthly_window_days = EXCLUDED.monthly_window_days;
|
||||
|
||||
INSERT INTO abc_classification_config (id, a_threshold, b_threshold, classification_period_days)
|
||||
VALUES (1, 20.0, 50.0, 90)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
a_threshold = VALUES(a_threshold),
|
||||
b_threshold = VALUES(b_threshold),
|
||||
classification_period_days = VALUES(classification_period_days);
|
||||
ON CONFLICT (id) DO UPDATE SET
|
||||
a_threshold = EXCLUDED.a_threshold,
|
||||
b_threshold = EXCLUDED.b_threshold,
|
||||
classification_period_days = EXCLUDED.classification_period_days;
|
||||
|
||||
INSERT INTO safety_stock_config (id, category_id, vendor, coverage_days, service_level)
|
||||
VALUES (1, NULL, NULL, 14, 95.0)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
coverage_days = VALUES(coverage_days),
|
||||
service_level = VALUES(service_level);
|
||||
ON CONFLICT (id) DO UPDATE SET
|
||||
coverage_days = EXCLUDED.coverage_days,
|
||||
service_level = EXCLUDED.service_level;
|
||||
|
||||
INSERT INTO turnover_config (id, category_id, vendor, calculation_period_days, target_rate)
|
||||
VALUES (1, NULL, NULL, 30, 1.0)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
calculation_period_days = VALUES(calculation_period_days),
|
||||
target_rate = VALUES(target_rate);
|
||||
ON CONFLICT (id) DO UPDATE SET
|
||||
calculation_period_days = EXCLUDED.calculation_period_days,
|
||||
target_rate = EXCLUDED.target_rate;
|
||||
|
||||
-- Insert default seasonality factors (neutral)
|
||||
INSERT INTO sales_seasonality (month, seasonality_factor)
|
||||
VALUES
|
||||
(1, 0), (2, 0), (3, 0), (4, 0), (5, 0), (6, 0),
|
||||
(7, 0), (8, 0), (9, 0), (10, 0), (11, 0), (12, 0)
|
||||
ON DUPLICATE KEY UPDATE last_updated = CURRENT_TIMESTAMP;
|
||||
ON CONFLICT (month) DO UPDATE SET
|
||||
last_updated = CURRENT_TIMESTAMP;
|
||||
|
||||
-- View to show thresholds with category names
|
||||
CREATE OR REPLACE VIEW stock_thresholds_view AS
|
||||
@@ -153,9 +157,9 @@ SELECT
|
||||
c.name as category_name,
|
||||
CASE
|
||||
WHEN st.category_id IS NULL AND st.vendor IS NULL THEN 'Global Default'
|
||||
WHEN st.category_id IS NULL THEN CONCAT('Vendor: ', st.vendor)
|
||||
WHEN st.vendor IS NULL THEN CONCAT('Category: ', c.name)
|
||||
ELSE CONCAT('Category: ', c.name, ' / Vendor: ', st.vendor)
|
||||
WHEN st.category_id IS NULL THEN 'Vendor: ' || st.vendor
|
||||
WHEN st.vendor IS NULL THEN 'Category: ' || c.name
|
||||
ELSE 'Category: ' || c.name || ' / Vendor: ' || st.vendor
|
||||
END as threshold_scope
|
||||
FROM
|
||||
stock_thresholds st
|
||||
@@ -171,59 +175,55 @@ ORDER BY
|
||||
c.name,
|
||||
st.vendor;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS calculate_history (
|
||||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||||
-- Types are created by the reset script
|
||||
CREATE TABLE calculate_history (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
start_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
end_time TIMESTAMP NULL,
|
||||
duration_seconds INT,
|
||||
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds / 60.0) STORED,
|
||||
total_products INT DEFAULT 0,
|
||||
total_orders INT DEFAULT 0,
|
||||
total_purchase_orders INT DEFAULT 0,
|
||||
processed_products INT DEFAULT 0,
|
||||
processed_orders INT DEFAULT 0,
|
||||
processed_purchase_orders INT DEFAULT 0,
|
||||
status ENUM('running', 'completed', 'failed', 'cancelled') DEFAULT 'running',
|
||||
duration_seconds INTEGER,
|
||||
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds::decimal / 60.0) STORED,
|
||||
total_products INTEGER DEFAULT 0,
|
||||
total_orders INTEGER DEFAULT 0,
|
||||
total_purchase_orders INTEGER DEFAULT 0,
|
||||
processed_products INTEGER DEFAULT 0,
|
||||
processed_orders INTEGER DEFAULT 0,
|
||||
processed_purchase_orders INTEGER DEFAULT 0,
|
||||
status calculation_status DEFAULT 'running',
|
||||
error_message TEXT,
|
||||
additional_info JSON,
|
||||
INDEX idx_status_time (status, start_time)
|
||||
additional_info JSONB
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS calculate_status (
|
||||
module_name ENUM(
|
||||
'product_metrics',
|
||||
'time_aggregates',
|
||||
'financial_metrics',
|
||||
'vendor_metrics',
|
||||
'category_metrics',
|
||||
'brand_metrics',
|
||||
'sales_forecasts',
|
||||
'abc_classification'
|
||||
) PRIMARY KEY,
|
||||
last_calculation_timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
INDEX idx_last_calc (last_calculation_timestamp)
|
||||
CREATE INDEX idx_status_time ON calculate_history(status, start_time);
|
||||
|
||||
CREATE TABLE calculate_status (
|
||||
module_name module_name PRIMARY KEY,
|
||||
last_calculation_timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS sync_status (
|
||||
CREATE INDEX idx_last_calc ON calculate_status(last_calculation_timestamp);
|
||||
|
||||
CREATE TABLE sync_status (
|
||||
table_name VARCHAR(50) PRIMARY KEY,
|
||||
last_sync_timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
last_sync_id BIGINT,
|
||||
INDEX idx_last_sync (last_sync_timestamp)
|
||||
last_sync_id BIGINT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS import_history (
|
||||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||||
CREATE INDEX idx_last_sync ON sync_status(last_sync_timestamp);
|
||||
|
||||
CREATE TABLE import_history (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
table_name VARCHAR(50) NOT NULL,
|
||||
start_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
end_time TIMESTAMP NULL,
|
||||
duration_seconds INT,
|
||||
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds / 60.0) STORED,
|
||||
records_added INT DEFAULT 0,
|
||||
records_updated INT DEFAULT 0,
|
||||
duration_seconds INTEGER,
|
||||
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds::decimal / 60.0) STORED,
|
||||
records_added INTEGER DEFAULT 0,
|
||||
records_updated INTEGER DEFAULT 0,
|
||||
is_incremental BOOLEAN DEFAULT FALSE,
|
||||
status ENUM('running', 'completed', 'failed', 'cancelled') DEFAULT 'running',
|
||||
status calculation_status DEFAULT 'running',
|
||||
error_message TEXT,
|
||||
additional_info JSON,
|
||||
INDEX idx_table_time (table_name, start_time),
|
||||
INDEX idx_status (status)
|
||||
additional_info JSONB
|
||||
);
|
||||
|
||||
CREATE INDEX idx_table_time ON import_history(table_name, start_time);
|
||||
CREATE INDEX idx_import_history_status ON import_history(status);
|
||||
@@ -1,8 +1,8 @@
|
||||
-- Disable foreign key checks
|
||||
SET FOREIGN_KEY_CHECKS = 0;
|
||||
SET session_replication_role = 'replica';
|
||||
|
||||
-- Temporary tables for batch metrics processing
|
||||
CREATE TABLE IF NOT EXISTS temp_sales_metrics (
|
||||
CREATE TABLE temp_sales_metrics (
|
||||
pid BIGINT NOT NULL,
|
||||
daily_sales_avg DECIMAL(10,3),
|
||||
weekly_sales_avg DECIMAL(10,3),
|
||||
@@ -14,9 +14,9 @@ CREATE TABLE IF NOT EXISTS temp_sales_metrics (
|
||||
PRIMARY KEY (pid)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS temp_purchase_metrics (
|
||||
CREATE TABLE temp_purchase_metrics (
|
||||
pid BIGINT NOT NULL,
|
||||
avg_lead_time_days INT,
|
||||
avg_lead_time_days INTEGER,
|
||||
last_purchase_date DATE,
|
||||
first_received_date DATE,
|
||||
last_received_date DATE,
|
||||
@@ -24,7 +24,7 @@ CREATE TABLE IF NOT EXISTS temp_purchase_metrics (
|
||||
);
|
||||
|
||||
-- New table for product metrics
|
||||
CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
CREATE TABLE product_metrics (
|
||||
pid BIGINT NOT NULL,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- Sales velocity metrics
|
||||
@@ -32,16 +32,16 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
weekly_sales_avg DECIMAL(10,3),
|
||||
monthly_sales_avg DECIMAL(10,3),
|
||||
avg_quantity_per_order DECIMAL(10,3),
|
||||
number_of_orders INT,
|
||||
number_of_orders INTEGER,
|
||||
first_sale_date DATE,
|
||||
last_sale_date DATE,
|
||||
-- Stock metrics
|
||||
days_of_inventory INT,
|
||||
weeks_of_inventory INT,
|
||||
reorder_point INT,
|
||||
safety_stock INT,
|
||||
reorder_qty INT DEFAULT 0,
|
||||
overstocked_amt INT DEFAULT 0,
|
||||
days_of_inventory INTEGER,
|
||||
weeks_of_inventory INTEGER,
|
||||
reorder_point INTEGER,
|
||||
safety_stock INTEGER,
|
||||
reorder_qty INTEGER DEFAULT 0,
|
||||
overstocked_amt INTEGER DEFAULT 0,
|
||||
-- Financial metrics
|
||||
avg_margin_percent DECIMAL(10,3),
|
||||
total_revenue DECIMAL(10,3),
|
||||
@@ -50,7 +50,7 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
gross_profit DECIMAL(10,3),
|
||||
gmroi DECIMAL(10,3),
|
||||
-- Purchase metrics
|
||||
avg_lead_time_days INT,
|
||||
avg_lead_time_days INTEGER,
|
||||
last_purchase_date DATE,
|
||||
first_received_date DATE,
|
||||
last_received_date DATE,
|
||||
@@ -60,48 +60,50 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
-- Turnover metrics
|
||||
turnover_rate DECIMAL(12,3),
|
||||
-- Lead time metrics
|
||||
current_lead_time INT,
|
||||
target_lead_time INT,
|
||||
current_lead_time INTEGER,
|
||||
target_lead_time INTEGER,
|
||||
lead_time_status VARCHAR(20),
|
||||
-- Forecast metrics
|
||||
forecast_accuracy DECIMAL(5,2) DEFAULT NULL,
|
||||
forecast_bias DECIMAL(5,2) DEFAULT NULL,
|
||||
last_forecast_date DATE DEFAULT NULL,
|
||||
PRIMARY KEY (pid),
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
||||
INDEX idx_metrics_revenue (total_revenue),
|
||||
INDEX idx_metrics_stock_status (stock_status),
|
||||
INDEX idx_metrics_lead_time (lead_time_status),
|
||||
INDEX idx_metrics_turnover (turnover_rate),
|
||||
INDEX idx_metrics_last_calculated (last_calculated_at),
|
||||
INDEX idx_metrics_abc (abc_class),
|
||||
INDEX idx_metrics_sales (daily_sales_avg, weekly_sales_avg, monthly_sales_avg),
|
||||
INDEX idx_metrics_forecast (forecast_accuracy, forecast_bias)
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_metrics_revenue ON product_metrics(total_revenue);
|
||||
CREATE INDEX idx_metrics_stock_status ON product_metrics(stock_status);
|
||||
CREATE INDEX idx_metrics_lead_time ON product_metrics(lead_time_status);
|
||||
CREATE INDEX idx_metrics_turnover ON product_metrics(turnover_rate);
|
||||
CREATE INDEX idx_metrics_last_calculated ON product_metrics(last_calculated_at);
|
||||
CREATE INDEX idx_metrics_abc ON product_metrics(abc_class);
|
||||
CREATE INDEX idx_metrics_sales ON product_metrics(daily_sales_avg, weekly_sales_avg, monthly_sales_avg);
|
||||
CREATE INDEX idx_metrics_forecast ON product_metrics(forecast_accuracy, forecast_bias);
|
||||
|
||||
-- New table for time-based aggregates
|
||||
CREATE TABLE IF NOT EXISTS product_time_aggregates (
|
||||
CREATE TABLE product_time_aggregates (
|
||||
pid BIGINT NOT NULL,
|
||||
year INT NOT NULL,
|
||||
month INT NOT NULL,
|
||||
year INTEGER NOT NULL,
|
||||
month INTEGER NOT NULL,
|
||||
-- Sales metrics
|
||||
total_quantity_sold INT DEFAULT 0,
|
||||
total_quantity_sold INTEGER DEFAULT 0,
|
||||
total_revenue DECIMAL(10,3) DEFAULT 0,
|
||||
total_cost DECIMAL(10,3) DEFAULT 0,
|
||||
order_count INT DEFAULT 0,
|
||||
order_count INTEGER DEFAULT 0,
|
||||
-- Stock changes
|
||||
stock_received INT DEFAULT 0,
|
||||
stock_ordered INT DEFAULT 0,
|
||||
stock_received INTEGER DEFAULT 0,
|
||||
stock_ordered INTEGER DEFAULT 0,
|
||||
-- Calculated fields
|
||||
avg_price DECIMAL(10,3),
|
||||
profit_margin DECIMAL(10,3),
|
||||
inventory_value DECIMAL(10,3),
|
||||
gmroi DECIMAL(10,3),
|
||||
PRIMARY KEY (pid, year, month),
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
||||
INDEX idx_date (year, month)
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_date ON product_time_aggregates(year, month);
|
||||
|
||||
-- Create vendor_details table
|
||||
CREATE TABLE vendor_details (
|
||||
vendor VARCHAR(100) PRIMARY KEY,
|
||||
@@ -110,45 +112,47 @@ CREATE TABLE vendor_details (
|
||||
phone VARCHAR(50),
|
||||
status VARCHAR(20) DEFAULT 'active',
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
INDEX idx_status (status)
|
||||
) ENGINE=InnoDB;
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX idx_vendor_details_status ON vendor_details(status);
|
||||
|
||||
-- New table for vendor metrics
|
||||
CREATE TABLE IF NOT EXISTS vendor_metrics (
|
||||
CREATE TABLE vendor_metrics (
|
||||
vendor VARCHAR(100) NOT NULL,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- Performance metrics
|
||||
avg_lead_time_days DECIMAL(10,3),
|
||||
on_time_delivery_rate DECIMAL(5,2),
|
||||
order_fill_rate DECIMAL(5,2),
|
||||
total_orders INT DEFAULT 0,
|
||||
total_late_orders INT DEFAULT 0,
|
||||
total_orders INTEGER DEFAULT 0,
|
||||
total_late_orders INTEGER DEFAULT 0,
|
||||
total_purchase_value DECIMAL(10,3) DEFAULT 0,
|
||||
avg_order_value DECIMAL(10,3),
|
||||
-- Product metrics
|
||||
active_products INT DEFAULT 0,
|
||||
total_products INT DEFAULT 0,
|
||||
active_products INTEGER DEFAULT 0,
|
||||
total_products INTEGER DEFAULT 0,
|
||||
-- Financial metrics
|
||||
total_revenue DECIMAL(10,3) DEFAULT 0,
|
||||
avg_margin_percent DECIMAL(5,2),
|
||||
-- Status
|
||||
status VARCHAR(20) DEFAULT 'active',
|
||||
PRIMARY KEY (vendor),
|
||||
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE,
|
||||
INDEX idx_vendor_performance (on_time_delivery_rate),
|
||||
INDEX idx_vendor_status (status),
|
||||
INDEX idx_metrics_last_calculated (last_calculated_at),
|
||||
INDEX idx_vendor_metrics_orders (total_orders, total_late_orders)
|
||||
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_vendor_performance ON vendor_metrics(on_time_delivery_rate);
|
||||
CREATE INDEX idx_vendor_status ON vendor_metrics(status);
|
||||
CREATE INDEX idx_vendor_metrics_last_calculated ON vendor_metrics(last_calculated_at);
|
||||
CREATE INDEX idx_vendor_metrics_orders ON vendor_metrics(total_orders, total_late_orders);
|
||||
|
||||
-- New table for category metrics
|
||||
CREATE TABLE IF NOT EXISTS category_metrics (
|
||||
CREATE TABLE category_metrics (
|
||||
category_id BIGINT NOT NULL,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- Product metrics
|
||||
product_count INT DEFAULT 0,
|
||||
active_products INT DEFAULT 0,
|
||||
product_count INTEGER DEFAULT 0,
|
||||
active_products INTEGER DEFAULT 0,
|
||||
-- Financial metrics
|
||||
total_value DECIMAL(15,3) DEFAULT 0,
|
||||
avg_margin DECIMAL(5,2),
|
||||
@@ -157,255 +161,215 @@ CREATE TABLE IF NOT EXISTS category_metrics (
|
||||
-- Status
|
||||
status VARCHAR(20) DEFAULT 'active',
|
||||
PRIMARY KEY (category_id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
INDEX idx_category_status (status),
|
||||
INDEX idx_category_growth (growth_rate),
|
||||
INDEX idx_metrics_last_calculated (last_calculated_at),
|
||||
INDEX idx_category_metrics_products (product_count, active_products)
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_category_status ON category_metrics(status);
|
||||
CREATE INDEX idx_category_growth ON category_metrics(growth_rate);
|
||||
CREATE INDEX idx_metrics_last_calculated_cat ON category_metrics(last_calculated_at);
|
||||
CREATE INDEX idx_category_metrics_products ON category_metrics(product_count, active_products);
|
||||
|
||||
-- New table for vendor time-based metrics
|
||||
CREATE TABLE IF NOT EXISTS vendor_time_metrics (
|
||||
CREATE TABLE vendor_time_metrics (
|
||||
vendor VARCHAR(100) NOT NULL,
|
||||
year INT NOT NULL,
|
||||
month INT NOT NULL,
|
||||
year INTEGER NOT NULL,
|
||||
month INTEGER NOT NULL,
|
||||
-- Order metrics
|
||||
total_orders INT DEFAULT 0,
|
||||
late_orders INT DEFAULT 0,
|
||||
total_orders INTEGER DEFAULT 0,
|
||||
late_orders INTEGER DEFAULT 0,
|
||||
avg_lead_time_days DECIMAL(10,3),
|
||||
-- Financial metrics
|
||||
total_purchase_value DECIMAL(10,3) DEFAULT 0,
|
||||
total_revenue DECIMAL(10,3) DEFAULT 0,
|
||||
avg_margin_percent DECIMAL(5,2),
|
||||
PRIMARY KEY (vendor, year, month),
|
||||
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE,
|
||||
INDEX idx_vendor_date (year, month)
|
||||
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_vendor_date ON vendor_time_metrics(year, month);
|
||||
|
||||
-- New table for category time-based metrics
|
||||
CREATE TABLE IF NOT EXISTS category_time_metrics (
|
||||
CREATE TABLE category_time_metrics (
|
||||
category_id BIGINT NOT NULL,
|
||||
year INT NOT NULL,
|
||||
month INT NOT NULL,
|
||||
year INTEGER NOT NULL,
|
||||
month INTEGER NOT NULL,
|
||||
-- Product metrics
|
||||
product_count INT DEFAULT 0,
|
||||
active_products INT DEFAULT 0,
|
||||
product_count INTEGER DEFAULT 0,
|
||||
active_products INTEGER DEFAULT 0,
|
||||
-- Financial metrics
|
||||
total_value DECIMAL(15,3) DEFAULT 0,
|
||||
total_revenue DECIMAL(15,3) DEFAULT 0,
|
||||
avg_margin DECIMAL(5,2),
|
||||
turnover_rate DECIMAL(12,3),
|
||||
PRIMARY KEY (category_id, year, month),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
INDEX idx_category_date (year, month)
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_category_date ON category_time_metrics(year, month);
|
||||
|
||||
-- New table for category-based sales metrics
|
||||
CREATE TABLE IF NOT EXISTS category_sales_metrics (
|
||||
CREATE TABLE category_sales_metrics (
|
||||
category_id BIGINT NOT NULL,
|
||||
brand VARCHAR(100) NOT NULL,
|
||||
period_start DATE NOT NULL,
|
||||
period_end DATE NOT NULL,
|
||||
avg_daily_sales DECIMAL(10,3) DEFAULT 0,
|
||||
total_sold INT DEFAULT 0,
|
||||
num_products INT DEFAULT 0,
|
||||
total_sold INTEGER DEFAULT 0,
|
||||
num_products INTEGER DEFAULT 0,
|
||||
avg_price DECIMAL(10,3) DEFAULT 0,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (category_id, brand, period_start, period_end),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
INDEX idx_category_brand (category_id, brand),
|
||||
INDEX idx_period (period_start, period_end)
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_category_brand ON category_sales_metrics(category_id, brand);
|
||||
CREATE INDEX idx_period ON category_sales_metrics(period_start, period_end);
|
||||
|
||||
-- New table for brand metrics
|
||||
CREATE TABLE IF NOT EXISTS brand_metrics (
|
||||
CREATE TABLE brand_metrics (
|
||||
brand VARCHAR(100) NOT NULL,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- Product metrics
|
||||
product_count INT DEFAULT 0,
|
||||
active_products INT DEFAULT 0,
|
||||
product_count INTEGER DEFAULT 0,
|
||||
active_products INTEGER DEFAULT 0,
|
||||
-- Stock metrics
|
||||
total_stock_units INT DEFAULT 0,
|
||||
total_stock_units INTEGER DEFAULT 0,
|
||||
total_stock_cost DECIMAL(15,2) DEFAULT 0,
|
||||
total_stock_retail DECIMAL(15,2) DEFAULT 0,
|
||||
-- Sales metrics
|
||||
total_revenue DECIMAL(15,2) DEFAULT 0,
|
||||
avg_margin DECIMAL(5,2) DEFAULT 0,
|
||||
growth_rate DECIMAL(5,2) DEFAULT 0,
|
||||
PRIMARY KEY (brand),
|
||||
INDEX idx_brand_metrics_last_calculated (last_calculated_at),
|
||||
INDEX idx_brand_metrics_revenue (total_revenue),
|
||||
INDEX idx_brand_metrics_growth (growth_rate)
|
||||
PRIMARY KEY (brand)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_brand_metrics_last_calculated ON brand_metrics(last_calculated_at);
|
||||
CREATE INDEX idx_brand_metrics_revenue ON brand_metrics(total_revenue);
|
||||
CREATE INDEX idx_brand_metrics_growth ON brand_metrics(growth_rate);
|
||||
|
||||
-- New table for brand time-based metrics
|
||||
CREATE TABLE IF NOT EXISTS brand_time_metrics (
|
||||
CREATE TABLE brand_time_metrics (
|
||||
brand VARCHAR(100) NOT NULL,
|
||||
year INT NOT NULL,
|
||||
month INT NOT NULL,
|
||||
year INTEGER NOT NULL,
|
||||
month INTEGER NOT NULL,
|
||||
-- Product metrics
|
||||
product_count INT DEFAULT 0,
|
||||
active_products INT DEFAULT 0,
|
||||
product_count INTEGER DEFAULT 0,
|
||||
active_products INTEGER DEFAULT 0,
|
||||
-- Stock metrics
|
||||
total_stock_units INT DEFAULT 0,
|
||||
total_stock_units INTEGER DEFAULT 0,
|
||||
total_stock_cost DECIMAL(15,2) DEFAULT 0,
|
||||
total_stock_retail DECIMAL(15,2) DEFAULT 0,
|
||||
-- Sales metrics
|
||||
total_revenue DECIMAL(15,2) DEFAULT 0,
|
||||
avg_margin DECIMAL(5,2) DEFAULT 0,
|
||||
PRIMARY KEY (brand, year, month),
|
||||
INDEX idx_brand_date (year, month)
|
||||
growth_rate DECIMAL(5,2) DEFAULT 0,
|
||||
PRIMARY KEY (brand, year, month)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_brand_time_date ON brand_time_metrics(year, month);
|
||||
|
||||
-- New table for sales forecasts
|
||||
CREATE TABLE IF NOT EXISTS sales_forecasts (
|
||||
CREATE TABLE sales_forecasts (
|
||||
pid BIGINT NOT NULL,
|
||||
forecast_date DATE NOT NULL,
|
||||
forecast_units DECIMAL(10,2) DEFAULT 0,
|
||||
forecast_revenue DECIMAL(10,2) DEFAULT 0,
|
||||
confidence_level DECIMAL(5,2) DEFAULT 0,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
forecast_quantity INTEGER,
|
||||
confidence_level DECIMAL(5,2),
|
||||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (pid, forecast_date),
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
||||
INDEX idx_forecast_date (forecast_date),
|
||||
INDEX idx_forecast_last_calculated (last_calculated_at)
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_forecast_date ON sales_forecasts(forecast_date);
|
||||
|
||||
-- New table for category forecasts
|
||||
CREATE TABLE IF NOT EXISTS category_forecasts (
|
||||
CREATE TABLE category_forecasts (
|
||||
category_id BIGINT NOT NULL,
|
||||
forecast_date DATE NOT NULL,
|
||||
forecast_units DECIMAL(10,2) DEFAULT 0,
|
||||
forecast_revenue DECIMAL(10,2) DEFAULT 0,
|
||||
confidence_level DECIMAL(5,2) DEFAULT 0,
|
||||
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
forecast_revenue DECIMAL(15,2),
|
||||
forecast_units INTEGER,
|
||||
confidence_level DECIMAL(5,2),
|
||||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (category_id, forecast_date),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
INDEX idx_category_forecast_date (forecast_date),
|
||||
INDEX idx_category_forecast_last_calculated (last_calculated_at)
|
||||
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Create view for inventory health
|
||||
CREATE INDEX idx_cat_forecast_date ON category_forecasts(forecast_date);
|
||||
|
||||
-- Create views for common calculations
|
||||
CREATE OR REPLACE VIEW inventory_health AS
|
||||
WITH product_thresholds AS (
|
||||
WITH stock_levels AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
COALESCE(
|
||||
-- Try category+vendor specific
|
||||
(SELECT critical_days FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.cat_id
|
||||
WHERE pc.pid = p.pid
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
-- Try category specific
|
||||
(SELECT critical_days FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.cat_id
|
||||
WHERE pc.pid = p.pid
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
-- Try vendor specific
|
||||
(SELECT critical_days FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
-- Fall back to default
|
||||
(SELECT critical_days FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
7
|
||||
) as critical_days,
|
||||
COALESCE(
|
||||
-- Try category+vendor specific
|
||||
(SELECT reorder_days FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.cat_id
|
||||
WHERE pc.pid = p.pid
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
-- Try category specific
|
||||
(SELECT reorder_days FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.cat_id
|
||||
WHERE pc.pid = p.pid
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
-- Try vendor specific
|
||||
(SELECT reorder_days FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
-- Fall back to default
|
||||
(SELECT reorder_days FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
14
|
||||
) as reorder_days,
|
||||
COALESCE(
|
||||
-- Try category+vendor specific
|
||||
(SELECT overstock_days FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.cat_id
|
||||
WHERE pc.pid = p.pid
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
-- Try category specific
|
||||
(SELECT overstock_days FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.cat_id
|
||||
WHERE pc.pid = p.pid
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
-- Try vendor specific
|
||||
(SELECT overstock_days FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
-- Fall back to default
|
||||
(SELECT overstock_days FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
90
|
||||
) as overstock_days
|
||||
p.title,
|
||||
p.SKU,
|
||||
p.stock_quantity,
|
||||
p.preorder_count,
|
||||
pm.daily_sales_avg,
|
||||
pm.weekly_sales_avg,
|
||||
pm.monthly_sales_avg,
|
||||
pm.reorder_point,
|
||||
pm.safety_stock,
|
||||
pm.days_of_inventory,
|
||||
pm.weeks_of_inventory,
|
||||
pm.stock_status,
|
||||
pm.abc_class,
|
||||
pm.turnover_rate,
|
||||
pm.avg_lead_time_days,
|
||||
pm.current_lead_time,
|
||||
pm.target_lead_time,
|
||||
pm.lead_time_status,
|
||||
p.cost_price,
|
||||
p.price,
|
||||
pm.inventory_value,
|
||||
pm.gmroi
|
||||
FROM products p
|
||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
||||
WHERE p.managing_stock = true AND p.visible = true
|
||||
)
|
||||
SELECT
|
||||
p.pid,
|
||||
p.SKU,
|
||||
p.title,
|
||||
p.stock_quantity,
|
||||
COALESCE(pm.daily_sales_avg, 0) as daily_sales_avg,
|
||||
COALESCE(pm.days_of_inventory, 0) as days_of_inventory,
|
||||
COALESCE(pm.reorder_point, 0) as reorder_point,
|
||||
COALESCE(pm.safety_stock, 0) as safety_stock,
|
||||
*,
|
||||
CASE
|
||||
WHEN pm.daily_sales_avg = 0 THEN 'New'
|
||||
WHEN p.stock_quantity <= CEIL(pm.daily_sales_avg * pt.critical_days) THEN 'Critical'
|
||||
WHEN p.stock_quantity <= CEIL(pm.daily_sales_avg * pt.reorder_days) THEN 'Reorder'
|
||||
WHEN p.stock_quantity > (pm.daily_sales_avg * pt.overstock_days) THEN 'Overstocked'
|
||||
WHEN stock_quantity <= safety_stock THEN 'Critical'
|
||||
WHEN stock_quantity <= reorder_point THEN 'Low'
|
||||
WHEN stock_quantity > (reorder_point * 3) THEN 'Excess'
|
||||
ELSE 'Healthy'
|
||||
END as stock_status
|
||||
FROM
|
||||
products p
|
||||
LEFT JOIN
|
||||
product_metrics pm ON p.pid = pm.pid
|
||||
LEFT JOIN
|
||||
product_thresholds pt ON p.pid = pt.pid
|
||||
WHERE
|
||||
p.managing_stock = true;
|
||||
END as inventory_status,
|
||||
CASE
|
||||
WHEN lead_time_status = 'delayed' AND stock_status = 'low' THEN 'High'
|
||||
WHEN lead_time_status = 'delayed' OR stock_status = 'low' THEN 'Medium'
|
||||
ELSE 'Low'
|
||||
END as risk_level
|
||||
FROM stock_levels;
|
||||
|
||||
-- Create view for category performance trends
|
||||
CREATE OR REPLACE VIEW category_performance_trends AS
|
||||
WITH monthly_trends AS (
|
||||
SELECT
|
||||
c.cat_id as category_id,
|
||||
c.name,
|
||||
c.description,
|
||||
p.name as parent_name,
|
||||
c.status,
|
||||
cm.product_count,
|
||||
cm.active_products,
|
||||
cm.total_value,
|
||||
cm.avg_margin,
|
||||
cm.turnover_rate,
|
||||
cm.growth_rate,
|
||||
c.cat_id,
|
||||
c.name as category_name,
|
||||
ctm.year,
|
||||
ctm.month,
|
||||
ctm.product_count,
|
||||
ctm.active_products,
|
||||
ctm.total_value,
|
||||
ctm.total_revenue,
|
||||
ctm.avg_margin,
|
||||
ctm.turnover_rate,
|
||||
LAG(ctm.total_revenue) OVER (PARTITION BY c.cat_id ORDER BY ctm.year, ctm.month) as prev_month_revenue,
|
||||
LAG(ctm.turnover_rate) OVER (PARTITION BY c.cat_id ORDER BY ctm.year, ctm.month) as prev_month_turnover
|
||||
FROM categories c
|
||||
JOIN category_time_metrics ctm ON c.cat_id = ctm.category_id
|
||||
)
|
||||
SELECT
|
||||
*,
|
||||
CASE
|
||||
WHEN cm.growth_rate >= 20 THEN 'High Growth'
|
||||
WHEN cm.growth_rate >= 5 THEN 'Growing'
|
||||
WHEN cm.growth_rate >= -5 THEN 'Stable'
|
||||
ELSE 'Declining'
|
||||
END as performance_rating
|
||||
FROM
|
||||
categories c
|
||||
LEFT JOIN
|
||||
categories p ON c.parent_id = p.cat_id
|
||||
LEFT JOIN
|
||||
category_metrics cm ON c.cat_id = cm.category_id;
|
||||
WHEN prev_month_revenue IS NULL THEN 0
|
||||
ELSE ((total_revenue - prev_month_revenue) / prev_month_revenue) * 100
|
||||
END as revenue_growth_percent,
|
||||
CASE
|
||||
WHEN prev_month_turnover IS NULL THEN 0
|
||||
ELSE ((turnover_rate - prev_month_turnover) / prev_month_turnover) * 100
|
||||
END as turnover_growth_percent
|
||||
FROM monthly_trends;
|
||||
|
||||
-- Re-enable foreign key checks
|
||||
SET FOREIGN_KEY_CHECKS = 1;
|
||||
SET session_replication_role = 'origin';
|
||||
@@ -1,6 +1,5 @@
|
||||
-- Enable strict error reporting
|
||||
SET sql_mode = 'STRICT_ALL_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_ZERO_DATE,NO_ZERO_IN_DATE,NO_ENGINE_SUBSTITUTION';
|
||||
SET FOREIGN_KEY_CHECKS = 0;
|
||||
SET session_replication_role = 'replica'; -- Disable foreign key checks temporarily
|
||||
|
||||
-- Create tables
|
||||
CREATE TABLE products (
|
||||
@@ -8,11 +7,11 @@ CREATE TABLE products (
|
||||
title VARCHAR(255) NOT NULL,
|
||||
description TEXT,
|
||||
SKU VARCHAR(50) NOT NULL,
|
||||
created_at TIMESTAMP NULL,
|
||||
first_received TIMESTAMP NULL,
|
||||
stock_quantity INT DEFAULT 0,
|
||||
preorder_count INT DEFAULT 0,
|
||||
notions_inv_count INT DEFAULT 0,
|
||||
created_at TIMESTAMP,
|
||||
first_received TIMESTAMP,
|
||||
stock_quantity INTEGER DEFAULT 0,
|
||||
preorder_count INTEGER DEFAULT 0,
|
||||
notions_inv_count INTEGER DEFAULT 0,
|
||||
price DECIMAL(10, 3) NOT NULL,
|
||||
regular_price DECIMAL(10, 3) NOT NULL,
|
||||
cost_price DECIMAL(10, 3),
|
||||
@@ -37,47 +36,52 @@ CREATE TABLE products (
|
||||
artist VARCHAR(100),
|
||||
options TEXT,
|
||||
tags TEXT,
|
||||
moq INT DEFAULT 1,
|
||||
uom INT DEFAULT 1,
|
||||
moq INTEGER DEFAULT 1,
|
||||
uom INTEGER DEFAULT 1,
|
||||
rating DECIMAL(10,2) DEFAULT 0.00,
|
||||
reviews INT UNSIGNED DEFAULT 0,
|
||||
reviews INTEGER DEFAULT 0,
|
||||
weight DECIMAL(10,3),
|
||||
length DECIMAL(10,3),
|
||||
width DECIMAL(10,3),
|
||||
height DECIMAL(10,3),
|
||||
country_of_origin VARCHAR(5),
|
||||
location VARCHAR(50),
|
||||
total_sold INT UNSIGNED DEFAULT 0,
|
||||
baskets INT UNSIGNED DEFAULT 0,
|
||||
notifies INT UNSIGNED DEFAULT 0,
|
||||
total_sold INTEGER DEFAULT 0,
|
||||
baskets INTEGER DEFAULT 0,
|
||||
notifies INTEGER DEFAULT 0,
|
||||
date_last_sold DATE,
|
||||
updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX idx_sku (SKU),
|
||||
INDEX idx_vendor (vendor),
|
||||
INDEX idx_brand (brand),
|
||||
INDEX idx_location (location),
|
||||
INDEX idx_total_sold (total_sold),
|
||||
INDEX idx_date_last_sold (date_last_sold),
|
||||
INDEX idx_updated (updated)
|
||||
) ENGINE=InnoDB;
|
||||
updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (pid)
|
||||
);
|
||||
|
||||
-- Create indexes for products table
|
||||
CREATE INDEX idx_products_sku ON products(SKU);
|
||||
CREATE INDEX idx_products_vendor ON products(vendor);
|
||||
CREATE INDEX idx_products_brand ON products(brand);
|
||||
CREATE INDEX idx_products_location ON products(location);
|
||||
CREATE INDEX idx_products_total_sold ON products(total_sold);
|
||||
CREATE INDEX idx_products_date_last_sold ON products(date_last_sold);
|
||||
CREATE INDEX idx_products_updated ON products(updated);
|
||||
|
||||
-- Create categories table with hierarchy support
|
||||
CREATE TABLE categories (
|
||||
cat_id BIGINT PRIMARY KEY,
|
||||
name VARCHAR(100) NOT NULL,
|
||||
type SMALLINT NOT NULL COMMENT '10=section, 11=category, 12=subcategory, 13=subsubcategory, 1=company, 2=line, 3=subline, 40=artist',
|
||||
type SMALLINT NOT NULL,
|
||||
parent_id BIGINT,
|
||||
description TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
status VARCHAR(20) DEFAULT 'active',
|
||||
FOREIGN KEY (parent_id) REFERENCES categories(cat_id),
|
||||
INDEX idx_parent (parent_id),
|
||||
INDEX idx_type (type),
|
||||
INDEX idx_status (status),
|
||||
INDEX idx_name_type (name, type)
|
||||
) ENGINE=InnoDB;
|
||||
FOREIGN KEY (parent_id) REFERENCES categories(cat_id)
|
||||
);
|
||||
|
||||
COMMENT ON COLUMN categories.type IS '10=section, 11=category, 12=subcategory, 13=subsubcategory, 1=company, 2=line, 3=subline, 40=artist';
|
||||
|
||||
CREATE INDEX idx_categories_parent ON categories(parent_id);
|
||||
CREATE INDEX idx_categories_type ON categories(type);
|
||||
CREATE INDEX idx_categories_status ON categories(status);
|
||||
CREATE INDEX idx_categories_name_type ON categories(name, type);
|
||||
|
||||
-- Create product_categories junction table
|
||||
CREATE TABLE product_categories (
|
||||
@@ -85,78 +89,86 @@ CREATE TABLE product_categories (
|
||||
pid BIGINT NOT NULL,
|
||||
PRIMARY KEY (pid, cat_id),
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
||||
FOREIGN KEY (cat_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
|
||||
INDEX idx_category (cat_id),
|
||||
INDEX idx_product (pid)
|
||||
) ENGINE=InnoDB;
|
||||
FOREIGN KEY (cat_id) REFERENCES categories(cat_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_product_categories_category ON product_categories(cat_id);
|
||||
CREATE INDEX idx_product_categories_product ON product_categories(pid);
|
||||
|
||||
-- Create orders table with its indexes
|
||||
CREATE TABLE IF NOT EXISTS orders (
|
||||
id BIGINT NOT NULL AUTO_INCREMENT,
|
||||
CREATE TABLE orders (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
order_number VARCHAR(50) NOT NULL,
|
||||
pid BIGINT NOT NULL,
|
||||
SKU VARCHAR(50) NOT NULL,
|
||||
date DATE NOT NULL,
|
||||
price DECIMAL(10,3) NOT NULL,
|
||||
quantity INT NOT NULL,
|
||||
quantity INTEGER NOT NULL,
|
||||
discount DECIMAL(10,3) DEFAULT 0.000,
|
||||
tax DECIMAL(10,3) DEFAULT 0.000,
|
||||
tax_included TINYINT(1) DEFAULT 0,
|
||||
tax_included BOOLEAN DEFAULT false,
|
||||
shipping DECIMAL(10,3) DEFAULT 0.000,
|
||||
costeach DECIMAL(10,3) DEFAULT 0.000,
|
||||
customer VARCHAR(50) NOT NULL,
|
||||
customer_name VARCHAR(100),
|
||||
status VARCHAR(20) DEFAULT 'pending',
|
||||
canceled TINYINT(1) DEFAULT 0,
|
||||
updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
UNIQUE KEY unique_order_line (order_number, pid),
|
||||
KEY order_number (order_number),
|
||||
KEY pid (pid),
|
||||
KEY customer (customer),
|
||||
KEY date (date),
|
||||
KEY status (status),
|
||||
INDEX idx_orders_metrics (pid, date, canceled),
|
||||
INDEX idx_updated (updated)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
canceled BOOLEAN DEFAULT false,
|
||||
updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE (order_number, pid)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_orders_number ON orders(order_number);
|
||||
CREATE INDEX idx_orders_pid ON orders(pid);
|
||||
CREATE INDEX idx_orders_customer ON orders(customer);
|
||||
CREATE INDEX idx_orders_date ON orders(date);
|
||||
CREATE INDEX idx_orders_status ON orders(status);
|
||||
CREATE INDEX idx_orders_metrics ON orders(pid, date, canceled);
|
||||
CREATE INDEX idx_orders_updated ON orders(updated);
|
||||
|
||||
-- Create purchase_orders table with its indexes
|
||||
CREATE TABLE purchase_orders (
|
||||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
po_id VARCHAR(50) NOT NULL,
|
||||
vendor VARCHAR(100) NOT NULL,
|
||||
date DATE NOT NULL,
|
||||
expected_date DATE,
|
||||
pid BIGINT NOT NULL,
|
||||
sku VARCHAR(50) NOT NULL,
|
||||
name VARCHAR(100) NOT NULL COMMENT 'Product name from products.description',
|
||||
name VARCHAR(100) NOT NULL,
|
||||
cost_price DECIMAL(10, 3) NOT NULL,
|
||||
po_cost_price DECIMAL(10, 3) NOT NULL COMMENT 'Original cost from PO, before receiving adjustments',
|
||||
status TINYINT UNSIGNED DEFAULT 1 COMMENT '0=canceled,1=created,10=electronically_ready_send,11=ordered,12=preordered,13=electronically_sent,15=receiving_started,50=done',
|
||||
receiving_status TINYINT UNSIGNED DEFAULT 1 COMMENT '0=canceled,1=created,30=partial_received,40=full_received,50=paid',
|
||||
po_cost_price DECIMAL(10, 3) NOT NULL,
|
||||
status SMALLINT DEFAULT 1,
|
||||
receiving_status SMALLINT DEFAULT 1,
|
||||
notes TEXT,
|
||||
long_note TEXT,
|
||||
ordered INT NOT NULL,
|
||||
received INT DEFAULT 0,
|
||||
received_date DATE COMMENT 'Date of first receiving',
|
||||
last_received_date DATE COMMENT 'Date of most recent receiving',
|
||||
received_by VARCHAR(100) COMMENT 'Name of person who first received this PO line',
|
||||
receiving_history JSON COMMENT 'Array of receiving records with qty, date, cost, receiving_id, and alt_po flag',
|
||||
updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
ordered INTEGER NOT NULL,
|
||||
received INTEGER DEFAULT 0,
|
||||
received_date DATE,
|
||||
last_received_date DATE,
|
||||
received_by VARCHAR(100),
|
||||
receiving_history JSONB,
|
||||
updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (pid) REFERENCES products(pid),
|
||||
INDEX idx_po_id (po_id),
|
||||
INDEX idx_vendor (vendor),
|
||||
INDEX idx_status (status),
|
||||
INDEX idx_receiving_status (receiving_status),
|
||||
INDEX idx_purchase_orders_metrics (pid, date, status, ordered, received),
|
||||
INDEX idx_po_metrics (pid, date, receiving_status, received_date),
|
||||
INDEX idx_po_product_date (pid, date),
|
||||
INDEX idx_po_product_status (pid, status),
|
||||
INDEX idx_updated (updated),
|
||||
UNIQUE KEY unique_po_product (po_id, pid)
|
||||
) ENGINE=InnoDB;
|
||||
UNIQUE (po_id, pid)
|
||||
);
|
||||
|
||||
SET FOREIGN_KEY_CHECKS = 1;
|
||||
COMMENT ON COLUMN purchase_orders.name IS 'Product name from products.description';
|
||||
COMMENT ON COLUMN purchase_orders.po_cost_price IS 'Original cost from PO, before receiving adjustments';
|
||||
COMMENT ON COLUMN purchase_orders.status IS '0=canceled,1=created,10=electronically_ready_send,11=ordered,12=preordered,13=electronically_sent,15=receiving_started,50=done';
|
||||
COMMENT ON COLUMN purchase_orders.receiving_status IS '0=canceled,1=created,30=partial_received,40=full_received,50=paid';
|
||||
COMMENT ON COLUMN purchase_orders.receiving_history IS 'Array of receiving records with qty, date, cost, receiving_id, and alt_po flag';
|
||||
|
||||
CREATE INDEX idx_po_id ON purchase_orders(po_id);
|
||||
CREATE INDEX idx_po_vendor ON purchase_orders(vendor);
|
||||
CREATE INDEX idx_po_status ON purchase_orders(status);
|
||||
CREATE INDEX idx_po_receiving_status ON purchase_orders(receiving_status);
|
||||
CREATE INDEX idx_po_metrics ON purchase_orders(pid, date, status, ordered, received);
|
||||
CREATE INDEX idx_po_metrics_receiving ON purchase_orders(pid, date, receiving_status, received_date);
|
||||
CREATE INDEX idx_po_product_date ON purchase_orders(pid, date);
|
||||
CREATE INDEX idx_po_product_status ON purchase_orders(pid, status);
|
||||
CREATE INDEX idx_po_updated ON purchase_orders(updated);
|
||||
|
||||
SET session_replication_role = 'origin'; -- Re-enable foreign key checks
|
||||
|
||||
-- Create views for common calculations
|
||||
-- product_sales_trends view moved to metrics-schema.sql
|
||||
649
inventory-server/package-lock.json
generated
649
inventory-server/package-lock.json
generated
@@ -9,12 +9,14 @@
|
||||
"version": "1.0.0",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"bcrypt": "^5.1.1",
|
||||
"cors": "^2.8.5",
|
||||
"csv-parse": "^5.6.0",
|
||||
"dotenv": "^16.4.7",
|
||||
"express": "^4.18.2",
|
||||
"multer": "^1.4.5-lts.1",
|
||||
"mysql2": "^3.12.0",
|
||||
"pg": "^8.13.2",
|
||||
"pm2": "^5.3.0",
|
||||
"ssh2": "^1.16.0",
|
||||
"uuid": "^9.0.1"
|
||||
@@ -23,6 +25,74 @@
|
||||
"nodemon": "^3.0.2"
|
||||
}
|
||||
},
|
||||
"node_modules/@mapbox/node-pre-gyp": {
|
||||
"version": "1.0.11",
|
||||
"resolved": "https://registry.npmjs.org/@mapbox/node-pre-gyp/-/node-pre-gyp-1.0.11.tgz",
|
||||
"integrity": "sha512-Yhlar6v9WQgUp/He7BdgzOz8lqMQ8sU+jkCq7Wx8Myc5YFJLbEe7lgui/V7G1qB1DJykHSGwreceSaD60Y0PUQ==",
|
||||
"license": "BSD-3-Clause",
|
||||
"dependencies": {
|
||||
"detect-libc": "^2.0.0",
|
||||
"https-proxy-agent": "^5.0.0",
|
||||
"make-dir": "^3.1.0",
|
||||
"node-fetch": "^2.6.7",
|
||||
"nopt": "^5.0.0",
|
||||
"npmlog": "^5.0.1",
|
||||
"rimraf": "^3.0.2",
|
||||
"semver": "^7.3.5",
|
||||
"tar": "^6.1.11"
|
||||
},
|
||||
"bin": {
|
||||
"node-pre-gyp": "bin/node-pre-gyp"
|
||||
}
|
||||
},
|
||||
"node_modules/@mapbox/node-pre-gyp/node_modules/agent-base": {
|
||||
"version": "6.0.2",
|
||||
"resolved": "https://registry.npmjs.org/agent-base/-/agent-base-6.0.2.tgz",
|
||||
"integrity": "sha512-RZNwNclF7+MS/8bDg70amg32dyeZGZxiDuQmZxKLAlQjr3jGyLx+4Kkk58UO7D2QdgFIQCovuSuZESne6RG6XQ==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"debug": "4"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 6.0.0"
|
||||
}
|
||||
},
|
||||
"node_modules/@mapbox/node-pre-gyp/node_modules/debug": {
|
||||
"version": "4.4.0",
|
||||
"resolved": "https://registry.npmjs.org/debug/-/debug-4.4.0.tgz",
|
||||
"integrity": "sha512-6WTZ/IxCY/T6BALoZHaE4ctp9xm+Z5kY/pzYaCHRFeyVhojxlrm+46y68HA6hr0TcwEssoxNiDEUJQjfPZ/RYA==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"ms": "^2.1.3"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=6.0"
|
||||
},
|
||||
"peerDependenciesMeta": {
|
||||
"supports-color": {
|
||||
"optional": true
|
||||
}
|
||||
}
|
||||
},
|
||||
"node_modules/@mapbox/node-pre-gyp/node_modules/https-proxy-agent": {
|
||||
"version": "5.0.1",
|
||||
"resolved": "https://registry.npmjs.org/https-proxy-agent/-/https-proxy-agent-5.0.1.tgz",
|
||||
"integrity": "sha512-dFcAjpTQFgoLMzC2VwU+C/CbS7uRL0lWmxDITmqm7C+7F0Odmj6s9l6alZc6AELXhrnggM2CeWSXHGOdX2YtwA==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"agent-base": "6",
|
||||
"debug": "4"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 6"
|
||||
}
|
||||
},
|
||||
"node_modules/@mapbox/node-pre-gyp/node_modules/ms": {
|
||||
"version": "2.1.3",
|
||||
"resolved": "https://registry.npmjs.org/ms/-/ms-2.1.3.tgz",
|
||||
"integrity": "sha512-6FlzubTLZG3J2a/NVCAleEhjzq5oxgHyaCU9yYXvcLsvoVaHJq/s5xXI6/XXP6tz7R9xAOtHnSO/tXtF3WRTlA==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/@pm2/agent": {
|
||||
"version": "2.0.4",
|
||||
"resolved": "https://registry.npmjs.org/@pm2/agent/-/agent-2.0.4.tgz",
|
||||
@@ -276,6 +346,12 @@
|
||||
"integrity": "sha512-C5Mc6rdnsaJDjO3UpGW/CQTHtCKaYlScZTly4JIu97Jxo/odCiH0ITnDXSJPTOrEKk/ycSZ0AOgTmkDtkOsvIA==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/abbrev": {
|
||||
"version": "1.1.1",
|
||||
"resolved": "https://registry.npmjs.org/abbrev/-/abbrev-1.1.1.tgz",
|
||||
"integrity": "sha512-nne9/IiQ/hzIhY6pdDnbBtz7DjPTKrY00P/zvPSm5pOFkl6xuGrGnXn/VtTNNfNtAfZ9/1RtehkszU9qcTii0Q==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/accepts": {
|
||||
"version": "1.3.8",
|
||||
"resolved": "https://registry.npmjs.org/accepts/-/accepts-1.3.8.tgz",
|
||||
@@ -322,6 +398,15 @@
|
||||
"node": ">=6"
|
||||
}
|
||||
},
|
||||
"node_modules/ansi-regex": {
|
||||
"version": "5.0.1",
|
||||
"resolved": "https://registry.npmjs.org/ansi-regex/-/ansi-regex-5.0.1.tgz",
|
||||
"integrity": "sha512-quJQXlTSUGL2LH9SUXo8VwsY4soanhgo6LNSm84E1LBcE8s3O0wpdiRzyR9z/ZZJMlMWv37qOOb9pdJlMUEKFQ==",
|
||||
"license": "MIT",
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/ansi-styles": {
|
||||
"version": "4.3.0",
|
||||
"resolved": "https://registry.npmjs.org/ansi-styles/-/ansi-styles-4.3.0.tgz",
|
||||
@@ -356,6 +441,40 @@
|
||||
"integrity": "sha512-klpgFSWLW1ZEs8svjfb7g4qWY0YS5imI82dTg+QahUvJ8YqAY0P10Uk8tTyh9ZGuYEZEMaeJYCF5BFuX552hsw==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/aproba": {
|
||||
"version": "2.0.0",
|
||||
"resolved": "https://registry.npmjs.org/aproba/-/aproba-2.0.0.tgz",
|
||||
"integrity": "sha512-lYe4Gx7QT+MKGbDsA+Z+he/Wtef0BiwDOlK/XkBrdfsh9J/jPPXbX0tE9x9cl27Tmu5gg3QUbUrQYa/y+KOHPQ==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/are-we-there-yet": {
|
||||
"version": "2.0.0",
|
||||
"resolved": "https://registry.npmjs.org/are-we-there-yet/-/are-we-there-yet-2.0.0.tgz",
|
||||
"integrity": "sha512-Ci/qENmwHnsYo9xKIcUJN5LeDKdJ6R1Z1j9V/J5wyq8nh/mYPEpIKJbBZXtZjG04HiK7zV/p6Vs9952MrMeUIw==",
|
||||
"deprecated": "This package is no longer supported.",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"delegates": "^1.0.0",
|
||||
"readable-stream": "^3.6.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=10"
|
||||
}
|
||||
},
|
||||
"node_modules/are-we-there-yet/node_modules/readable-stream": {
|
||||
"version": "3.6.2",
|
||||
"resolved": "https://registry.npmjs.org/readable-stream/-/readable-stream-3.6.2.tgz",
|
||||
"integrity": "sha512-9u/sniCrY3D5WdsERHzHE4G2YCXqoG5FTHUiCC4SIbr6XcLZBY05ya9EKjYek9O5xOAwjGq+1JdGBAS7Q9ScoA==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"inherits": "^2.0.3",
|
||||
"string_decoder": "^1.1.1",
|
||||
"util-deprecate": "^1.0.1"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 6"
|
||||
}
|
||||
},
|
||||
"node_modules/argparse": {
|
||||
"version": "2.0.1",
|
||||
"resolved": "https://registry.npmjs.org/argparse/-/argparse-2.0.1.tgz",
|
||||
@@ -414,7 +533,6 @@
|
||||
"version": "1.0.2",
|
||||
"resolved": "https://registry.npmjs.org/balanced-match/-/balanced-match-1.0.2.tgz",
|
||||
"integrity": "sha512-3oSeUO0TMV67hN1AmbXsK4yaqU7tjiHlbxRDZOpH0KW9+CeX4bRAaX0Anxt0tx2MrpRpWwQaPwIlISEJhYU5Pw==",
|
||||
"dev": true,
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/basic-ftp": {
|
||||
@@ -426,6 +544,20 @@
|
||||
"node": ">=10.0.0"
|
||||
}
|
||||
},
|
||||
"node_modules/bcrypt": {
|
||||
"version": "5.1.1",
|
||||
"resolved": "https://registry.npmjs.org/bcrypt/-/bcrypt-5.1.1.tgz",
|
||||
"integrity": "sha512-AGBHOG5hPYZ5Xl9KXzU5iKq9516yEmvCKDg3ecP5kX2aB6UqTeXZxk2ELnDgDm6BQSMlLt9rDB4LoSMx0rYwww==",
|
||||
"hasInstallScript": true,
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"@mapbox/node-pre-gyp": "^1.0.11",
|
||||
"node-addon-api": "^5.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 10.0.0"
|
||||
}
|
||||
},
|
||||
"node_modules/bcrypt-pbkdf": {
|
||||
"version": "1.0.2",
|
||||
"resolved": "https://registry.npmjs.org/bcrypt-pbkdf/-/bcrypt-pbkdf-1.0.2.tgz",
|
||||
@@ -493,7 +625,6 @@
|
||||
"version": "1.1.11",
|
||||
"resolved": "https://registry.npmjs.org/brace-expansion/-/brace-expansion-1.1.11.tgz",
|
||||
"integrity": "sha512-iCuPHDFgrHX7H2vEI/5xpz07zSHB00TpugqhmYtVmMO6518mCuRMoOYFldEBl0g187ufozdaHgWKcYFb61qGiA==",
|
||||
"dev": true,
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"balanced-match": "^1.0.0",
|
||||
@@ -619,6 +750,15 @@
|
||||
"fsevents": "~2.3.2"
|
||||
}
|
||||
},
|
||||
"node_modules/chownr": {
|
||||
"version": "2.0.0",
|
||||
"resolved": "https://registry.npmjs.org/chownr/-/chownr-2.0.0.tgz",
|
||||
"integrity": "sha512-bIomtDF5KGpdogkLd9VspvFzk9KfpyyGlS8YFVZl7TGPBHL5snIOnxeshwVgPteQ9b4Eydl+pVbIyE1DcvCWgQ==",
|
||||
"license": "ISC",
|
||||
"engines": {
|
||||
"node": ">=10"
|
||||
}
|
||||
},
|
||||
"node_modules/cli-tableau": {
|
||||
"version": "2.0.1",
|
||||
"resolved": "https://registry.npmjs.org/cli-tableau/-/cli-tableau-2.0.1.tgz",
|
||||
@@ -648,6 +788,15 @@
|
||||
"integrity": "sha512-dOy+3AuW3a2wNbZHIuMZpTcgjGuLU/uBL/ubcZF9OXbDo8ff4O8yVp5Bf0efS8uEoYo5q4Fx7dY9OgQGXgAsQA==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/color-support": {
|
||||
"version": "1.1.3",
|
||||
"resolved": "https://registry.npmjs.org/color-support/-/color-support-1.1.3.tgz",
|
||||
"integrity": "sha512-qiBjkpbMLO/HL68y+lh4q0/O1MZFj2RX6X/KmMa3+gJD3z+WwI1ZzDHysvqHGS3mP6mznPckpXmw1nI9cJjyRg==",
|
||||
"license": "ISC",
|
||||
"bin": {
|
||||
"color-support": "bin.js"
|
||||
}
|
||||
},
|
||||
"node_modules/commander": {
|
||||
"version": "2.15.1",
|
||||
"resolved": "https://registry.npmjs.org/commander/-/commander-2.15.1.tgz",
|
||||
@@ -658,7 +807,6 @@
|
||||
"version": "0.0.1",
|
||||
"resolved": "https://registry.npmjs.org/concat-map/-/concat-map-0.0.1.tgz",
|
||||
"integrity": "sha512-/Srv4dswyQNBfohGpz9o6Yb3Gz3SrUDqBH5rTuhGR7ahtlbYKnVxw2bCFMRljaA7EXHaXZ8wsHdodFvbkhKmqg==",
|
||||
"dev": true,
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/concat-stream": {
|
||||
@@ -676,6 +824,12 @@
|
||||
"typedarray": "^0.0.6"
|
||||
}
|
||||
},
|
||||
"node_modules/console-control-strings": {
|
||||
"version": "1.1.0",
|
||||
"resolved": "https://registry.npmjs.org/console-control-strings/-/console-control-strings-1.1.0.tgz",
|
||||
"integrity": "sha512-ty/fTekppD2fIwRvnZAVdeOiGd1c7YXEixbgJTNzqcxJWKQnjJ/V1bNEEE6hygpM3WjwHFUVK6HTjWSzV4a8sQ==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/content-disposition": {
|
||||
"version": "0.5.4",
|
||||
"resolved": "https://registry.npmjs.org/content-disposition/-/content-disposition-0.5.4.tgz",
|
||||
@@ -801,6 +955,12 @@
|
||||
"node": ">= 14"
|
||||
}
|
||||
},
|
||||
"node_modules/delegates": {
|
||||
"version": "1.0.0",
|
||||
"resolved": "https://registry.npmjs.org/delegates/-/delegates-1.0.0.tgz",
|
||||
"integrity": "sha512-bd2L678uiWATM6m5Z1VzNCErI3jiGzt6HGY8OVICs40JQq/HALfbyNJmp0UDakEY4pMMaN0Ly5om/B1VI/+xfQ==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/denque": {
|
||||
"version": "2.1.0",
|
||||
"resolved": "https://registry.npmjs.org/denque/-/denque-2.1.0.tgz",
|
||||
@@ -829,6 +989,15 @@
|
||||
"npm": "1.2.8000 || >= 1.4.16"
|
||||
}
|
||||
},
|
||||
"node_modules/detect-libc": {
|
||||
"version": "2.0.3",
|
||||
"resolved": "https://registry.npmjs.org/detect-libc/-/detect-libc-2.0.3.tgz",
|
||||
"integrity": "sha512-bwy0MGW55bG41VqxxypOsdSdGqLwXPI/focwgTYCFMbdUiBAxLg9CFzG08sz2aqzknwiX7Hkl0bQENjg8iLByw==",
|
||||
"license": "Apache-2.0",
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/dotenv": {
|
||||
"version": "16.4.7",
|
||||
"resolved": "https://registry.npmjs.org/dotenv/-/dotenv-16.4.7.tgz",
|
||||
@@ -861,6 +1030,12 @@
|
||||
"integrity": "sha512-WMwm9LhRUo+WUaRN+vRuETqG89IgZphVSNkdFgeb6sS/E4OrDIN7t48CAewSHXc6C8lefD8KKfr5vY61brQlow==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/emoji-regex": {
|
||||
"version": "8.0.0",
|
||||
"resolved": "https://registry.npmjs.org/emoji-regex/-/emoji-regex-8.0.0.tgz",
|
||||
"integrity": "sha512-MSjYzcWNOA0ewAHpz0MxpYFvwg6yjy1NG3xteoqz644VCo/RPgnr1/GGt+ic3iJTzQ8Eu3TdM14SawnVUmGE6A==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/encodeurl": {
|
||||
"version": "2.0.0",
|
||||
"resolved": "https://registry.npmjs.org/encodeurl/-/encodeurl-2.0.0.tgz",
|
||||
@@ -1132,6 +1307,36 @@
|
||||
"node": ">= 0.6"
|
||||
}
|
||||
},
|
||||
"node_modules/fs-minipass": {
|
||||
"version": "2.1.0",
|
||||
"resolved": "https://registry.npmjs.org/fs-minipass/-/fs-minipass-2.1.0.tgz",
|
||||
"integrity": "sha512-V/JgOLFCS+R6Vcq0slCuaeWEdNC3ouDlJMNIsacH2VtALiu9mV4LPrHc5cDl8k5aw6J8jwgWWpiTo5RYhmIzvg==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"minipass": "^3.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 8"
|
||||
}
|
||||
},
|
||||
"node_modules/fs-minipass/node_modules/minipass": {
|
||||
"version": "3.3.6",
|
||||
"resolved": "https://registry.npmjs.org/minipass/-/minipass-3.3.6.tgz",
|
||||
"integrity": "sha512-DxiNidxSEK+tHG6zOIklvNOwm3hvCrbUrdtzY74U6HKTJxvIDfOUL5W5P2Ghd3DTkhhKPYGqeNUIh5qcM4YBfw==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"yallist": "^4.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/fs.realpath": {
|
||||
"version": "1.0.0",
|
||||
"resolved": "https://registry.npmjs.org/fs.realpath/-/fs.realpath-1.0.0.tgz",
|
||||
"integrity": "sha512-OO0pH2lK6a0hZnAdau5ItzHPI6pUlvI7jMVnxUQRtw4owF2wk8lOSabtGDCTP4Ggrg2MbGnWO9X8K1t4+fGMDw==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/fsevents": {
|
||||
"version": "2.3.3",
|
||||
"resolved": "https://registry.npmjs.org/fsevents/-/fsevents-2.3.3.tgz",
|
||||
@@ -1155,6 +1360,27 @@
|
||||
"url": "https://github.com/sponsors/ljharb"
|
||||
}
|
||||
},
|
||||
"node_modules/gauge": {
|
||||
"version": "3.0.2",
|
||||
"resolved": "https://registry.npmjs.org/gauge/-/gauge-3.0.2.tgz",
|
||||
"integrity": "sha512-+5J6MS/5XksCuXq++uFRsnUd7Ovu1XenbeuIuNRJxYWjgQbPuFhT14lAvsWfqfAmnwluf1OwMjz39HjfLPci0Q==",
|
||||
"deprecated": "This package is no longer supported.",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"aproba": "^1.0.3 || ^2.0.0",
|
||||
"color-support": "^1.1.2",
|
||||
"console-control-strings": "^1.0.0",
|
||||
"has-unicode": "^2.0.1",
|
||||
"object-assign": "^4.1.1",
|
||||
"signal-exit": "^3.0.0",
|
||||
"string-width": "^4.2.3",
|
||||
"strip-ansi": "^6.0.1",
|
||||
"wide-align": "^1.1.2"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=10"
|
||||
}
|
||||
},
|
||||
"node_modules/generate-function": {
|
||||
"version": "2.3.1",
|
||||
"resolved": "https://registry.npmjs.org/generate-function/-/generate-function-2.3.1.tgz",
|
||||
@@ -1250,6 +1476,27 @@
|
||||
"integrity": "sha512-2e/nZezdVlyCopOCYHeW0onkbZg7xP1Ad6pndPy1rCygeRykefUS6r7oA5cJRGEFvseiaz5a/qUHFVX1dd6Isg==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/glob": {
|
||||
"version": "7.2.3",
|
||||
"resolved": "https://registry.npmjs.org/glob/-/glob-7.2.3.tgz",
|
||||
"integrity": "sha512-nFR0zLpU2YCaRxwoCJvL6UvCH2JFyFVIvwTLsIf21AuHlMskA1hhTdk+LlYJtOlYt9v6dvszD2BGRqBL+iQK9Q==",
|
||||
"deprecated": "Glob versions prior to v9 are no longer supported",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"fs.realpath": "^1.0.0",
|
||||
"inflight": "^1.0.4",
|
||||
"inherits": "2",
|
||||
"minimatch": "^3.1.1",
|
||||
"once": "^1.3.0",
|
||||
"path-is-absolute": "^1.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": "*"
|
||||
},
|
||||
"funding": {
|
||||
"url": "https://github.com/sponsors/isaacs"
|
||||
}
|
||||
},
|
||||
"node_modules/glob-parent": {
|
||||
"version": "5.1.2",
|
||||
"resolved": "https://registry.npmjs.org/glob-parent/-/glob-parent-5.1.2.tgz",
|
||||
@@ -1295,6 +1542,12 @@
|
||||
"url": "https://github.com/sponsors/ljharb"
|
||||
}
|
||||
},
|
||||
"node_modules/has-unicode": {
|
||||
"version": "2.0.1",
|
||||
"resolved": "https://registry.npmjs.org/has-unicode/-/has-unicode-2.0.1.tgz",
|
||||
"integrity": "sha512-8Rf9Y83NBReMnx0gFzA8JImQACstCYWUplepDa9xprwwtmgEZUF0h/i5xSA625zB/I37EtrswSST6OXxwaaIJQ==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/hasown": {
|
||||
"version": "2.0.2",
|
||||
"resolved": "https://registry.npmjs.org/hasown/-/hasown-2.0.2.tgz",
|
||||
@@ -1414,6 +1667,17 @@
|
||||
"dev": true,
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/inflight": {
|
||||
"version": "1.0.6",
|
||||
"resolved": "https://registry.npmjs.org/inflight/-/inflight-1.0.6.tgz",
|
||||
"integrity": "sha512-k92I/b08q4wvFscXCLvqfsHCrjrF7yiXsQuIVvVE7N82W3+aqpzuUdBbfhWcy/FZR3/4IgflMgKLOsvPDrGCJA==",
|
||||
"deprecated": "This module is not supported, and leaks memory. Do not use it. Check out lru-cache if you want a good and tested way to coalesce async requests by a key value, which is much more comprehensive and powerful.",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"once": "^1.3.0",
|
||||
"wrappy": "1"
|
||||
}
|
||||
},
|
||||
"node_modules/inherits": {
|
||||
"version": "2.0.4",
|
||||
"resolved": "https://registry.npmjs.org/inherits/-/inherits-2.0.4.tgz",
|
||||
@@ -1490,6 +1754,15 @@
|
||||
"node": ">=0.10.0"
|
||||
}
|
||||
},
|
||||
"node_modules/is-fullwidth-code-point": {
|
||||
"version": "3.0.0",
|
||||
"resolved": "https://registry.npmjs.org/is-fullwidth-code-point/-/is-fullwidth-code-point-3.0.0.tgz",
|
||||
"integrity": "sha512-zymm5+u+sCsSWyD9qNaejV3DFvhCKclKdizYaJUuHA83RLjb7nSuGnddCHGv0hk+KY7BMAlsWeK4Ueg6EV6XQg==",
|
||||
"license": "MIT",
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/is-glob": {
|
||||
"version": "4.0.3",
|
||||
"resolved": "https://registry.npmjs.org/is-glob/-/is-glob-4.0.3.tgz",
|
||||
@@ -1605,6 +1878,30 @@
|
||||
"url": "https://github.com/sponsors/wellwelwel"
|
||||
}
|
||||
},
|
||||
"node_modules/make-dir": {
|
||||
"version": "3.1.0",
|
||||
"resolved": "https://registry.npmjs.org/make-dir/-/make-dir-3.1.0.tgz",
|
||||
"integrity": "sha512-g3FeP20LNwhALb/6Cz6Dd4F2ngze0jz7tbzrD2wAV+o9FeNHe4rL+yK2md0J/fiSf1sa1ADhXqi5+oVwOM/eGw==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"semver": "^6.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
},
|
||||
"funding": {
|
||||
"url": "https://github.com/sponsors/sindresorhus"
|
||||
}
|
||||
},
|
||||
"node_modules/make-dir/node_modules/semver": {
|
||||
"version": "6.3.1",
|
||||
"resolved": "https://registry.npmjs.org/semver/-/semver-6.3.1.tgz",
|
||||
"integrity": "sha512-BR7VvDCVHO+q2xBEWskxS6DJE1qRnb7DxzUrogb71CWoSficBxYsiAGd+Kl0mmq/MprG9yArRkyrQxTO6XjMzA==",
|
||||
"license": "ISC",
|
||||
"bin": {
|
||||
"semver": "bin/semver.js"
|
||||
}
|
||||
},
|
||||
"node_modules/math-intrinsics": {
|
||||
"version": "1.1.0",
|
||||
"resolved": "https://registry.npmjs.org/math-intrinsics/-/math-intrinsics-1.1.0.tgz",
|
||||
@@ -1678,7 +1975,6 @@
|
||||
"version": "3.1.2",
|
||||
"resolved": "https://registry.npmjs.org/minimatch/-/minimatch-3.1.2.tgz",
|
||||
"integrity": "sha512-J7p63hRiAjw1NDEww1W7i37+ByIrOWO5XQQAzZ3VOcL0PNybwpfmV/N05zFAzwQ9USyEcX6t3UO+K5aqBQOIHw==",
|
||||
"dev": true,
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"brace-expansion": "^1.1.7"
|
||||
@@ -1696,6 +1992,40 @@
|
||||
"url": "https://github.com/sponsors/ljharb"
|
||||
}
|
||||
},
|
||||
"node_modules/minipass": {
|
||||
"version": "5.0.0",
|
||||
"resolved": "https://registry.npmjs.org/minipass/-/minipass-5.0.0.tgz",
|
||||
"integrity": "sha512-3FnjYuehv9k6ovOEbyOswadCDPX1piCfhV8ncmYtHOjuPwylVWsghTLo7rabjC3Rx5xD4HDx8Wm1xnMF7S5qFQ==",
|
||||
"license": "ISC",
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/minizlib": {
|
||||
"version": "2.1.2",
|
||||
"resolved": "https://registry.npmjs.org/minizlib/-/minizlib-2.1.2.tgz",
|
||||
"integrity": "sha512-bAxsR8BVfj60DWXHE3u30oHzfl4G7khkSuPW+qvpd7jFRHm7dLxOjUk1EHACJ/hxLY8phGJ0YhYHZo7jil7Qdg==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"minipass": "^3.0.0",
|
||||
"yallist": "^4.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 8"
|
||||
}
|
||||
},
|
||||
"node_modules/minizlib/node_modules/minipass": {
|
||||
"version": "3.3.6",
|
||||
"resolved": "https://registry.npmjs.org/minipass/-/minipass-3.3.6.tgz",
|
||||
"integrity": "sha512-DxiNidxSEK+tHG6zOIklvNOwm3hvCrbUrdtzY74U6HKTJxvIDfOUL5W5P2Ghd3DTkhhKPYGqeNUIh5qcM4YBfw==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"yallist": "^4.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/mkdirp": {
|
||||
"version": "1.0.4",
|
||||
"resolved": "https://registry.npmjs.org/mkdirp/-/mkdirp-1.0.4.tgz",
|
||||
@@ -1857,6 +2187,32 @@
|
||||
"node": ">= 0.4.0"
|
||||
}
|
||||
},
|
||||
"node_modules/node-addon-api": {
|
||||
"version": "5.1.0",
|
||||
"resolved": "https://registry.npmjs.org/node-addon-api/-/node-addon-api-5.1.0.tgz",
|
||||
"integrity": "sha512-eh0GgfEkpnoWDq+VY8OyvYhFEzBk6jIYbRKdIlyTiAXIVJ8PyBaKb0rp7oDtoddbdoHWhq8wwr+XZ81F1rpNdA==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/node-fetch": {
|
||||
"version": "2.7.0",
|
||||
"resolved": "https://registry.npmjs.org/node-fetch/-/node-fetch-2.7.0.tgz",
|
||||
"integrity": "sha512-c4FRfUm/dbcWZ7U+1Wq0AwCyFL+3nt2bEw05wfxSz+DWpWsitgmSgYmy2dQdWyKC1694ELPqMs/YzUSNozLt8A==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"whatwg-url": "^5.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": "4.x || >=6.0.0"
|
||||
},
|
||||
"peerDependencies": {
|
||||
"encoding": "^0.1.0"
|
||||
},
|
||||
"peerDependenciesMeta": {
|
||||
"encoding": {
|
||||
"optional": true
|
||||
}
|
||||
}
|
||||
},
|
||||
"node_modules/nodemon": {
|
||||
"version": "3.1.9",
|
||||
"resolved": "https://registry.npmjs.org/nodemon/-/nodemon-3.1.9.tgz",
|
||||
@@ -1934,6 +2290,21 @@
|
||||
"node": ">=4"
|
||||
}
|
||||
},
|
||||
"node_modules/nopt": {
|
||||
"version": "5.0.0",
|
||||
"resolved": "https://registry.npmjs.org/nopt/-/nopt-5.0.0.tgz",
|
||||
"integrity": "sha512-Tbj67rffqceeLpcRXrT7vKAN8CwfPeIBgM7E6iBkmKLV7bEMwpGgYLGv0jACUsECaa/vuxP0IjEont6umdMgtQ==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"abbrev": "1"
|
||||
},
|
||||
"bin": {
|
||||
"nopt": "bin/nopt.js"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=6"
|
||||
}
|
||||
},
|
||||
"node_modules/normalize-path": {
|
||||
"version": "3.0.0",
|
||||
"resolved": "https://registry.npmjs.org/normalize-path/-/normalize-path-3.0.0.tgz",
|
||||
@@ -1943,6 +2314,19 @@
|
||||
"node": ">=0.10.0"
|
||||
}
|
||||
},
|
||||
"node_modules/npmlog": {
|
||||
"version": "5.0.1",
|
||||
"resolved": "https://registry.npmjs.org/npmlog/-/npmlog-5.0.1.tgz",
|
||||
"integrity": "sha512-AqZtDUWOMKs1G/8lwylVjrdYgqA4d9nu8hc+0gzRxlDb1I10+FHBGMXs6aiQHFdCUUlqH99MUMuLfzWDNDtfxw==",
|
||||
"deprecated": "This package is no longer supported.",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"are-we-there-yet": "^2.0.0",
|
||||
"console-control-strings": "^1.1.0",
|
||||
"gauge": "^3.0.0",
|
||||
"set-blocking": "^2.0.0"
|
||||
}
|
||||
},
|
||||
"node_modules/nssocket": {
|
||||
"version": "0.6.0",
|
||||
"resolved": "https://registry.npmjs.org/nssocket/-/nssocket-0.6.0.tgz",
|
||||
@@ -1995,6 +2379,15 @@
|
||||
"node": ">= 0.8"
|
||||
}
|
||||
},
|
||||
"node_modules/once": {
|
||||
"version": "1.4.0",
|
||||
"resolved": "https://registry.npmjs.org/once/-/once-1.4.0.tgz",
|
||||
"integrity": "sha512-lNaJgI+2Q5URQBkccEKHTQOPaXdUxnZZElQTZY0MFUAuaEqe1E+Nyvgdz/aIyNi6Z9MzO5dv1H8n58/GELp3+w==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"wrappy": "1"
|
||||
}
|
||||
},
|
||||
"node_modules/pac-proxy-agent": {
|
||||
"version": "7.1.0",
|
||||
"resolved": "https://registry.npmjs.org/pac-proxy-agent/-/pac-proxy-agent-7.1.0.tgz",
|
||||
@@ -2065,6 +2458,15 @@
|
||||
"node": ">= 0.8"
|
||||
}
|
||||
},
|
||||
"node_modules/path-is-absolute": {
|
||||
"version": "1.0.1",
|
||||
"resolved": "https://registry.npmjs.org/path-is-absolute/-/path-is-absolute-1.0.1.tgz",
|
||||
"integrity": "sha512-AVbw3UJ2e9bq64vSaS9Am0fje1Pa8pbGqTTsmXfaIiMpnr5DlDhfJOuLj9Sf95ZPVDAUerDfEk88MPmPe7UCQg==",
|
||||
"license": "MIT",
|
||||
"engines": {
|
||||
"node": ">=0.10.0"
|
||||
}
|
||||
},
|
||||
"node_modules/path-parse": {
|
||||
"version": "1.0.7",
|
||||
"resolved": "https://registry.npmjs.org/path-parse/-/path-parse-1.0.7.tgz",
|
||||
@@ -2077,6 +2479,95 @@
|
||||
"integrity": "sha512-RA1GjUVMnvYFxuqovrEqZoxxW5NUZqbwKtYz/Tt7nXerk0LbLblQmrsgdeOxV5SFHf0UDggjS/bSeOZwt1pmEQ==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/pg": {
|
||||
"version": "8.13.2",
|
||||
"resolved": "https://registry.npmjs.org/pg/-/pg-8.13.2.tgz",
|
||||
"integrity": "sha512-L5QkPvTjVWWHbLaFjCkOSplpb2uCiRYbg0IJ2okCy5ClYfWlSgDDnvdR6dyw3EWAH2AfS4j8E61QFI7gLfTtlw==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"pg-connection-string": "^2.7.0",
|
||||
"pg-pool": "^3.7.1",
|
||||
"pg-protocol": "^1.7.1",
|
||||
"pg-types": "^2.1.0",
|
||||
"pgpass": "1.x"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">= 8.0.0"
|
||||
},
|
||||
"optionalDependencies": {
|
||||
"pg-cloudflare": "^1.1.1"
|
||||
},
|
||||
"peerDependencies": {
|
||||
"pg-native": ">=3.0.1"
|
||||
},
|
||||
"peerDependenciesMeta": {
|
||||
"pg-native": {
|
||||
"optional": true
|
||||
}
|
||||
}
|
||||
},
|
||||
"node_modules/pg-cloudflare": {
|
||||
"version": "1.1.1",
|
||||
"resolved": "https://registry.npmjs.org/pg-cloudflare/-/pg-cloudflare-1.1.1.tgz",
|
||||
"integrity": "sha512-xWPagP/4B6BgFO+EKz3JONXv3YDgvkbVrGw2mTo3D6tVDQRh1e7cqVGvyR3BE+eQgAvx1XhW/iEASj4/jCWl3Q==",
|
||||
"license": "MIT",
|
||||
"optional": true
|
||||
},
|
||||
"node_modules/pg-connection-string": {
|
||||
"version": "2.7.0",
|
||||
"resolved": "https://registry.npmjs.org/pg-connection-string/-/pg-connection-string-2.7.0.tgz",
|
||||
"integrity": "sha512-PI2W9mv53rXJQEOb8xNR8lH7Hr+EKa6oJa38zsK0S/ky2er16ios1wLKhZyxzD7jUReiWokc9WK5nxSnC7W1TA==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/pg-int8": {
|
||||
"version": "1.0.1",
|
||||
"resolved": "https://registry.npmjs.org/pg-int8/-/pg-int8-1.0.1.tgz",
|
||||
"integrity": "sha512-WCtabS6t3c8SkpDBUlb1kjOs7l66xsGdKpIPZsg4wR+B3+u9UAum2odSsF9tnvxg80h4ZxLWMy4pRjOsFIqQpw==",
|
||||
"license": "ISC",
|
||||
"engines": {
|
||||
"node": ">=4.0.0"
|
||||
}
|
||||
},
|
||||
"node_modules/pg-pool": {
|
||||
"version": "3.7.1",
|
||||
"resolved": "https://registry.npmjs.org/pg-pool/-/pg-pool-3.7.1.tgz",
|
||||
"integrity": "sha512-xIOsFoh7Vdhojas6q3596mXFsR8nwBQBXX5JiV7p9buEVAGqYL4yFzclON5P9vFrpu1u7Zwl2oriyDa89n0wbw==",
|
||||
"license": "MIT",
|
||||
"peerDependencies": {
|
||||
"pg": ">=8.0"
|
||||
}
|
||||
},
|
||||
"node_modules/pg-protocol": {
|
||||
"version": "1.7.1",
|
||||
"resolved": "https://registry.npmjs.org/pg-protocol/-/pg-protocol-1.7.1.tgz",
|
||||
"integrity": "sha512-gjTHWGYWsEgy9MsY0Gp6ZJxV24IjDqdpTW7Eh0x+WfJLFsm/TJx1MzL6T0D88mBvkpxotCQ6TwW6N+Kko7lhgQ==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/pg-types": {
|
||||
"version": "2.2.0",
|
||||
"resolved": "https://registry.npmjs.org/pg-types/-/pg-types-2.2.0.tgz",
|
||||
"integrity": "sha512-qTAAlrEsl8s4OiEQY69wDvcMIdQN6wdz5ojQiOy6YRMuynxenON0O5oCpJI6lshc6scgAY8qvJ2On/p+CXY0GA==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"pg-int8": "1.0.1",
|
||||
"postgres-array": "~2.0.0",
|
||||
"postgres-bytea": "~1.0.0",
|
||||
"postgres-date": "~1.0.4",
|
||||
"postgres-interval": "^1.1.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=4"
|
||||
}
|
||||
},
|
||||
"node_modules/pgpass": {
|
||||
"version": "1.0.5",
|
||||
"resolved": "https://registry.npmjs.org/pgpass/-/pgpass-1.0.5.tgz",
|
||||
"integrity": "sha512-FdW9r/jQZhSeohs1Z3sI1yxFQNFvMcnmfuj4WBMUTxOrAyLMaTcE1aAMBiTlbMNaXvBCQuVi0R7hd8udDSP7ug==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"split2": "^4.1.0"
|
||||
}
|
||||
},
|
||||
"node_modules/picomatch": {
|
||||
"version": "2.3.1",
|
||||
"resolved": "https://registry.npmjs.org/picomatch/-/picomatch-2.3.1.tgz",
|
||||
@@ -2320,6 +2811,45 @@
|
||||
"integrity": "sha512-6FlzubTLZG3J2a/NVCAleEhjzq5oxgHyaCU9yYXvcLsvoVaHJq/s5xXI6/XXP6tz7R9xAOtHnSO/tXtF3WRTlA==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/postgres-array": {
|
||||
"version": "2.0.0",
|
||||
"resolved": "https://registry.npmjs.org/postgres-array/-/postgres-array-2.0.0.tgz",
|
||||
"integrity": "sha512-VpZrUqU5A69eQyW2c5CA1jtLecCsN2U/bD6VilrFDWq5+5UIEVO7nazS3TEcHf1zuPYO/sqGvUvW62g86RXZuA==",
|
||||
"license": "MIT",
|
||||
"engines": {
|
||||
"node": ">=4"
|
||||
}
|
||||
},
|
||||
"node_modules/postgres-bytea": {
|
||||
"version": "1.0.0",
|
||||
"resolved": "https://registry.npmjs.org/postgres-bytea/-/postgres-bytea-1.0.0.tgz",
|
||||
"integrity": "sha512-xy3pmLuQqRBZBXDULy7KbaitYqLcmxigw14Q5sj8QBVLqEwXfeybIKVWiqAXTlcvdvb0+xkOtDbfQMOf4lST1w==",
|
||||
"license": "MIT",
|
||||
"engines": {
|
||||
"node": ">=0.10.0"
|
||||
}
|
||||
},
|
||||
"node_modules/postgres-date": {
|
||||
"version": "1.0.7",
|
||||
"resolved": "https://registry.npmjs.org/postgres-date/-/postgres-date-1.0.7.tgz",
|
||||
"integrity": "sha512-suDmjLVQg78nMK2UZ454hAG+OAW+HQPZ6n++TNDUX+L0+uUlLywnoxJKDou51Zm+zTCjrCl0Nq6J9C5hP9vK/Q==",
|
||||
"license": "MIT",
|
||||
"engines": {
|
||||
"node": ">=0.10.0"
|
||||
}
|
||||
},
|
||||
"node_modules/postgres-interval": {
|
||||
"version": "1.2.0",
|
||||
"resolved": "https://registry.npmjs.org/postgres-interval/-/postgres-interval-1.2.0.tgz",
|
||||
"integrity": "sha512-9ZhXKM/rw350N1ovuWHbGxnGh/SNJ4cnxHiM0rxE4VN41wsg8P8zWn9hv/buK00RP4WvlOyr/RBDiptyxVbkZQ==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"xtend": "^4.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=0.10.0"
|
||||
}
|
||||
},
|
||||
"node_modules/process-nextick-args": {
|
||||
"version": "2.0.1",
|
||||
"resolved": "https://registry.npmjs.org/process-nextick-args/-/process-nextick-args-2.0.1.tgz",
|
||||
@@ -2544,6 +3074,22 @@
|
||||
"url": "https://github.com/sponsors/ljharb"
|
||||
}
|
||||
},
|
||||
"node_modules/rimraf": {
|
||||
"version": "3.0.2",
|
||||
"resolved": "https://registry.npmjs.org/rimraf/-/rimraf-3.0.2.tgz",
|
||||
"integrity": "sha512-JZkJMZkAGFFPP2YqXZXPbMlMBgsxzE8ILs4lMIX/2o0L9UBw9O/Y3o6wFw/i9YLapcUJWwqbi3kdxIPdC62TIA==",
|
||||
"deprecated": "Rimraf versions prior to v4 are no longer supported",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"glob": "^7.1.3"
|
||||
},
|
||||
"bin": {
|
||||
"rimraf": "bin.js"
|
||||
},
|
||||
"funding": {
|
||||
"url": "https://github.com/sponsors/isaacs"
|
||||
}
|
||||
},
|
||||
"node_modules/run-series": {
|
||||
"version": "1.1.9",
|
||||
"resolved": "https://registry.npmjs.org/run-series/-/run-series-1.1.9.tgz",
|
||||
@@ -2667,6 +3213,12 @@
|
||||
"node": ">= 0.8.0"
|
||||
}
|
||||
},
|
||||
"node_modules/set-blocking": {
|
||||
"version": "2.0.0",
|
||||
"resolved": "https://registry.npmjs.org/set-blocking/-/set-blocking-2.0.0.tgz",
|
||||
"integrity": "sha512-KiKBS8AnWGEyLzofFfmvKwpdPzqiy16LvQfK3yv/fVH7Bj13/wl3JSR1J+rfgRE9q7xUJK4qvgS8raSOeLUehw==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/setprototypeof": {
|
||||
"version": "1.2.0",
|
||||
"resolved": "https://registry.npmjs.org/setprototypeof/-/setprototypeof-1.2.0.tgz",
|
||||
@@ -2850,6 +3402,15 @@
|
||||
"source-map": "^0.6.0"
|
||||
}
|
||||
},
|
||||
"node_modules/split2": {
|
||||
"version": "4.2.0",
|
||||
"resolved": "https://registry.npmjs.org/split2/-/split2-4.2.0.tgz",
|
||||
"integrity": "sha512-UcjcJOWknrNkF6PLX83qcHM6KHgVKNkV62Y8a5uYDVv9ydGQVwAHMKqHdJje1VTWpljG0WYpCDhrCdAOYH4TWg==",
|
||||
"license": "ISC",
|
||||
"engines": {
|
||||
"node": ">= 10.x"
|
||||
}
|
||||
},
|
||||
"node_modules/sprintf-js": {
|
||||
"version": "1.1.2",
|
||||
"resolved": "https://registry.npmjs.org/sprintf-js/-/sprintf-js-1.1.2.tgz",
|
||||
@@ -2914,6 +3475,32 @@
|
||||
"integrity": "sha512-Gd2UZBJDkXlY7GbJxfsE8/nvKkUEU1G38c1siN6QP6a9PT9MmHB8GnpscSmMJSoF8LOIrt8ud/wPtojys4G6+g==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/string-width": {
|
||||
"version": "4.2.3",
|
||||
"resolved": "https://registry.npmjs.org/string-width/-/string-width-4.2.3.tgz",
|
||||
"integrity": "sha512-wKyQRQpjJ0sIp62ErSZdGsjMJWsap5oRNihHhu6G7JVO/9jIB6UyevL+tXuOqrng8j/cxKTWyWUwvSTriiZz/g==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"emoji-regex": "^8.0.0",
|
||||
"is-fullwidth-code-point": "^3.0.0",
|
||||
"strip-ansi": "^6.0.1"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/strip-ansi": {
|
||||
"version": "6.0.1",
|
||||
"resolved": "https://registry.npmjs.org/strip-ansi/-/strip-ansi-6.0.1.tgz",
|
||||
"integrity": "sha512-Y38VPSHcqkFrCpFnQ9vuSXmquuv5oXOKpGeT6aGrr3o3Gc9AlVa6JBfUSOCnbxGGZF+/0ooI7KrPuUSztUdU5A==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"ansi-regex": "^5.0.1"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=8"
|
||||
}
|
||||
},
|
||||
"node_modules/supports-color": {
|
||||
"version": "7.2.0",
|
||||
"resolved": "https://registry.npmjs.org/supports-color/-/supports-color-7.2.0.tgz",
|
||||
@@ -2965,6 +3552,23 @@
|
||||
"url": "https://www.buymeacoffee.com/systeminfo"
|
||||
}
|
||||
},
|
||||
"node_modules/tar": {
|
||||
"version": "6.2.1",
|
||||
"resolved": "https://registry.npmjs.org/tar/-/tar-6.2.1.tgz",
|
||||
"integrity": "sha512-DZ4yORTwrbTj/7MZYq2w+/ZFdI6OZ/f9SFHR+71gIVUZhOQPHzVCLpvRnPgyaMpfWxxk/4ONva3GQSyNIKRv6A==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"chownr": "^2.0.0",
|
||||
"fs-minipass": "^2.0.0",
|
||||
"minipass": "^5.0.0",
|
||||
"minizlib": "^2.1.1",
|
||||
"mkdirp": "^1.0.3",
|
||||
"yallist": "^4.0.0"
|
||||
},
|
||||
"engines": {
|
||||
"node": ">=10"
|
||||
}
|
||||
},
|
||||
"node_modules/to-regex-range": {
|
||||
"version": "5.0.1",
|
||||
"resolved": "https://registry.npmjs.org/to-regex-range/-/to-regex-range-5.0.1.tgz",
|
||||
@@ -2996,6 +3600,12 @@
|
||||
"nodetouch": "bin/nodetouch.js"
|
||||
}
|
||||
},
|
||||
"node_modules/tr46": {
|
||||
"version": "0.0.3",
|
||||
"resolved": "https://registry.npmjs.org/tr46/-/tr46-0.0.3.tgz",
|
||||
"integrity": "sha512-N3WMsuqV66lT30CrXNbEjx4GEwlow3v6rr4mCcv6prnfwhS01rkgyFdjPNBYd9br7LpXV1+Emh01fHnq2Gdgrw==",
|
||||
"license": "MIT"
|
||||
},
|
||||
"node_modules/tslib": {
|
||||
"version": "1.9.3",
|
||||
"resolved": "https://registry.npmjs.org/tslib/-/tslib-1.9.3.tgz",
|
||||
@@ -3132,6 +3742,37 @@
|
||||
"lodash": "^4.17.14"
|
||||
}
|
||||
},
|
||||
"node_modules/webidl-conversions": {
|
||||
"version": "3.0.1",
|
||||
"resolved": "https://registry.npmjs.org/webidl-conversions/-/webidl-conversions-3.0.1.tgz",
|
||||
"integrity": "sha512-2JAn3z8AR6rjK8Sm8orRC0h/bcl/DqL7tRPdGZ4I1CjdF+EaMLmYxBHyXuKL849eucPFhvBoxMsflfOb8kxaeQ==",
|
||||
"license": "BSD-2-Clause"
|
||||
},
|
||||
"node_modules/whatwg-url": {
|
||||
"version": "5.0.0",
|
||||
"resolved": "https://registry.npmjs.org/whatwg-url/-/whatwg-url-5.0.0.tgz",
|
||||
"integrity": "sha512-saE57nupxk6v3HY35+jzBwYa0rKSy0XR8JSxZPwgLr7ys0IBzhGviA1/TUGJLmSVqs8pb9AnvICXEuOHLprYTw==",
|
||||
"license": "MIT",
|
||||
"dependencies": {
|
||||
"tr46": "~0.0.3",
|
||||
"webidl-conversions": "^3.0.0"
|
||||
}
|
||||
},
|
||||
"node_modules/wide-align": {
|
||||
"version": "1.1.5",
|
||||
"resolved": "https://registry.npmjs.org/wide-align/-/wide-align-1.1.5.tgz",
|
||||
"integrity": "sha512-eDMORYaPNZ4sQIuuYPDHdQvf4gyCF9rEEV/yPxGfwPkRodwEgiMUUXTx/dex+Me0wxx53S+NgUHaP7y3MGlDmg==",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"string-width": "^1.0.2 || 2 || 3 || 4"
|
||||
}
|
||||
},
|
||||
"node_modules/wrappy": {
|
||||
"version": "1.0.2",
|
||||
"resolved": "https://registry.npmjs.org/wrappy/-/wrappy-1.0.2.tgz",
|
||||
"integrity": "sha512-l4Sp/DRseor9wL6EvV2+TuQn63dMkPjZ/sp9XkghTEbV9KlPS1xUsZ3u7/IQO4wxtcFB4bgpQPRcR3QCvezPcQ==",
|
||||
"license": "ISC"
|
||||
},
|
||||
"node_modules/ws": {
|
||||
"version": "7.5.10",
|
||||
"resolved": "https://registry.npmjs.org/ws/-/ws-7.5.10.tgz",
|
||||
|
||||
@@ -18,12 +18,14 @@
|
||||
"author": "",
|
||||
"license": "ISC",
|
||||
"dependencies": {
|
||||
"bcrypt": "^5.1.1",
|
||||
"cors": "^2.8.5",
|
||||
"csv-parse": "^5.6.0",
|
||||
"dotenv": "^16.4.7",
|
||||
"express": "^4.18.2",
|
||||
"multer": "^1.4.5-lts.1",
|
||||
"mysql2": "^3.12.0",
|
||||
"pg": "^8.13.2",
|
||||
"pm2": "^5.3.0",
|
||||
"ssh2": "^1.16.0",
|
||||
"uuid": "^9.0.1"
|
||||
|
||||
79
inventory-server/scripts/add-user.js
Normal file
79
inventory-server/scripts/add-user.js
Normal file
@@ -0,0 +1,79 @@
|
||||
const { Client } = require('pg');
|
||||
const bcrypt = require('bcrypt');
|
||||
const path = require('path');
|
||||
const readline = require('readline');
|
||||
require('dotenv').config({ path: path.resolve(__dirname, '../.env') });
|
||||
|
||||
const SALT_ROUNDS = 10;
|
||||
|
||||
const dbConfig = {
|
||||
host: process.env.DB_HOST,
|
||||
user: process.env.DB_USER,
|
||||
password: process.env.DB_PASSWORD,
|
||||
database: process.env.DB_NAME,
|
||||
port: process.env.DB_PORT || 5432
|
||||
};
|
||||
|
||||
function prompt(question) {
|
||||
const rl = readline.createInterface({
|
||||
input: process.stdin,
|
||||
output: process.stdout
|
||||
});
|
||||
|
||||
return new Promise(resolve => {
|
||||
rl.question(question, answer => {
|
||||
rl.close();
|
||||
resolve(answer);
|
||||
});
|
||||
});
|
||||
}
|
||||
|
||||
async function addUser() {
|
||||
try {
|
||||
const username = await prompt('Enter username: ');
|
||||
if (!username.trim()) {
|
||||
console.error('Error: Username cannot be empty');
|
||||
process.exit(1);
|
||||
}
|
||||
|
||||
const password = await prompt('Enter password: ');
|
||||
if (!password.trim()) {
|
||||
console.error('Error: Password cannot be empty');
|
||||
process.exit(1);
|
||||
}
|
||||
|
||||
const client = new Client(dbConfig);
|
||||
await client.connect();
|
||||
|
||||
// Check if user exists
|
||||
const checkUser = await client.query(
|
||||
'SELECT username FROM users WHERE username = $1',
|
||||
[username]
|
||||
);
|
||||
|
||||
if (checkUser.rows.length > 0) {
|
||||
console.error('Error: Username already exists');
|
||||
process.exit(1);
|
||||
}
|
||||
|
||||
// Hash password
|
||||
const hashedPassword = await bcrypt.hash(password, SALT_ROUNDS);
|
||||
|
||||
// Insert new user
|
||||
await client.query(
|
||||
'INSERT INTO users (username, password) VALUES ($1, $2)',
|
||||
[username, hashedPassword]
|
||||
);
|
||||
|
||||
console.log(`User '${username}' created successfully`);
|
||||
await client.end();
|
||||
} catch (error) {
|
||||
console.error('Error creating user:', error.message);
|
||||
process.exit(1);
|
||||
}
|
||||
}
|
||||
|
||||
// Run if called directly
|
||||
if (require.main === module) {
|
||||
addUser();
|
||||
}
|
||||
@@ -14,7 +14,15 @@ function outputProgress(data) {
|
||||
function runScript(scriptPath) {
|
||||
return new Promise((resolve, reject) => {
|
||||
const child = spawn('node', [scriptPath], {
|
||||
stdio: ['inherit', 'pipe', 'pipe']
|
||||
stdio: ['inherit', 'pipe', 'pipe'],
|
||||
env: {
|
||||
...process.env,
|
||||
PGHOST: process.env.DB_HOST,
|
||||
PGUSER: process.env.DB_USER,
|
||||
PGPASSWORD: process.env.DB_PASSWORD,
|
||||
PGDATABASE: process.env.DB_NAME,
|
||||
PGPORT: process.env.DB_PORT || '5432'
|
||||
}
|
||||
});
|
||||
|
||||
let output = '';
|
||||
|
||||
@@ -1,4 +1,4 @@
|
||||
const mysql = require('mysql2/promise');
|
||||
const { Client } = require('pg');
|
||||
const path = require('path');
|
||||
const dotenv = require('dotenv');
|
||||
const fs = require('fs');
|
||||
@@ -10,7 +10,7 @@ const dbConfig = {
|
||||
user: process.env.DB_USER,
|
||||
password: process.env.DB_PASSWORD,
|
||||
database: process.env.DB_NAME,
|
||||
multipleStatements: true
|
||||
port: process.env.DB_PORT || 5432
|
||||
};
|
||||
|
||||
// Helper function to output progress in JSON format
|
||||
@@ -120,46 +120,42 @@ async function resetDatabase() {
|
||||
}
|
||||
});
|
||||
|
||||
const connection = await mysql.createConnection(dbConfig);
|
||||
const client = new Client(dbConfig);
|
||||
await client.connect();
|
||||
|
||||
try {
|
||||
// Check MySQL privileges
|
||||
// Check PostgreSQL version and user
|
||||
outputProgress({
|
||||
operation: 'Checking privileges',
|
||||
message: 'Verifying MySQL user privileges...'
|
||||
operation: 'Checking database',
|
||||
message: 'Verifying PostgreSQL version and user privileges...'
|
||||
});
|
||||
|
||||
const [grants] = await connection.query('SHOW GRANTS');
|
||||
const versionResult = await client.query('SELECT version()');
|
||||
const userResult = await client.query('SELECT current_user, current_database()');
|
||||
|
||||
outputProgress({
|
||||
operation: 'User privileges',
|
||||
operation: 'Database info',
|
||||
message: {
|
||||
grants: grants.map(g => Object.values(g)[0])
|
||||
version: versionResult.rows[0].version,
|
||||
user: userResult.rows[0].current_user,
|
||||
database: userResult.rows[0].current_database
|
||||
}
|
||||
});
|
||||
|
||||
// Enable warnings as errors
|
||||
await connection.query('SET SESSION sql_notes = 1');
|
||||
|
||||
// Log database config (without sensitive info)
|
||||
outputProgress({
|
||||
operation: 'Database config',
|
||||
message: `Using database: ${dbConfig.database} on host: ${dbConfig.host}`
|
||||
});
|
||||
|
||||
// Get list of all tables in the current database
|
||||
outputProgress({
|
||||
operation: 'Getting table list',
|
||||
message: 'Retrieving all table names...'
|
||||
});
|
||||
|
||||
const [tables] = await connection.query(`
|
||||
SELECT GROUP_CONCAT(table_name) as tables
|
||||
FROM information_schema.tables
|
||||
WHERE table_schema = DATABASE()
|
||||
AND table_name NOT IN ('users', 'import_history', 'calculate_history')
|
||||
const tablesResult = await client.query(`
|
||||
SELECT string_agg(tablename, ', ') as tables
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
AND tablename NOT IN ('users', 'calculate_history', 'import_history');
|
||||
`);
|
||||
|
||||
if (!tables[0].tables) {
|
||||
if (!tablesResult.rows[0].tables) {
|
||||
outputProgress({
|
||||
operation: 'No tables found',
|
||||
message: 'Database is already empty'
|
||||
@@ -170,18 +166,47 @@ async function resetDatabase() {
|
||||
message: 'Dropping all existing tables...'
|
||||
});
|
||||
|
||||
await connection.query('SET FOREIGN_KEY_CHECKS = 0');
|
||||
const dropQuery = `
|
||||
DROP TABLE IF EXISTS
|
||||
${tables[0].tables
|
||||
.split(',')
|
||||
.filter(table => !['users', 'calculate_history'].includes(table))
|
||||
.map(table => '`' + table + '`')
|
||||
.join(', ')}
|
||||
`;
|
||||
await connection.query(dropQuery);
|
||||
await connection.query('SET FOREIGN_KEY_CHECKS = 1');
|
||||
// Disable triggers/foreign key checks
|
||||
await client.query('SET session_replication_role = \'replica\';');
|
||||
|
||||
// Drop all tables except users
|
||||
const tables = tablesResult.rows[0].tables.split(', ');
|
||||
for (const table of tables) {
|
||||
if (!['users'].includes(table)) {
|
||||
await client.query(`DROP TABLE IF EXISTS "${table}" CASCADE`);
|
||||
}
|
||||
}
|
||||
|
||||
// Drop types if they exist
|
||||
await client.query('DROP TYPE IF EXISTS calculation_status CASCADE;');
|
||||
await client.query('DROP TYPE IF EXISTS module_name CASCADE;');
|
||||
|
||||
// Re-enable triggers/foreign key checks
|
||||
await client.query('SET session_replication_role = \'origin\';');
|
||||
}
|
||||
|
||||
// Create enum types
|
||||
outputProgress({
|
||||
operation: 'Creating enum types',
|
||||
message: 'Setting up required enum types...'
|
||||
});
|
||||
|
||||
await client.query(`
|
||||
CREATE TYPE calculation_status AS ENUM ('running', 'completed', 'failed', 'cancelled')
|
||||
`);
|
||||
|
||||
await client.query(`
|
||||
CREATE TYPE module_name AS ENUM (
|
||||
'product_metrics',
|
||||
'time_aggregates',
|
||||
'financial_metrics',
|
||||
'vendor_metrics',
|
||||
'category_metrics',
|
||||
'brand_metrics',
|
||||
'sales_forecasts',
|
||||
'abc_classification'
|
||||
)
|
||||
`);
|
||||
|
||||
// Read and execute main schema (core tables)
|
||||
outputProgress({
|
||||
@@ -223,35 +248,24 @@ async function resetDatabase() {
|
||||
for (let i = 0; i < statements.length; i++) {
|
||||
const stmt = statements[i];
|
||||
try {
|
||||
const [result, fields] = await connection.query(stmt);
|
||||
|
||||
// Check for warnings
|
||||
const [warnings] = await connection.query('SHOW WARNINGS');
|
||||
if (warnings && warnings.length > 0) {
|
||||
outputProgress({
|
||||
status: 'warning',
|
||||
operation: 'SQL Warning',
|
||||
statement: i + 1,
|
||||
warnings: warnings
|
||||
});
|
||||
}
|
||||
const result = await client.query(stmt);
|
||||
|
||||
// Verify if table was created (if this was a CREATE TABLE statement)
|
||||
if (stmt.trim().toLowerCase().startsWith('create table')) {
|
||||
const tableName = stmt.match(/create\s+table\s+(?:if\s+not\s+exists\s+)?`?(\w+)`?/i)?.[1];
|
||||
const tableName = stmt.match(/create\s+table\s+(?:if\s+not\s+exists\s+)?["]?(\w+)["]?/i)?.[1];
|
||||
if (tableName) {
|
||||
const [tableExists] = await connection.query(`
|
||||
const tableExists = await client.query(`
|
||||
SELECT COUNT(*) as count
|
||||
FROM information_schema.tables
|
||||
WHERE table_schema = DATABASE()
|
||||
AND table_name = ?
|
||||
WHERE table_schema = 'public'
|
||||
AND table_name = $1
|
||||
`, [tableName]);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Table Creation Verification',
|
||||
message: {
|
||||
table: tableName,
|
||||
exists: tableExists[0].count > 0
|
||||
exists: tableExists.rows[0].count > 0
|
||||
}
|
||||
});
|
||||
}
|
||||
@@ -263,7 +277,7 @@ async function resetDatabase() {
|
||||
statement: i + 1,
|
||||
total: statements.length,
|
||||
preview: stmt.substring(0, 100) + (stmt.length > 100 ? '...' : ''),
|
||||
affectedRows: result.affectedRows
|
||||
rowCount: result.rowCount
|
||||
}
|
||||
});
|
||||
} catch (sqlError) {
|
||||
@@ -271,8 +285,6 @@ async function resetDatabase() {
|
||||
status: 'error',
|
||||
operation: 'SQL Error',
|
||||
error: sqlError.message,
|
||||
sqlState: sqlError.sqlState,
|
||||
errno: sqlError.errno,
|
||||
statement: stmt,
|
||||
statementNumber: i + 1
|
||||
});
|
||||
@@ -281,25 +293,17 @@ async function resetDatabase() {
|
||||
}
|
||||
|
||||
// List all tables in the database after schema execution
|
||||
outputProgress({
|
||||
operation: 'Debug database',
|
||||
message: {
|
||||
currentDatabase: (await connection.query('SELECT DATABASE() as db'))[0][0].db
|
||||
}
|
||||
});
|
||||
|
||||
const [allTables] = await connection.query(`
|
||||
const allTables = await client.query(`
|
||||
SELECT
|
||||
table_schema,
|
||||
table_name,
|
||||
engine,
|
||||
create_time,
|
||||
table_rows
|
||||
pg_size_pretty(pg_total_relation_size(quote_ident(table_schema) || '.' || quote_ident(table_name))) as size,
|
||||
pg_relation_size(quote_ident(table_schema) || '.' || quote_ident(table_name)) as raw_size
|
||||
FROM information_schema.tables
|
||||
WHERE table_schema = DATABASE()
|
||||
WHERE table_schema = 'public'
|
||||
`);
|
||||
|
||||
if (allTables.length === 0) {
|
||||
if (allTables.rows.length === 0) {
|
||||
outputProgress({
|
||||
operation: 'Warning',
|
||||
message: 'No tables found in database after schema execution'
|
||||
@@ -308,38 +312,19 @@ async function resetDatabase() {
|
||||
outputProgress({
|
||||
operation: 'Tables after schema execution',
|
||||
message: {
|
||||
count: allTables.length,
|
||||
tables: allTables.map(t => ({
|
||||
count: allTables.rows.length,
|
||||
tables: allTables.rows.map(t => ({
|
||||
schema: t.table_schema,
|
||||
name: t.table_name,
|
||||
engine: t.engine,
|
||||
created: t.create_time,
|
||||
rows: t.table_rows
|
||||
size: t.size,
|
||||
rawSize: t.raw_size
|
||||
}))
|
||||
}
|
||||
});
|
||||
}
|
||||
|
||||
// Also check table status
|
||||
const [tableStatus] = await connection.query('SHOW TABLE STATUS');
|
||||
outputProgress({
|
||||
operation: 'Table Status',
|
||||
message: {
|
||||
tables: tableStatus.map(t => ({
|
||||
name: t.Name,
|
||||
engine: t.Engine,
|
||||
version: t.Version,
|
||||
rowFormat: t.Row_format,
|
||||
rows: t.Rows,
|
||||
createTime: t.Create_time,
|
||||
updateTime: t.Update_time
|
||||
}))
|
||||
}
|
||||
});
|
||||
|
||||
// Verify core tables were created using SHOW TABLES
|
||||
const [showTables] = await connection.query('SHOW TABLES');
|
||||
const existingTables = showTables.map(t => Object.values(t)[0]);
|
||||
// Verify core tables were created
|
||||
const existingTables = allTables.rows.map(t => t.table_name);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Core tables verification',
|
||||
@@ -359,16 +344,6 @@ async function resetDatabase() {
|
||||
);
|
||||
}
|
||||
|
||||
// Verify all core tables use InnoDB
|
||||
const [engineStatus] = await connection.query('SHOW TABLE STATUS WHERE Name IN (?)', [CORE_TABLES]);
|
||||
const nonInnoDBTables = engineStatus.filter(t => t.Engine !== 'InnoDB');
|
||||
|
||||
if (nonInnoDBTables.length > 0) {
|
||||
throw new Error(
|
||||
`Tables using non-InnoDB engine: ${nonInnoDBTables.map(t => t.Name).join(', ')}`
|
||||
);
|
||||
}
|
||||
|
||||
outputProgress({
|
||||
operation: 'Core tables created',
|
||||
message: `Successfully created tables: ${CORE_TABLES.join(', ')}`
|
||||
@@ -400,18 +375,7 @@ async function resetDatabase() {
|
||||
for (let i = 0; i < configStatements.length; i++) {
|
||||
const stmt = configStatements[i];
|
||||
try {
|
||||
const [result, fields] = await connection.query(stmt);
|
||||
|
||||
// Check for warnings
|
||||
const [warnings] = await connection.query('SHOW WARNINGS');
|
||||
if (warnings && warnings.length > 0) {
|
||||
outputProgress({
|
||||
status: 'warning',
|
||||
operation: 'Config SQL Warning',
|
||||
statement: i + 1,
|
||||
warnings: warnings
|
||||
});
|
||||
}
|
||||
const result = await client.query(stmt);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Config SQL Progress',
|
||||
@@ -419,7 +383,7 @@ async function resetDatabase() {
|
||||
statement: i + 1,
|
||||
total: configStatements.length,
|
||||
preview: stmt.substring(0, 100) + (stmt.length > 100 ? '...' : ''),
|
||||
affectedRows: result.affectedRows
|
||||
rowCount: result.rowCount
|
||||
}
|
||||
});
|
||||
} catch (sqlError) {
|
||||
@@ -427,8 +391,6 @@ async function resetDatabase() {
|
||||
status: 'error',
|
||||
operation: 'Config SQL Error',
|
||||
error: sqlError.message,
|
||||
sqlState: sqlError.sqlState,
|
||||
errno: sqlError.errno,
|
||||
statement: stmt,
|
||||
statementNumber: i + 1
|
||||
});
|
||||
@@ -437,8 +399,12 @@ async function resetDatabase() {
|
||||
}
|
||||
|
||||
// Verify config tables were created
|
||||
const [showConfigTables] = await connection.query('SHOW TABLES');
|
||||
const existingConfigTables = showConfigTables.map(t => Object.values(t)[0]);
|
||||
const configTablesResult = await client.query(`
|
||||
SELECT table_name
|
||||
FROM information_schema.tables
|
||||
WHERE table_schema = 'public'
|
||||
`);
|
||||
const existingConfigTables = configTablesResult.rows.map(t => t.table_name);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Config tables verification',
|
||||
@@ -489,18 +455,7 @@ async function resetDatabase() {
|
||||
for (let i = 0; i < metricsStatements.length; i++) {
|
||||
const stmt = metricsStatements[i];
|
||||
try {
|
||||
const [result, fields] = await connection.query(stmt);
|
||||
|
||||
// Check for warnings
|
||||
const [warnings] = await connection.query('SHOW WARNINGS');
|
||||
if (warnings && warnings.length > 0) {
|
||||
outputProgress({
|
||||
status: 'warning',
|
||||
operation: 'Metrics SQL Warning',
|
||||
statement: i + 1,
|
||||
warnings: warnings
|
||||
});
|
||||
}
|
||||
const result = await client.query(stmt);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Metrics SQL Progress',
|
||||
@@ -508,7 +463,7 @@ async function resetDatabase() {
|
||||
statement: i + 1,
|
||||
total: metricsStatements.length,
|
||||
preview: stmt.substring(0, 100) + (stmt.length > 100 ? '...' : ''),
|
||||
affectedRows: result.affectedRows
|
||||
rowCount: result.rowCount
|
||||
}
|
||||
});
|
||||
} catch (sqlError) {
|
||||
@@ -516,8 +471,6 @@ async function resetDatabase() {
|
||||
status: 'error',
|
||||
operation: 'Metrics SQL Error',
|
||||
error: sqlError.message,
|
||||
sqlState: sqlError.sqlState,
|
||||
errno: sqlError.errno,
|
||||
statement: stmt,
|
||||
statementNumber: i + 1
|
||||
});
|
||||
@@ -539,7 +492,7 @@ async function resetDatabase() {
|
||||
});
|
||||
process.exit(1);
|
||||
} finally {
|
||||
await connection.end();
|
||||
await client.end();
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
@@ -1,4 +1,4 @@
|
||||
const mysql = require('mysql2/promise');
|
||||
const { Client } = require('pg');
|
||||
const path = require('path');
|
||||
const fs = require('fs');
|
||||
require('dotenv').config({ path: path.resolve(__dirname, '../.env') });
|
||||
@@ -8,7 +8,7 @@ const dbConfig = {
|
||||
user: process.env.DB_USER,
|
||||
password: process.env.DB_PASSWORD,
|
||||
database: process.env.DB_NAME,
|
||||
multipleStatements: true
|
||||
port: process.env.DB_PORT || 5432
|
||||
};
|
||||
|
||||
function outputProgress(data) {
|
||||
@@ -34,8 +34,8 @@ const METRICS_TABLES = [
|
||||
'sales_forecasts',
|
||||
'temp_purchase_metrics',
|
||||
'temp_sales_metrics',
|
||||
'vendor_metrics', //before vendor_details for foreign key
|
||||
'vendor_time_metrics', //before vendor_details for foreign key
|
||||
'vendor_metrics',
|
||||
'vendor_time_metrics',
|
||||
'vendor_details'
|
||||
];
|
||||
|
||||
@@ -90,31 +90,31 @@ function splitSQLStatements(sql) {
|
||||
}
|
||||
|
||||
async function resetMetrics() {
|
||||
let connection;
|
||||
let client;
|
||||
try {
|
||||
outputProgress({
|
||||
operation: 'Starting metrics reset',
|
||||
message: 'Connecting to database...'
|
||||
});
|
||||
|
||||
connection = await mysql.createConnection(dbConfig);
|
||||
await connection.beginTransaction();
|
||||
client = new Client(dbConfig);
|
||||
await client.connect();
|
||||
|
||||
// First verify current state
|
||||
const [initialTables] = await connection.query(`
|
||||
SELECT TABLE_NAME as name
|
||||
FROM information_schema.tables
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME IN (?)
|
||||
const initialTables = await client.query(`
|
||||
SELECT tablename as name
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
AND tablename = ANY($1)
|
||||
`, [METRICS_TABLES]);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Initial state',
|
||||
message: `Found ${initialTables.length} existing metrics tables: ${initialTables.map(t => t.name).join(', ')}`
|
||||
message: `Found ${initialTables.rows.length} existing metrics tables: ${initialTables.rows.map(t => t.name).join(', ')}`
|
||||
});
|
||||
|
||||
// Disable foreign key checks at the start
|
||||
await connection.query('SET FOREIGN_KEY_CHECKS = 0');
|
||||
await client.query('SET session_replication_role = \'replica\'');
|
||||
|
||||
// Drop all metrics tables in reverse order to handle dependencies
|
||||
outputProgress({
|
||||
@@ -124,17 +124,17 @@ async function resetMetrics() {
|
||||
|
||||
for (const table of [...METRICS_TABLES].reverse()) {
|
||||
try {
|
||||
await connection.query(`DROP TABLE IF EXISTS ${table}`);
|
||||
await client.query(`DROP TABLE IF EXISTS "${table}" CASCADE`);
|
||||
|
||||
// Verify the table was actually dropped
|
||||
const [checkDrop] = await connection.query(`
|
||||
const checkDrop = await client.query(`
|
||||
SELECT COUNT(*) as count
|
||||
FROM information_schema.tables
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME = ?
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
AND tablename = $1
|
||||
`, [table]);
|
||||
|
||||
if (checkDrop[0].count > 0) {
|
||||
if (parseInt(checkDrop.rows[0].count) > 0) {
|
||||
throw new Error(`Failed to drop table ${table} - table still exists`);
|
||||
}
|
||||
|
||||
@@ -153,15 +153,15 @@ async function resetMetrics() {
|
||||
}
|
||||
|
||||
// Verify all tables were dropped
|
||||
const [afterDrop] = await connection.query(`
|
||||
SELECT TABLE_NAME as name
|
||||
FROM information_schema.tables
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME IN (?)
|
||||
const afterDrop = await client.query(`
|
||||
SELECT tablename as name
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
AND tablename = ANY($1)
|
||||
`, [METRICS_TABLES]);
|
||||
|
||||
if (afterDrop.length > 0) {
|
||||
throw new Error(`Failed to drop all tables. Remaining tables: ${afterDrop.map(t => t.name).join(', ')}`);
|
||||
if (afterDrop.rows.length > 0) {
|
||||
throw new Error(`Failed to drop all tables. Remaining tables: ${afterDrop.rows.map(t => t.name).join(', ')}`);
|
||||
}
|
||||
|
||||
// Read metrics schema
|
||||
@@ -187,39 +187,26 @@ async function resetMetrics() {
|
||||
for (let i = 0; i < statements.length; i++) {
|
||||
const stmt = statements[i];
|
||||
try {
|
||||
await connection.query(stmt);
|
||||
|
||||
// Check for warnings
|
||||
const [warnings] = await connection.query('SHOW WARNINGS');
|
||||
if (warnings && warnings.length > 0) {
|
||||
outputProgress({
|
||||
status: 'warning',
|
||||
operation: 'SQL Warning',
|
||||
message: {
|
||||
statement: i + 1,
|
||||
warnings: warnings
|
||||
}
|
||||
});
|
||||
}
|
||||
const result = await client.query(stmt);
|
||||
|
||||
// If this is a CREATE TABLE statement, verify the table was created
|
||||
if (stmt.trim().toLowerCase().startsWith('create table')) {
|
||||
const tableName = stmt.match(/create\s+table\s+(?:if\s+not\s+exists\s+)?`?(\w+)`?/i)?.[1];
|
||||
const tableName = stmt.match(/create\s+table\s+(?:if\s+not\s+exists\s+)?["]?(\w+)["]?/i)?.[1];
|
||||
if (tableName) {
|
||||
const [checkCreate] = await connection.query(`
|
||||
SELECT TABLE_NAME as name, CREATE_TIME as created
|
||||
FROM information_schema.tables
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME = ?
|
||||
const checkCreate = await client.query(`
|
||||
SELECT tablename as name
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
AND tablename = $1
|
||||
`, [tableName]);
|
||||
|
||||
if (checkCreate.length === 0) {
|
||||
if (checkCreate.rows.length === 0) {
|
||||
throw new Error(`Failed to create table ${tableName} - table does not exist after CREATE statement`);
|
||||
}
|
||||
|
||||
outputProgress({
|
||||
operation: 'Table created',
|
||||
message: `Successfully created table: ${tableName} at ${checkCreate[0].created}`
|
||||
message: `Successfully created table: ${tableName}`
|
||||
});
|
||||
}
|
||||
}
|
||||
@@ -229,7 +216,8 @@ async function resetMetrics() {
|
||||
message: {
|
||||
statement: i + 1,
|
||||
total: statements.length,
|
||||
preview: stmt.substring(0, 100) + (stmt.length > 100 ? '...' : '')
|
||||
preview: stmt.substring(0, 100) + (stmt.length > 100 ? '...' : ''),
|
||||
rowCount: result.rowCount
|
||||
}
|
||||
});
|
||||
} catch (sqlError) {
|
||||
@@ -238,8 +226,6 @@ async function resetMetrics() {
|
||||
operation: 'SQL Error',
|
||||
message: {
|
||||
error: sqlError.message,
|
||||
sqlState: sqlError.sqlState,
|
||||
errno: sqlError.errno,
|
||||
statement: stmt,
|
||||
statementNumber: i + 1
|
||||
}
|
||||
@@ -249,7 +235,7 @@ async function resetMetrics() {
|
||||
}
|
||||
|
||||
// Re-enable foreign key checks after all tables are created
|
||||
await connection.query('SET FOREIGN_KEY_CHECKS = 1');
|
||||
await client.query('SET session_replication_role = \'origin\'');
|
||||
|
||||
// Verify metrics tables were created
|
||||
outputProgress({
|
||||
@@ -257,37 +243,36 @@ async function resetMetrics() {
|
||||
message: 'Checking all metrics tables were created...'
|
||||
});
|
||||
|
||||
const [metricsTablesResult] = await connection.query(`
|
||||
SELECT
|
||||
TABLE_NAME as name,
|
||||
TABLE_ROWS as \`rows\`,
|
||||
CREATE_TIME as created
|
||||
FROM information_schema.tables
|
||||
WHERE TABLE_SCHEMA = DATABASE()
|
||||
AND TABLE_NAME IN (?)
|
||||
const metricsTablesResult = await client.query(`
|
||||
SELECT tablename as name
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
AND tablename = ANY($1)
|
||||
`, [METRICS_TABLES]);
|
||||
|
||||
outputProgress({
|
||||
operation: 'Tables found',
|
||||
message: `Found ${metricsTablesResult.length} tables: ${metricsTablesResult.map(t =>
|
||||
`${t.name} (created: ${t.created})`
|
||||
).join(', ')}`
|
||||
message: `Found ${metricsTablesResult.rows.length} tables: ${metricsTablesResult.rows.map(t => t.name).join(', ')}`
|
||||
});
|
||||
|
||||
const existingMetricsTables = metricsTablesResult.map(t => t.name);
|
||||
const existingMetricsTables = metricsTablesResult.rows.map(t => t.name);
|
||||
const missingMetricsTables = METRICS_TABLES.filter(t => !existingMetricsTables.includes(t));
|
||||
|
||||
if (missingMetricsTables.length > 0) {
|
||||
// Do one final check of the actual tables
|
||||
const [finalCheck] = await connection.query('SHOW TABLES');
|
||||
const finalCheck = await client.query(`
|
||||
SELECT tablename as name
|
||||
FROM pg_tables
|
||||
WHERE schemaname = 'public'
|
||||
`);
|
||||
outputProgress({
|
||||
operation: 'Final table check',
|
||||
message: `All database tables: ${finalCheck.map(t => Object.values(t)[0]).join(', ')}`
|
||||
message: `All database tables: ${finalCheck.rows.map(t => t.name).join(', ')}`
|
||||
});
|
||||
throw new Error(`Failed to create metrics tables: ${missingMetricsTables.join(', ')}`);
|
||||
}
|
||||
|
||||
await connection.commit();
|
||||
await client.query('COMMIT');
|
||||
|
||||
outputProgress({
|
||||
status: 'complete',
|
||||
@@ -302,17 +287,17 @@ async function resetMetrics() {
|
||||
stack: error.stack
|
||||
});
|
||||
|
||||
if (connection) {
|
||||
await connection.rollback();
|
||||
if (client) {
|
||||
await client.query('ROLLBACK');
|
||||
// Make sure to re-enable foreign key checks even if there's an error
|
||||
await connection.query('SET FOREIGN_KEY_CHECKS = 1').catch(() => {});
|
||||
await client.query('SET session_replication_role = \'origin\'').catch(() => {});
|
||||
}
|
||||
throw error;
|
||||
} finally {
|
||||
if (connection) {
|
||||
if (client) {
|
||||
// One final attempt to ensure foreign key checks are enabled
|
||||
await connection.query('SET FOREIGN_KEY_CHECKS = 1').catch(() => {});
|
||||
await connection.end();
|
||||
await client.query('SET session_replication_role = \'origin\'').catch(() => {});
|
||||
await client.end();
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user