-- Tabelas para Sistema MDM (Mobile Device Management) -- Tabela de políticas CREATE TABLE IF NOT EXISTS policies ( id SERIAL PRIMARY KEY, name VARCHAR(255) NOT NULL, description TEXT, type VARCHAR(50) NOT NULL, -- 'windows_update', 'software_install', 'registry', 'script', 'security', etc. config JSONB NOT NULL DEFAULT '{}', -- Configuração específica da política enabled BOOLEAN DEFAULT true, schedule VARCHAR(100), -- Cron expression ou 'immediate' priority INTEGER DEFAULT 5, -- 1-10, 10 = mais alta created_at TIMESTAMP DEFAULT NOW(), updated_at TIMESTAMP DEFAULT NOW() ); -- Índices para policies CREATE INDEX IF NOT EXISTS idx_policies_type ON policies(type); CREATE INDEX IF NOT EXISTS idx_policies_enabled ON policies(enabled); -- Tabela de associação: dispositivos x políticas CREATE TABLE IF NOT EXISTS device_policies ( id SERIAL PRIMARY KEY, device_id VARCHAR(255) NOT NULL, policy_id INTEGER NOT NULL, assigned_at TIMESTAMP DEFAULT NOW(), FOREIGN KEY (device_id) REFERENCES devices(device_id) ON DELETE CASCADE, FOREIGN KEY (policy_id) REFERENCES policies(id) ON DELETE CASCADE, UNIQUE(device_id, policy_id) ); -- Índices para device_policies CREATE INDEX IF NOT EXISTS idx_device_policies_device ON device_policies(device_id); CREATE INDEX IF NOT EXISTS idx_device_policies_policy ON device_policies(policy_id); -- Tabela de comandos de política (fila de execução) CREATE TABLE IF NOT EXISTS policy_commands ( id SERIAL PRIMARY KEY, device_id VARCHAR(255) NOT NULL, policy_id INTEGER NOT NULL, command_type VARCHAR(50) NOT NULL, command_data JSONB NOT NULL DEFAULT '{}', status VARCHAR(20) DEFAULT 'pending', -- 'pending', 'sent', 'executing', 'success', 'failed', 'cancelled' priority INTEGER DEFAULT 5, created_at TIMESTAMP DEFAULT NOW(), sent_at TIMESTAMP, completed_at TIMESTAMP, result JSONB, error_message TEXT, retry_count INTEGER DEFAULT 0, max_retries INTEGER DEFAULT 3, FOREIGN KEY (device_id) REFERENCES devices(device_id) ON DELETE CASCADE, FOREIGN KEY (policy_id) REFERENCES policies(id) ON DELETE CASCADE ); -- Índices para policy_commands CREATE INDEX IF NOT EXISTS idx_policy_commands_device ON policy_commands(device_id); CREATE INDEX IF NOT EXISTS idx_policy_commands_status ON policy_commands(status); CREATE INDEX IF NOT EXISTS idx_policy_commands_created ON policy_commands(created_at DESC); -- Tabela de histórico de execução de políticas CREATE TABLE IF NOT EXISTS policy_executions ( id SERIAL PRIMARY KEY, device_id VARCHAR(255) NOT NULL, policy_id INTEGER NOT NULL, command_id INTEGER, status VARCHAR(20) NOT NULL, -- 'success', 'failed', 'partial' executed_at TIMESTAMP DEFAULT NOW(), duration_seconds INTEGER, result JSONB, error_message TEXT, details TEXT, FOREIGN KEY (device_id) REFERENCES devices(device_id) ON DELETE CASCADE, FOREIGN KEY (policy_id) REFERENCES policies(id) ON DELETE CASCADE, FOREIGN KEY (command_id) REFERENCES policy_commands(id) ON DELETE SET NULL ); -- Índices para policy_executions CREATE INDEX IF NOT EXISTS idx_policy_executions_device ON policy_executions(device_id); CREATE INDEX IF NOT EXISTS idx_policy_executions_policy ON policy_executions(policy_id); CREATE INDEX IF NOT EXISTS idx_policy_executions_executed ON policy_executions(executed_at DESC); CREATE INDEX IF NOT EXISTS idx_policy_executions_status ON policy_executions(status); -- Tabela de templates de políticas (pré-configuradas) CREATE TABLE IF NOT EXISTS policy_templates ( id SERIAL PRIMARY KEY, name VARCHAR(255) NOT NULL, description TEXT, category VARCHAR(50), -- 'security', 'updates', 'software', 'configuration', etc. type VARCHAR(50) NOT NULL, default_config JSONB NOT NULL DEFAULT '{}', icon VARCHAR(100), created_at TIMESTAMP DEFAULT NOW() ); -- Índices para policy_templates CREATE INDEX IF NOT EXISTS idx_policy_templates_category ON policy_templates(category); CREATE INDEX IF NOT EXISTS idx_policy_templates_type ON policy_templates(type); -- Inserir templates padrão de políticas INSERT INTO policy_templates (name, description, category, type, default_config, icon) VALUES ( 'Forçar Windows Update', 'Força a verificação e instalação de atualizações do Windows', 'updates', 'windows_update', '{ "action": "force_check_and_install", "reboot_if_required": true, "reboot_delay_minutes": 30, "include_optional": false, "max_wait_hours": 24 }', 'update' ), ( 'Instalar Software', 'Instala software via URL de download ou repositório', 'software', 'software_install', '{ "software_name": "", "download_url": "", "install_args": "/S /SILENT", "verify_install": true, "uninstall_first": false }', 'download' ), ( 'Executar Script PowerShell', 'Executa um script PowerShell personalizado', 'configuration', 'powershell_script', '{ "script": "", "run_as_admin": true, "timeout_minutes": 30, "execution_policy": "Bypass" }', 'terminal' ), ( 'Configurar Registro do Windows', 'Modifica chaves do registro do Windows', 'configuration', 'registry', '{ "hive": "HKLM", "key": "", "value_name": "", "value_data": "", "value_type": "String", "create_if_missing": true }', 'settings' ), ( 'Reiniciar Dispositivo', 'Reinicia o dispositivo Windows', 'maintenance', 'reboot', '{ "delay_minutes": 5, "force": false, "message": "O sistema será reiniciado em breve" }', 'refresh' ), ( 'Limpar Arquivos Temporários', 'Remove arquivos temporários e cache para liberar espaço', 'maintenance', 'cleanup', '{ "clear_temp": true, "clear_windows_temp": true, "clear_browser_cache": true, "clear_recycle_bin": true, "min_age_days": 7 }', 'trash' ), ( 'Configurar Firewall', 'Adiciona ou modifica regras do Windows Firewall', 'security', 'firewall', '{ "action": "add_rule", "rule_name": "", "direction": "inbound", "protocol": "TCP", "port": "", "action_type": "allow" }', 'shield' ), ( 'Desinstalar Software', 'Remove software instalado no dispositivo', 'software', 'software_uninstall', '{ "software_name": "", "silent": true, "force": false }', 'delete' ) ON CONFLICT DO NOTHING; -- View para resumo de políticas por dispositivo CREATE OR REPLACE VIEW device_policies_summary AS SELECT d.device_id, d.device_name, COUNT(DISTINCT dp.policy_id) as total_policies, COUNT(DISTINCT CASE WHEN p.enabled = true THEN dp.policy_id END) as active_policies, MAX(pe.executed_at) as last_execution, COUNT(DISTINCT CASE WHEN pe.status = 'success' THEN pe.id END) as successful_executions, COUNT(DISTINCT CASE WHEN pe.status = 'failed' THEN pe.id END) as failed_executions FROM devices d LEFT JOIN device_policies dp ON d.device_id = dp.device_id LEFT JOIN policies p ON dp.policy_id = p.id LEFT JOIN policy_executions pe ON d.device_id = pe.device_id GROUP BY d.device_id, d.device_name; -- View para comandos pendentes por dispositivo CREATE OR REPLACE VIEW pending_commands_by_device AS SELECT device_id, COUNT(*) as pending_count, MIN(created_at) as oldest_command, MAX(priority) as highest_priority FROM policy_commands WHERE status IN ('pending', 'sent') GROUP BY device_id; -- Comentários nas tabelas COMMENT ON TABLE policies IS 'Políticas MDM que podem ser aplicadas aos dispositivos'; COMMENT ON TABLE device_policies IS 'Associação entre dispositivos e políticas'; COMMENT ON TABLE policy_commands IS 'Fila de comandos de política a serem executados'; COMMENT ON TABLE policy_executions IS 'Histórico de execução de políticas'; COMMENT ON TABLE policy_templates IS 'Templates pré-configurados de políticas comuns'; COMMENT ON COLUMN policies.config IS 'Configuração JSON específica de cada tipo de política'; COMMENT ON COLUMN policies.schedule IS 'Quando executar: immediate, cron expression, ou NULL para manual'; COMMENT ON COLUMN policy_commands.status IS 'Status do comando: pending, sent, executing, success, failed, cancelled'; COMMENT ON COLUMN policy_commands.retry_count IS 'Número de tentativas de execução'; -- Função para limpar execuções antigas (manter apenas últimos 90 dias) CREATE OR REPLACE FUNCTION cleanup_old_policy_executions() RETURNS INTEGER AS $$ DECLARE deleted_count INTEGER; BEGIN DELETE FROM policy_executions WHERE executed_at < NOW() - INTERVAL '90 days'; GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END; $$ LANGUAGE plpgsql; -- Trigger para atualizar updated_at em policies CREATE OR REPLACE FUNCTION update_policies_timestamp() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER trigger_update_policies_timestamp BEFORE UPDATE ON policies FOR EACH ROW EXECUTE FUNCTION update_policies_timestamp(); COMMENT ON FUNCTION cleanup_old_policy_executions IS 'Remove execuções de políticas com mais de 90 dias';