feat: integrate First8 Marketing hyper-personalization system

Enhanced Umami Analytics with First8 Marketing integration for
hyper-personalized recommendation engine.

Database Enhancements:
- PostgreSQL 17 with Apache AGE 1.6.0 (graph database)
- TimescaleDB 2.23.0 (time-series optimization)
- Extended schema for WooCommerce event tracking
- Custom tables for recommendation engine integration

Features Added:
- Real-time ETL pipeline to recommendation engine
- Extended event tracking (WordPress + WooCommerce)
- Graph database for relationship mapping
- Time-series optimization for analytics queries
- Custom migrations for hyper-personalization

Documentation:
- Updated README with integration details
- Added system architecture documentation
- Documented data flow and components
- Preserved original Umami Software credits

Integration Components:
- First8 Marketing Track plugin (event tracking)
- Recommendation Engine (ML backend)
- First8 Marketing Recommendation Engine plugin (presentation)

Status: Production-ready
Version: Based on Umami latest + First8 Marketing enhancements
This commit is contained in:
iskandarsulaili 2025-11-05 19:17:57 +08:00
parent a6d4519a98
commit 5f496fdb79
16 changed files with 8856 additions and 9790 deletions

View file

@ -0,0 +1,58 @@
-- Migration: Add WooCommerce and Enhanced Tracking Fields
-- Created: 2025-01-15
-- Description: Adds WooCommerce e-commerce tracking fields and enhanced engagement metrics to website_event table
-- Add enhanced engagement tracking fields
ALTER TABLE website_event
ADD COLUMN IF NOT EXISTS scroll_depth INTEGER,
ADD COLUMN IF NOT EXISTS time_on_page INTEGER,
ADD COLUMN IF NOT EXISTS click_count INTEGER,
ADD COLUMN IF NOT EXISTS form_interactions JSONB;
-- Add WooCommerce e-commerce tracking fields
ALTER TABLE website_event
ADD COLUMN IF NOT EXISTS wc_product_id VARCHAR(50),
ADD COLUMN IF NOT EXISTS wc_category_id VARCHAR(50),
ADD COLUMN IF NOT EXISTS wc_cart_value DECIMAL(19, 4),
ADD COLUMN IF NOT EXISTS wc_checkout_step INTEGER,
ADD COLUMN IF NOT EXISTS wc_order_id VARCHAR(50),
ADD COLUMN IF NOT EXISTS wc_revenue DECIMAL(19, 4);
-- Create indexes for WooCommerce queries (performance optimization)
-- Index for product-based queries
CREATE INDEX IF NOT EXISTS idx_website_event_wc_product
ON website_event(website_id, wc_product_id, created_at)
WHERE wc_product_id IS NOT NULL;
-- Index for category-based queries
CREATE INDEX IF NOT EXISTS idx_website_event_wc_category
ON website_event(website_id, wc_category_id, created_at)
WHERE wc_category_id IS NOT NULL;
-- Index for order-based queries (partial index for sparse data)
CREATE INDEX IF NOT EXISTS idx_website_event_wc_order
ON website_event(wc_order_id)
WHERE wc_order_id IS NOT NULL;
-- Index for revenue analysis
CREATE INDEX IF NOT EXISTS idx_website_event_wc_revenue
ON website_event(website_id, created_at, wc_revenue)
WHERE wc_revenue IS NOT NULL;
-- Index for engagement metrics
CREATE INDEX IF NOT EXISTS idx_website_event_engagement
ON website_event(website_id, created_at, scroll_depth, time_on_page)
WHERE scroll_depth IS NOT NULL OR time_on_page IS NOT NULL;
-- Add comments for documentation
COMMENT ON COLUMN website_event.scroll_depth IS 'Percentage of page scrolled (0-100)';
COMMENT ON COLUMN website_event.time_on_page IS 'Time spent on page in seconds';
COMMENT ON COLUMN website_event.click_count IS 'Number of clicks on the page';
COMMENT ON COLUMN website_event.form_interactions IS 'JSONB array of form interaction events';
COMMENT ON COLUMN website_event.wc_product_id IS 'WooCommerce product ID';
COMMENT ON COLUMN website_event.wc_category_id IS 'WooCommerce category ID';
COMMENT ON COLUMN website_event.wc_cart_value IS 'Cart value at time of event';
COMMENT ON COLUMN website_event.wc_checkout_step IS 'Checkout step number (1-N)';
COMMENT ON COLUMN website_event.wc_order_id IS 'WooCommerce order ID for purchase events';
COMMENT ON COLUMN website_event.wc_revenue IS 'Revenue amount for purchase events';

