Folder reorganize 1
This commit is contained in:
20
sql/control_write_log.sql
Normal file
20
sql/control_write_log.sql
Normal file
@@ -0,0 +1,20 @@
|
||||
-- Audit log table for tag control overrides
|
||||
CREATE TABLE IF NOT EXISTS `control_write_log` (
|
||||
`id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`created_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`tag_id` VARCHAR(190) NOT NULL,
|
||||
`tag_name` VARCHAR(190) DEFAULT NULL,
|
||||
`mode` VARCHAR(32) DEFAULT NULL,
|
||||
`previous_value` DECIMAL(18,6) DEFAULT NULL,
|
||||
`new_value` DECIMAL(18,6) DEFAULT NULL,
|
||||
`requested_value` DECIMAL(18,6) DEFAULT NULL,
|
||||
`delta` DECIMAL(18,6) DEFAULT NULL,
|
||||
`status` VARCHAR(190) DEFAULT NULL,
|
||||
`message` VARCHAR(255) DEFAULT NULL,
|
||||
`username` VARCHAR(190) DEFAULT NULL,
|
||||
`session_id` VARCHAR(128) DEFAULT NULL,
|
||||
`client_ip` VARCHAR(64) DEFAULT NULL,
|
||||
PRIMARY KEY (`id`),
|
||||
KEY `idx_control_write_log_created_at` (`created_at`),
|
||||
KEY `idx_control_write_log_tag_id` (`tag_id`)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||
21
sql/create_dashboard_row_catalog.sql
Normal file
21
sql/create_dashboard_row_catalog.sql
Normal file
@@ -0,0 +1,21 @@
|
||||
-- Catalog of available overview rows for personal dashboards
|
||||
-- Run against the LASUCA MySQL schema (same database that stores `members`).
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `dashboard_row_catalog` (
|
||||
`id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`row_key` VARCHAR(64) NOT NULL COMMENT 'Stable identifier used in code / user selections',
|
||||
`friendly_name` VARCHAR(255) NOT NULL COMMENT 'Display label shown in pickers',
|
||||
`source_type` VARCHAR(32) NOT NULL DEFAULT 'historian' COMMENT 'historian|mysql|computed etc.',
|
||||
`source_id` VARCHAR(128) NOT NULL COMMENT 'Identifier used by the source system (e.g., historian ID or tag name)',
|
||||
`unit` VARCHAR(32) DEFAULT NULL COMMENT 'Unit of measure (psi, %, rpm, ft, etc.)',
|
||||
`is_level_indicator` TINYINT(1) NOT NULL DEFAULT 0 COMMENT '1 = render as level indicator instead of plain numeric',
|
||||
`value_precision` TINYINT UNSIGNED DEFAULT NULL COMMENT 'Optional decimal precision hint',
|
||||
`display_template` VARCHAR(128) DEFAULT NULL COMMENT 'Optional PHP include or template key for rendering',
|
||||
`requires_include` VARCHAR(128) DEFAULT NULL COMMENT 'Name of include file required to populate data arrays',
|
||||
`sort_order` SMALLINT UNSIGNED NOT NULL DEFAULT 0 COMMENT 'Default ordering in selection lists',
|
||||
`metadata_json` LONGTEXT DEFAULT NULL COMMENT 'Free-form JSON for additional configuration (thresholds, colors, etc.)',
|
||||
`created_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`updated_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (`id`),
|
||||
UNIQUE KEY `uniq_dashboard_row_key` (`row_key`)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||
41
sql/create_query_log.sql
Normal file
41
sql/create_query_log.sql
Normal file
@@ -0,0 +1,41 @@
|
||||
-- Query log table for capturing form-based searches
|
||||
-- Used to seed few-shot examples for NL2SQL agent
|
||||
|
||||
IF OBJECT_ID('dbo.controls_query_log', 'U') IS NULL
|
||||
BEGIN
|
||||
CREATE TABLE dbo.controls_query_log (
|
||||
id INT IDENTITY(1,1) PRIMARY KEY,
|
||||
user_query NVARCHAR(1000) NOT NULL, -- Natural-language description of the search
|
||||
sql_template NVARCHAR(MAX) NOT NULL, -- Parameterized SQL (placeholders like :tag, :start, :end)
|
||||
sql_template_hash AS CONVERT(VARBINARY(32), HASHBYTES('SHA2_256', sql_template)) PERSISTED, -- For indexing
|
||||
params NVARCHAR(MAX) NULL, -- JSON blob of actual parameter values
|
||||
source_form NVARCHAR(100) NULL, -- Which form generated this (e.g., 'opcsearch', 'trend')
|
||||
user_session NVARCHAR(100) NULL, -- Optional: session or user identifier
|
||||
execution_ms INT NULL, -- Optional: query execution time in milliseconds
|
||||
row_count INT NULL, -- Optional: number of rows returned
|
||||
created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME()
|
||||
);
|
||||
|
||||
-- Index on hash for deduplication and fast lookup
|
||||
CREATE NONCLUSTERED INDEX IX_controls_query_log_template_hash
|
||||
ON dbo.controls_query_log (sql_template_hash)
|
||||
INCLUDE (user_query, created_at);
|
||||
|
||||
-- Index for time-based analysis
|
||||
CREATE NONCLUSTERED INDEX IX_controls_query_log_created
|
||||
ON dbo.controls_query_log (created_at DESC)
|
||||
INCLUDE (user_query, source_form);
|
||||
END;
|
||||
GO
|
||||
|
||||
-- View for distinct templates with example user queries
|
||||
CREATE OR ALTER VIEW dbo.vw_controls_query_templates AS
|
||||
SELECT
|
||||
sql_template,
|
||||
COUNT(*) AS usage_count,
|
||||
MAX(user_query) AS sample_user_query,
|
||||
MIN(created_at) AS first_used,
|
||||
MAX(created_at) AS last_used
|
||||
FROM dbo.controls_query_log
|
||||
GROUP BY sql_template;
|
||||
GO
|
||||
31
sql/create_truckdump_cache.sql
Normal file
31
sql/create_truckdump_cache.sql
Normal file
@@ -0,0 +1,31 @@
|
||||
-- Truck dump stats cache table
|
||||
-- Run on: 192.168.0.10 / controls database
|
||||
|
||||
CREATE TABLE IF NOT EXISTS truckdump_stats_cache (
|
||||
id INT PRIMARY KEY DEFAULT 1,
|
||||
|
||||
-- East (totnorth) stats
|
||||
east_since_last VARCHAR(20),
|
||||
east_between_dumps VARCHAR(20),
|
||||
east_avg_10 VARCHAR(20),
|
||||
|
||||
-- West 1 (totsouth) stats
|
||||
west1_since_last VARCHAR(20),
|
||||
west1_between_dumps VARCHAR(20),
|
||||
west1_avg_10 VARCHAR(20),
|
||||
|
||||
-- West 2 (totwest2) stats
|
||||
west2_since_last VARCHAR(20),
|
||||
west2_between_dumps VARCHAR(20),
|
||||
west2_avg_10 VARCHAR(20),
|
||||
|
||||
-- Metadata
|
||||
updated_at DATETIME NOT NULL,
|
||||
|
||||
-- Ensure only one row
|
||||
CONSTRAINT single_row CHECK (id = 1)
|
||||
);
|
||||
|
||||
-- Insert initial row
|
||||
INSERT IGNORE INTO truckdump_stats_cache (id, updated_at)
|
||||
VALUES (1, NOW());
|
||||
35
sql/create_user_tag_dashboards.sql
Normal file
35
sql/create_user_tag_dashboards.sql
Normal file
@@ -0,0 +1,35 @@
|
||||
-- Personal dashboard tag selections for each user
|
||||
-- Run this against the LASUCA MySQL instance (same schema as `members`).
|
||||
-- Adjust the referenced user table/column names if they differ in production.
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `user_tag_dashboards` (
|
||||
`id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`user_id` INT NOT NULL COMMENT 'FK to members.member_id',
|
||||
`dashboard_key` VARCHAR(64) NOT NULL DEFAULT 'default' COMMENT 'Allows multiple personal pages per user',
|
||||
`widget_type` VARCHAR(32) NOT NULL DEFAULT 'trend' COMMENT 'trend|stat|gauge etc.',
|
||||
`panel_size` VARCHAR(16) NOT NULL DEFAULT 'full' COMMENT 'full|half|card layout hints',
|
||||
`position_index` SMALLINT UNSIGNED NOT NULL DEFAULT 0 COMMENT '0-based ordering of widgets on a dashboard',
|
||||
`tag_name` VARCHAR(255) NOT NULL COMMENT 'Historian/OPC tag identifier',
|
||||
`display_label` VARCHAR(255) DEFAULT NULL COMMENT 'Optional custom label shown on the page',
|
||||
`series_color` VARCHAR(32) DEFAULT NULL COMMENT 'Hex/RGB override for the rendered series',
|
||||
`preferred_axis` VARCHAR(16) NOT NULL DEFAULT 'left' COMMENT 'left/right axis preference for charts',
|
||||
`update_interval_ms` INT UNSIGNED NOT NULL DEFAULT 5000 COMMENT 'Polling cadence in milliseconds',
|
||||
`time_window_minutes` SMALLINT UNSIGNED NOT NULL DEFAULT 180 COMMENT 'Historical window for trend widgets',
|
||||
`rollup_function` VARCHAR(16) NOT NULL DEFAULT 'raw' COMMENT 'raw|avg|min|max|sum|delta, applied server-side when supported',
|
||||
`scale_min` DECIMAL(14,4) DEFAULT NULL COMMENT 'Manual Y-scale lower bound',
|
||||
`scale_max` DECIMAL(14,4) DEFAULT NULL COMMENT 'Manual Y-scale upper bound',
|
||||
`threshold_low` DECIMAL(14,4) DEFAULT NULL COMMENT 'Alert threshold (low)',
|
||||
`threshold_high` DECIMAL(14,4) DEFAULT NULL COMMENT 'Alert threshold (high)',
|
||||
`is_active` TINYINT(1) NOT NULL DEFAULT 1 COMMENT 'Soft-delete flag for widgets the user hides temporarily',
|
||||
`config_json` LONGTEXT DEFAULT NULL COMMENT 'Free-form JSON blob for future settings (annotations, aggregates, etc.)',
|
||||
`last_viewed_at` DATETIME DEFAULT NULL COMMENT 'Updated when the user loads the dashboard',
|
||||
`created_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`updated_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (`id`),
|
||||
UNIQUE KEY `uniq_user_dashboard_tag` (`user_id`, `dashboard_key`, `widget_type`, `tag_name`),
|
||||
KEY `idx_user_dashboard` (`user_id`, `dashboard_key`, `is_active`),
|
||||
CONSTRAINT `fk_user_tag_dashboards_user`
|
||||
FOREIGN KEY (`user_id`) REFERENCES `members`(`member_id`)
|
||||
ON DELETE CASCADE
|
||||
ON UPDATE CASCADE
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||
Reference in New Issue
Block a user