View file

@ -0,0 +1,154 @@
-- Migration: Create Recommendation Engine Tables
-- Created: 2025-01-15
-- Description: Creates tables for user profiles, recommendations tracking, and ML model registry
-- ============================================================================
-- Table: user_profiles
-- Purpose: Aggregated user behavior and preferences for personalization
-- ============================================================================
CREATE TABLE IF NOT EXISTS user_profiles (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id VARCHAR(255) UNIQUE NOT NULL, -- Can be session_id or logged-in user_id
website_id UUID NOT NULL,
-- Lifecycle
lifecycle_stage VARCHAR(50), -- 'new', 'active', 'at_risk', 'churned'
funnel_position VARCHAR(50), -- 'awareness', 'consideration', 'decision', 'retention'
-- Engagement metrics
session_count INTEGER DEFAULT 0,
total_pageviews INTEGER DEFAULT 0,
total_events INTEGER DEFAULT 0,
total_purchases INTEGER DEFAULT 0,
total_revenue DECIMAL(19, 4) DEFAULT 0,
-- Behavior
avg_session_duration INTEGER, -- seconds
avg_time_on_page INTEGER, -- seconds
avg_scroll_depth INTEGER, -- percentage
bounce_rate DECIMAL(5, 4),
-- Preferences (JSONB for flexibility)
favorite_categories JSONB, -- ['electronics', 'books']
favorite_products JSONB, -- ['product_id_1', 'product_id_2']
price_sensitivity VARCHAR(20), -- 'low', 'medium', 'high'
preferred_brands JSONB,
device_preference VARCHAR(20), -- 'mobile', 'tablet', 'desktop'
-- Timestamps
first_visit TIMESTAMPTZ,
last_visit TIMESTAMPTZ,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW(),
CONSTRAINT fk_user_profiles_website FOREIGN KEY (website_id) REFERENCES website(website_id) ON DELETE CASCADE
);
-- Indexes for user_profiles
CREATE INDEX idx_user_profiles_user_id ON user_profiles(user_id);
CREATE INDEX idx_user_profiles_website_id ON user_profiles(website_id);
CREATE INDEX idx_user_profiles_lifecycle ON user_profiles(lifecycle_stage);
CREATE INDEX idx_user_profiles_last_visit ON user_profiles(last_visit);
-- Comments for user_profiles
COMMENT ON TABLE user_profiles IS 'Aggregated user behavior and preferences for personalization';
COMMENT ON COLUMN user_profiles.lifecycle_stage IS 'User lifecycle stage: new, active, at_risk, churned';
COMMENT ON COLUMN user_profiles.funnel_position IS 'User position in marketing funnel';
COMMENT ON COLUMN user_profiles.favorite_categories IS 'JSONB array of favorite product categories';
COMMENT ON COLUMN user_profiles.favorite_products IS 'JSONB array of favorite product IDs';
-- ============================================================================
-- Table: recommendations
-- Purpose: Historical recommendations for analysis and learning
-- ============================================================================
CREATE TABLE IF NOT EXISTS recommendations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
session_id UUID NOT NULL,
user_id VARCHAR(255),
website_id UUID NOT NULL,
-- Recommendation details
recommendation_type VARCHAR(50), -- 'product', 'content', 'offer'
item_id VARCHAR(255) NOT NULL,
score DECIMAL(5, 4),
rank INTEGER,
-- Context
context JSONB, -- Page, product, category where shown
strategy VARCHAR(50), -- 'collaborative', 'sequential', 'graph', etc.
model_version VARCHAR(50),
-- Personalization factors
personalization_factors JSONB,
-- Outcome
shown BOOLEAN DEFAULT TRUE,
clicked BOOLEAN DEFAULT FALSE,
converted BOOLEAN DEFAULT FALSE,
revenue DECIMAL(19, 4),
-- Timestamps
shown_at TIMESTAMPTZ DEFAULT NOW(),
clicked_at TIMESTAMPTZ,
converted_at TIMESTAMPTZ,
CONSTRAINT fk_recommendations_website FOREIGN KEY (website_id) REFERENCES website(website_id) ON DELETE CASCADE
);
-- Indexes for recommendations
CREATE INDEX idx_recommendations_session ON recommendations(session_id);
CREATE INDEX idx_recommendations_user ON recommendations(user_id);
CREATE INDEX idx_recommendations_item ON recommendations(item_id);
CREATE INDEX idx_recommendations_shown_at ON recommendations(shown_at);
CREATE INDEX idx_recommendations_outcome ON recommendations(clicked, converted);
CREATE INDEX idx_recommendations_website ON recommendations(website_id);
-- Comments for recommendations
COMMENT ON TABLE recommendations IS 'Historical recommendations for analysis and learning';
COMMENT ON COLUMN recommendations.strategy IS 'Recommendation strategy used: collaborative, sequential, graph, etc.';
COMMENT ON COLUMN recommendations.personalization_factors IS 'JSONB object containing factors that influenced this recommendation';
-- ============================================================================
-- Table: ml_models
-- Purpose: Model registry and versioning
-- ============================================================================
CREATE TABLE IF NOT EXISTS ml_models (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(100) NOT NULL,
version VARCHAR(50) NOT NULL,
model_type VARCHAR(50), -- 'collaborative_filtering', 'sequential', etc.
-- Model metadata
algorithm VARCHAR(100),
hyperparameters JSONB,
training_data_period JSONB, -- {start: '2025-01-01', end: '2025-01-15'}
-- Performance metrics
metrics JSONB, -- {precision: 0.15, recall: 0.25, ndcg: 0.30}
-- Storage
artifact_path VARCHAR(500), -- S3/local path to model file
artifact_size_bytes BIGINT,
-- Status
status VARCHAR(20), -- 'training', 'validating', 'production', 'archived'
is_active BOOLEAN DEFAULT FALSE,
-- Timestamps
trained_at TIMESTAMPTZ,
deployed_at TIMESTAMPTZ,
created_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(name, version)
);
-- Indexes for ml_models
CREATE INDEX idx_ml_models_name ON ml_models(name);
CREATE INDEX idx_ml_models_status ON ml_models(status);
CREATE INDEX idx_ml_models_active ON ml_models(is_active) WHERE is_active = TRUE;
-- Comments for ml_models
COMMENT ON TABLE ml_models IS 'ML model registry and versioning';
COMMENT ON COLUMN ml_models.status IS 'Model status: training, validating, production, archived';
COMMENT ON COLUMN ml_models.is_active IS 'Whether this model version is currently active in production';

View file

@ -0,0 +1,151 @@
-- Migration: Setup Apache AGE Graph Database
-- Created: 2025-01-15
-- Description: Installs Apache AGE extension and creates graph schema for user journey tracking
-- Requirements: PostgreSQL 17 + Apache AGE 1.6.0
-- ============================================================================
-- Step 1: Install Apache AGE Extension
-- ============================================================================
CREATE EXTENSION IF NOT EXISTS age;
-- Load AGE into search path
SET search_path = ag_catalog, "$user", public;
-- ============================================================================
-- Step 2: Create Graph for User Journey Tracking
-- ============================================================================
SELECT ag_catalog.create_graph('user_journey');
-- ============================================================================
-- Step 3: Create Vertex Labels (Node Types)
-- ============================================================================
-- User nodes (represents sessions or logged-in users)
SELECT ag_catalog.create_vlabel('user_journey', 'User');
-- Product nodes
SELECT ag_catalog.create_vlabel('user_journey', 'Product');
-- Category nodes
SELECT ag_catalog.create_vlabel('user_journey', 'Category');
-- Page nodes
SELECT ag_catalog.create_vlabel('user_journey', 'Page');
-- Event nodes (for anomaly detection)
SELECT ag_catalog.create_vlabel('user_journey', 'Event');
-- ============================================================================
-- Step 4: Create Edge Labels (Relationship Types)
-- ============================================================================
-- Generic Relationships (Mode 1 - Always Available)
SELECT ag_catalog.create_elabel('user_journey', 'VIEWED');
SELECT ag_catalog.create_elabel('user_journey', 'ADDED_TO_CART');
SELECT ag_catalog.create_elabel('user_journey', 'PURCHASED');
SELECT ag_catalog.create_elabel('user_journey', 'SEARCHED_FOR');
SELECT ag_catalog.create_elabel('user_journey', 'NAVIGATED_TO');
SELECT ag_catalog.create_elabel('user_journey', 'BOUGHT_TOGETHER');
SELECT ag_catalog.create_elabel('user_journey', 'VIEWED_TOGETHER');
SELECT ag_catalog.create_elabel('user_journey', 'IN_CATEGORY');
-- Adaptive Relationships (Mode 2 - LLM-Enhanced, Optional)
SELECT ag_catalog.create_elabel('user_journey', 'SEMANTICALLY_SIMILAR');
SELECT ag_catalog.create_elabel('user_journey', 'PREDICTED_INTEREST');
SELECT ag_catalog.create_elabel('user_journey', 'COMPLEMENTARY');
SELECT ag_catalog.create_elabel('user_journey', 'ANOMALOUS_BEHAVIOR');
-- ============================================================================
-- Step 5: Create Helper Functions
-- ============================================================================
-- Function to execute Cypher queries safely
CREATE OR REPLACE FUNCTION execute_cypher(graph_name text, query text)
RETURNS SETOF agtype
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY EXECUTE format('SELECT * FROM ag_catalog.cypher(%L, %L) AS (result agtype)', graph_name, query);
END;
$$;
COMMENT ON FUNCTION execute_cypher IS 'Helper function to execute Cypher queries on Apache AGE graphs';
-- ============================================================================
-- Step 6: Create Indexes for Graph Performance
-- ============================================================================
-- Note: Apache AGE automatically creates indexes for vertex and edge IDs
-- Additional indexes can be created on properties as needed
-- ============================================================================
-- Step 7: Verify Installation
-- ============================================================================
-- Verify graph exists
DO $$
DECLARE
graph_count INTEGER;
BEGIN
SELECT COUNT(*) INTO graph_count
FROM ag_catalog.ag_graph
WHERE name = 'user_journey';
IF graph_count = 0 THEN
RAISE EXCEPTION 'Graph user_journey was not created successfully';
ELSE
RAISE NOTICE 'Apache AGE setup complete: Graph user_journey created successfully';
END IF;
END $$;
-- Verify vertex labels
DO $$
DECLARE
vlabel_count INTEGER;
BEGIN
SELECT COUNT(*) INTO vlabel_count
FROM ag_catalog.ag_label
WHERE graph = (SELECT graphid FROM ag_catalog.ag_graph WHERE name = 'user_journey')
AND kind = 'v';
RAISE NOTICE 'Created % vertex labels', vlabel_count;
END $$;
-- Verify edge labels
DO $$
DECLARE
elabel_count INTEGER;
BEGIN
SELECT COUNT(*) INTO elabel_count
FROM ag_catalog.ag_label
WHERE graph = (SELECT graphid FROM ag_catalog.ag_graph WHERE name = 'user_journey')
AND kind = 'e';
RAISE NOTICE 'Created % edge labels', elabel_count;
END $$;
-- ============================================================================
-- Step 8: Grant Permissions
-- ============================================================================
-- Grant usage on ag_catalog schema to application user
-- Note: Replace 'umami_user' with your actual database user
-- GRANT USAGE ON SCHEMA ag_catalog TO umami_user;
-- GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA ag_catalog TO umami_user;
-- ============================================================================
-- Migration Complete
-- ============================================================================
-- Log completion
DO $$
BEGIN
RAISE NOTICE '=================================================================';
RAISE NOTICE 'Apache AGE Migration Complete';
RAISE NOTICE 'Graph: user_journey';
RAISE NOTICE 'Vertex Labels: User, Product, Category, Page, Event';
RAISE NOTICE 'Edge Labels: VIEWED, ADDED_TO_CART, PURCHASED, SEARCHED_FOR, etc.';
RAISE NOTICE 'Helper Functions: execute_cypher()';
RAISE NOTICE '=================================================================';
END $$;

View file

@ -0,0 +1,214 @@
-- Migration: Setup TimescaleDB for Time-Series Analytics
-- Created: 2025-01-15
-- Description: Installs TimescaleDB extension and creates hypertables for time-series data
-- Requirements: PostgreSQL 17 + TimescaleDB 2.23.0
-- ============================================================================
-- Step 1: Install TimescaleDB Extension
-- ============================================================================
CREATE EXTENSION IF NOT EXISTS timescaledb;
-- ============================================================================
-- Step 2: Create Time-Series Events Table
-- ============================================================================
CREATE TABLE IF NOT EXISTS time_series_events (
time TIMESTAMPTZ NOT NULL,
website_id UUID NOT NULL,
session_id UUID NOT NULL,
user_id VARCHAR(255),
-- Event details
event_type VARCHAR(50) NOT NULL,
event_name VARCHAR(50),
event_value DECIMAL(19, 4),
properties JSONB,
-- Dimensions for fast filtering
page_url VARCHAR(500),
product_id VARCHAR(50),
category VARCHAR(100),
device VARCHAR(20),
country CHAR(2),
PRIMARY KEY (time, website_id, session_id)
);
-- Convert to hypertable (partitioned by time)
SELECT create_hypertable('time_series_events', 'time',
chunk_time_interval => INTERVAL '7 days',
if_not_exists => TRUE
);
-- ============================================================================
-- Step 3: Create Indexes for Time-Series Queries
-- ============================================================================
-- Index for website-specific queries
CREATE INDEX IF NOT EXISTS idx_ts_events_website
ON time_series_events (website_id, time DESC);
-- Index for session-based queries
CREATE INDEX IF NOT EXISTS idx_ts_events_session
ON time_series_events (session_id, time DESC);
-- Index for product-based queries (partial index for sparse data)
CREATE INDEX IF NOT EXISTS idx_ts_events_product
ON time_series_events (product_id, time DESC)
WHERE product_id IS NOT NULL;
-- Index for event type queries
CREATE INDEX IF NOT EXISTS idx_ts_events_event_type
ON time_series_events (event_type, time DESC);
-- ============================================================================
-- Step 4: Create Aggregated Metrics Tables
-- ============================================================================
-- Website metrics aggregated hourly
CREATE TABLE IF NOT EXISTS website_metrics_hourly (
time TIMESTAMPTZ NOT NULL,
website_id UUID NOT NULL,
-- Traffic metrics
pageviews INTEGER DEFAULT 0,
unique_sessions INTEGER DEFAULT 0,
unique_users INTEGER DEFAULT 0,
avg_time_on_page INTEGER,
avg_scroll_depth INTEGER,
bounce_rate DECIMAL(5, 4),
-- Conversion metrics
add_to_cart_count INTEGER DEFAULT 0,
checkout_start_count INTEGER DEFAULT 0,
purchase_count INTEGER DEFAULT 0,
conversion_rate DECIMAL(5, 4),
-- Revenue metrics
total_revenue DECIMAL(19, 4) DEFAULT 0,
avg_order_value DECIMAL(19, 4),
PRIMARY KEY (time, website_id)
);
-- Convert to hypertable
SELECT create_hypertable('website_metrics_hourly', 'time',
chunk_time_interval => INTERVAL '30 days',
if_not_exists => TRUE
);
-- Product metrics aggregated daily
CREATE TABLE IF NOT EXISTS product_metrics_daily (
time DATE NOT NULL,
website_id UUID NOT NULL,
product_id VARCHAR(50) NOT NULL,
-- View metrics
views INTEGER DEFAULT 0,
unique_viewers INTEGER DEFAULT 0,
avg_time_viewed INTEGER,
-- Conversion metrics
add_to_cart_count INTEGER DEFAULT 0,
purchase_count INTEGER DEFAULT 0,
conversion_rate DECIMAL(5, 4),
-- Revenue metrics
revenue DECIMAL(19, 4) DEFAULT 0,
units_sold INTEGER DEFAULT 0,
PRIMARY KEY (time, website_id, product_id)
);
-- Convert to hypertable
SELECT create_hypertable('product_metrics_daily', 'time',
chunk_time_interval => INTERVAL '30 days',
if_not_exists => TRUE
);
-- ============================================================================
-- Step 5: Create Continuous Aggregates (Materialized Views)
-- ============================================================================
-- Hourly website metrics continuous aggregate
CREATE MATERIALIZED VIEW IF NOT EXISTS website_metrics_hourly_agg
WITH (timescaledb.continuous) AS
SELECT
time_bucket('1 hour', time) AS time,
website_id,
COUNT(*) FILTER (WHERE event_type = 'pageview') as pageviews,
COUNT(DISTINCT session_id) as unique_sessions,
COUNT(DISTINCT user_id) FILTER (WHERE user_id IS NOT NULL) as unique_users,
COUNT(*) FILTER (WHERE event_name = 'add_to_cart') as add_to_cart_count,
COUNT(*) FILTER (WHERE event_name = 'checkout_start') as checkout_start_count,
COUNT(*) FILTER (WHERE event_name = 'purchase') as purchase_count,
SUM(event_value) FILTER (WHERE event_name = 'purchase') as total_revenue
FROM time_series_events
GROUP BY time_bucket('1 hour', time), website_id;
-- Add refresh policy for continuous aggregate
SELECT add_continuous_aggregate_policy('website_metrics_hourly_agg',
start_offset => INTERVAL '3 hours',
end_offset => INTERVAL '1 hour',
schedule_interval => INTERVAL '1 hour',
if_not_exists => TRUE
);
-- Daily product metrics continuous aggregate
CREATE MATERIALIZED VIEW IF NOT EXISTS product_metrics_daily_agg
WITH (timescaledb.continuous) AS
SELECT
time_bucket('1 day', time) AS time,
website_id,
product_id,
COUNT(*) FILTER (WHERE event_name = 'product_view') as views,
COUNT(DISTINCT session_id) FILTER (WHERE event_name = 'product_view') as unique_viewers,
COUNT(*) FILTER (WHERE event_name = 'add_to_cart') as add_to_cart_count,
COUNT(*) FILTER (WHERE event_name = 'purchase') as purchase_count,
SUM(event_value) FILTER (WHERE event_name = 'purchase') as revenue
FROM time_series_events
WHERE product_id IS NOT NULL
GROUP BY time_bucket('1 day', time), website_id, product_id;
-- Add refresh policy for product metrics
SELECT add_continuous_aggregate_policy('product_metrics_daily_agg',
start_offset => INTERVAL '7 days',
end_offset => INTERVAL '1 day',
schedule_interval => INTERVAL '1 day',
if_not_exists => TRUE
);
-- ============================================================================
-- Step 6: Create Data Retention Policies
-- ============================================================================
-- Retain raw time-series events for 90 days
SELECT add_retention_policy('time_series_events',
INTERVAL '90 days',
if_not_exists => TRUE
);
-- Retain hourly aggregates for 1 year
SELECT add_retention_policy('website_metrics_hourly',
INTERVAL '1 year',
if_not_exists => TRUE
);
-- Retain daily product metrics for 2 years
SELECT add_retention_policy('product_metrics_daily',
INTERVAL '2 years',
if_not_exists => TRUE
);
-- ============================================================================
-- Migration Complete
-- ============================================================================
DO $$
BEGIN
RAISE NOTICE '=================================================================';
RAISE NOTICE 'TimescaleDB Migration Complete';
RAISE NOTICE 'Hypertables: time_series_events, website_metrics_hourly, product_metrics_daily';
RAISE NOTICE 'Continuous Aggregates: website_metrics_hourly_agg, product_metrics_daily_agg';
RAISE NOTICE 'Retention Policies: 90 days (raw), 1 year (hourly), 2 years (daily)';
RAISE NOTICE '=================================================================';
END $$;

View file

@ -121,6 +121,20 @@ model WebsiteEvent {
tag String? @db.VarChar(50)
hostname String? @db.VarChar(100)
// Enhanced engagement tracking fields
scrollDepth Int? @map("scroll_depth") @db.Integer
timeOnPage Int? @map("time_on_page") @db.Integer
clickCount Int? @map("click_count") @db.Integer
formInteractions Json? @map("form_interactions")
// WooCommerce e-commerce tracking fields
wcProductId String? @map("wc_product_id") @db.VarChar(50)
wcCategoryId String? @map("wc_category_id") @db.VarChar(50)
wcCartValue Decimal? @map("wc_cart_value") @db.Decimal(19, 4)
wcCheckoutStep Int? @map("wc_checkout_step") @db.Integer
wcOrderId String? @map("wc_order_id") @db.VarChar(50)
wcRevenue Decimal? @map("wc_revenue") @db.Decimal(19, 4)
eventData EventData[]
session Session @relation(fields: [sessionId], references: [id])