feat(analytics): Dashboard v2 con recomendaciones accionables y UX mejorada

- Agregar KPIs con tendencias vs período anterior (↑↓% comparativo)
- Implementar secciones de recomendaciones: Contenido a Crear, CTR 0%,
  Quick Wins, Contenido Estrella, Contenido en Decadencia
- Convertir listados a tablas con columnas separadas para mejor legibilidad
- Agregar botones Editar + Ver en todas las tablas de posts
- Ocultar secciones vacías dinámicamente (Búsquedas Sin Resultados)
- Relajar criterios Quick Wins: pos 2-15, CTR ≥2%, búsquedas ≥2
- Incluir distribución de clicks por posición con barras de progreso
- Agregar exportación a Markdown para análisis con IA

Archivos nuevos:
- admin/class-analytics-dashboard.php (UI del dashboard)
- admin/class-metrics-repository.php (queries de métricas)
- admin/assets/dashboard.css (estilos Bootstrap 5)
- admin/assets/dashboard.js (interactividad y export)
- sql/create-indices.sql (índices para optimización)

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
FrankZamora
2025-12-03 20:15:56 -06:00
parent 255d720db6
commit 41fb658ca7
6 changed files with 1821 additions and 2 deletions

View File

@@ -0,0 +1,552 @@
<?php
/**
* Metrics Repository for Analytics Dashboard
*
* @package ROI_APU_Search
* @since 1.2.0
*/
declare(strict_types=1);
// Prevent direct access
if (!defined('ABSPATH')) {
exit;
}
/**
* Repository class for dashboard metrics queries
*/
final class ROI_APU_Metrics_Repository
{
private PDO $pdo;
private string $prefix;
/**
* Constructor
*
* @param PDO $pdo Database connection
* @param string $prefix Table prefix
*/
public function __construct(PDO $pdo, string $prefix)
{
$this->pdo = $pdo;
$this->prefix = $prefix;
}
/**
* Get KPIs for dashboard with trends vs previous period
*
* @param int $days Number of days to query
* @return array{total_busquedas: int, pct_sin_resultados: float, clicks: int, ctr: float, pos_prom: float, trends: array}
*/
public function getKPIs(int $days = 30): array
{
// Default values
$result = [
'total_busquedas' => 0,
'pct_sin_resultados' => 0.0,
'clicks' => 0,
'ctr' => 0.0,
'pos_prom' => 0.0,
'trends' => [
'busquedas' => 0.0,
'ctr' => 0.0,
'sin_resultados' => 0.0,
'pos_prom' => 0.0,
],
];
try {
// Query 1: Basic KPIs from searches table
$sql1 = "SELECT
COUNT(*) as total_busquedas,
ROUND(SUM(zero_results)*100.0/NULLIF(COUNT(*), 0), 2) as pct_sin_resultados
FROM {$this->prefix}rcp_paginas_querys
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmt1 = $this->pdo->prepare($sql1);
$stmt1->execute(['days' => $days]);
$row1 = $stmt1->fetch();
if ($row1) {
$result['total_busquedas'] = (int) ($row1['total_busquedas'] ?? 0);
$result['pct_sin_resultados'] = (float) ($row1['pct_sin_resultados'] ?? 0);
}
// Query 2: Clicks, CTR (correct calculation), and average position
// CTR = búsquedas con al menos 1 click / total búsquedas
$sql2 = "SELECT
COUNT(*) as clicks,
COUNT(DISTINCT search_id) as busquedas_con_click,
ROUND(AVG(position), 1) as pos_prom
FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmt2 = $this->pdo->prepare($sql2);
$stmt2->execute(['days' => $days]);
$row2 = $stmt2->fetch();
if ($row2) {
$result['clicks'] = (int) ($row2['clicks'] ?? 0);
$result['pos_prom'] = (float) ($row2['pos_prom'] ?? 0);
// Calculate CTR correctly: distinct searches with clicks / total searches
$busquedasConClick = (int) ($row2['busquedas_con_click'] ?? 0);
if ($result['total_busquedas'] > 0) {
$result['ctr'] = round(($busquedasConClick / $result['total_busquedas']) * 100, 1);
}
}
// Query 3: Previous period for trends comparison
$sqlPrev1 = "SELECT
COUNT(*) as total_busquedas,
ROUND(SUM(zero_results)*100.0/NULLIF(COUNT(*), 0), 2) as pct_sin_resultados
FROM {$this->prefix}rcp_paginas_querys
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days2 DAY)
AND ts < DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmtPrev1 = $this->pdo->prepare($sqlPrev1);
$stmtPrev1->bindValue('days', $days, PDO::PARAM_INT);
$stmtPrev1->bindValue('days2', $days * 2, PDO::PARAM_INT);
$stmtPrev1->execute();
$prevRow1 = $stmtPrev1->fetch();
$sqlPrev2 = "SELECT
COUNT(*) as clicks,
COUNT(DISTINCT search_id) as busquedas_con_click,
ROUND(AVG(position), 1) as pos_prom
FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days2 DAY)
AND ts < DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmtPrev2 = $this->pdo->prepare($sqlPrev2);
$stmtPrev2->bindValue('days', $days, PDO::PARAM_INT);
$stmtPrev2->bindValue('days2', $days * 2, PDO::PARAM_INT);
$stmtPrev2->execute();
$prevRow2 = $stmtPrev2->fetch();
// Calculate trends
if ($prevRow1 && $prevRow2) {
$prevBusquedas = (int) ($prevRow1['total_busquedas'] ?? 0);
$prevSinResultados = (float) ($prevRow1['pct_sin_resultados'] ?? 0);
$prevBusquedasConClick = (int) ($prevRow2['busquedas_con_click'] ?? 0);
$prevCtr = $prevBusquedas > 0 ? round(($prevBusquedasConClick / $prevBusquedas) * 100, 1) : 0;
$prevPosProm = (float) ($prevRow2['pos_prom'] ?? 0);
// Trend = current - previous (positive = improvement for most, except pos_prom)
if ($prevBusquedas > 0) {
$result['trends']['busquedas'] = round((($result['total_busquedas'] - $prevBusquedas) / $prevBusquedas) * 100, 1);
}
if ($prevCtr > 0) {
$result['trends']['ctr'] = round($result['ctr'] - $prevCtr, 1);
}
$result['trends']['sin_resultados'] = round($result['pct_sin_resultados'] - $prevSinResultados, 1);
if ($prevPosProm > 0) {
$result['trends']['pos_prom'] = round($result['pos_prom'] - $prevPosProm, 1);
}
}
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getKPIs error: ' . $e->getMessage());
}
return $result;
}
/**
* Get terms with CTR 0% (have results but no clicks)
*
* @param int $days Number of days to query
* @param int $limit Max results
* @return array<array{q_term: string, busquedas: int, resultados: int}>
*/
public function getCTRZero(int $days = 30, int $limit = 20): array
{
try {
$sql = "SELECT s.q_term, COUNT(DISTINCT s.id) as busquedas, MAX(s.total_results) as resultados
FROM {$this->prefix}rcp_paginas_querys s
LEFT JOIN {$this->prefix}rcp_paginas_querys_log c ON s.id = c.search_id
WHERE s.total_results > 0
AND c.id IS NULL
AND s.ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY s.q_term
HAVING busquedas >= 3
ORDER BY busquedas DESC
LIMIT :limit";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getCTRZero error: ' . $e->getMessage());
return [];
}
}
/**
* Get underpositioned posts (many clicks but high position)
*
* @param int $days Number of days to query
* @param int $minClicks Minimum clicks threshold
* @param int $minPosition Minimum position threshold
* @param int $limit Max results
* @return array<array{post_id: int, post_title: string, clicks: int, pos_prom: float}>
*/
public function getInfraposicionados(
int $days = 30,
int $minClicks = 5,
int $minPosition = 5,
int $limit = 20
): array {
try {
$sql = "SELECT c.post_id, p.post_title, COUNT(*) as clicks, ROUND(AVG(c.position), 1) as pos_prom
FROM {$this->prefix}rcp_paginas_querys_log c
JOIN {$this->prefix}posts p ON c.post_id = p.ID
WHERE c.ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY c.post_id, p.post_title
HAVING clicks >= :minClicks AND pos_prom >= :minPosition
ORDER BY clicks DESC
LIMIT :limit";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('minClicks', $minClicks, PDO::PARAM_INT);
$stmt->bindValue('minPosition', $minPosition, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getInfraposicionados error: ' . $e->getMessage());
return [];
}
}
// ========================================================================
// Dashboard v2 Methods - Recomendaciones Accionables
// ========================================================================
/**
* Get top search terms with metrics (paginated)
*
* @param int $days Number of days to query
* @param int $limit Results per page
* @param int $offset Pagination offset
* @return array<array{q_term: string, busquedas: int, clicks: int, ctr: float, resultados: int}>
*/
public function getTopSearches(int $days = 30, int $limit = 20, int $offset = 0): array
{
try {
$sql = "SELECT
s.q_term,
COUNT(DISTINCT s.id) as busquedas,
COUNT(DISTINCT c.id) as clicks,
ROUND(COUNT(DISTINCT c.search_id) * 100.0 / NULLIF(COUNT(DISTINCT s.id), 0), 1) as ctr,
MAX(s.total_results) as resultados
FROM {$this->prefix}rcp_paginas_querys s
LEFT JOIN {$this->prefix}rcp_paginas_querys_log c ON s.id = c.search_id
WHERE s.ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY s.q_term
ORDER BY busquedas DESC
LIMIT :limit OFFSET :offset";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->bindValue('offset', $offset, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getTopSearches error: ' . $e->getMessage());
return [];
}
}
/**
* Get top clicked posts with URL (paginated)
*
* @param int $days Number of days to query
* @param int $limit Results per page
* @param int $offset Pagination offset
* @return array<array{post_id: int, post_title: string, post_name: string, clicks: int, busquedas_con_click: int, pos_prom: float}>
*/
public function getTopClicks(int $days = 30, int $limit = 20, int $offset = 0): array
{
try {
$sql = "SELECT
c.post_id,
p.post_title,
p.post_name,
COUNT(DISTINCT c.id) as clicks,
COUNT(DISTINCT c.search_id) as busquedas_con_click,
ROUND(AVG(c.position), 1) as pos_prom
FROM {$this->prefix}rcp_paginas_querys_log c
JOIN {$this->prefix}posts p ON c.post_id = p.ID
WHERE c.ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY c.post_id, p.post_title, p.post_name
ORDER BY clicks DESC
LIMIT :limit OFFSET :offset";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->bindValue('offset', $offset, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getTopClicks error: ' . $e->getMessage());
return [];
}
}
/**
* Get searches with zero results (paginated)
*
* @param int $days Number of days to query
* @param int $limit Results per page
* @param int $offset Pagination offset
* @return array<array{q_term: string, frecuencia: int, ultima_busqueda: string}>
*/
public function getZeroResults(int $days = 30, int $limit = 20, int $offset = 0): array
{
try {
$sql = "SELECT
q_term,
COUNT(*) as frecuencia,
MAX(ts) as ultima_busqueda
FROM {$this->prefix}rcp_paginas_querys
WHERE zero_results = 1
AND ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY q_term
ORDER BY frecuencia DESC
LIMIT :limit OFFSET :offset";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->bindValue('offset', $offset, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getZeroResults error: ' . $e->getMessage());
return [];
}
}
/**
* Get quick wins: terms in position 2-15 with some CTR
* Relaxed criteria to show more actionable data
*
* @param int $days Number of days to query
* @param int $limit Max results
* @return array<array{q_term: string, busquedas: int, clicks: int, ctr: float, pos_prom: float}>
*/
public function getQuickWins(int $days = 30, int $limit = 10): array
{
try {
$sql = "SELECT
s.q_term,
COUNT(DISTINCT s.id) as busquedas,
COUNT(DISTINCT c.id) as clicks,
ROUND(COUNT(DISTINCT c.search_id) * 100.0 / NULLIF(COUNT(DISTINCT s.id), 0), 1) as ctr,
ROUND(AVG(c.position), 1) as pos_prom
FROM {$this->prefix}rcp_paginas_querys s
JOIN {$this->prefix}rcp_paginas_querys_log c ON s.id = c.search_id
WHERE s.ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY s.q_term
HAVING pos_prom BETWEEN 2 AND 15
AND ctr >= 2.0
AND busquedas >= 2
ORDER BY busquedas DESC
LIMIT :limit";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getQuickWins error: ' . $e->getMessage());
return [];
}
}
/**
* Get star content: posts with most clicks
*
* @param int $days Number of days to query
* @param int $limit Max results
* @return array<array{post_id: int, post_title: string, post_name: string, clicks: int, busquedas_con_click: int, pos_prom: float}>
*/
public function getContenidoEstrella(int $days = 30, int $limit = 10): array
{
try {
$sql = "SELECT
c.post_id,
p.post_title,
p.post_name,
COUNT(DISTINCT c.id) as clicks,
COUNT(DISTINCT c.search_id) as busquedas_con_click,
ROUND(AVG(c.position), 1) as pos_prom
FROM {$this->prefix}rcp_paginas_querys_log c
JOIN {$this->prefix}posts p ON c.post_id = p.ID
WHERE c.ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY c.post_id, p.post_title, p.post_name
HAVING clicks >= 3
ORDER BY clicks DESC
LIMIT :limit";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getContenidoEstrella error: ' . $e->getMessage());
return [];
}
}
/**
* Get click distribution by position
*
* @param int $days Number of days to query
* @return array<array{posicion: string, clicks: int, porcentaje: float}>
*/
public function getClickDistribution(int $days = 30): array
{
try {
$sql = "SELECT
CASE
WHEN position = 1 THEN 'Pos 1'
WHEN position = 2 THEN 'Pos 2'
WHEN position = 3 THEN 'Pos 3'
WHEN position = 4 THEN 'Pos 4'
WHEN position = 5 THEN 'Pos 5'
ELSE 'Pos 6+'
END as posicion,
COUNT(*) as clicks,
ROUND(COUNT(*) * 100.0 / NULLIF((
SELECT COUNT(*) FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days2 DAY)
), 0), 1) as porcentaje
FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY posicion
ORDER BY MIN(position)";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('days2', $days, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getClickDistribution error: ' . $e->getMessage());
return [];
}
}
/**
* Get decaying content: posts that lost clicks vs previous period
*
* @param int $days Number of days to query
* @param int $limit Max results
* @return array<array{post_id: int, post_title: string, post_name: string, clicks_actual: int, clicks_anterior: int, cambio_pct: float}>
*/
public function getDecayContent(int $days = 30, int $limit = 10): array
{
try {
$sql = "SELECT
pa.post_id,
p.post_title,
p.post_name,
COALESCE(curr.clicks_actual, 0) as clicks_actual,
pa.clicks_anterior,
ROUND((COALESCE(curr.clicks_actual, 0) - pa.clicks_anterior) * 100.0 / pa.clicks_anterior, 1) as cambio_pct
FROM (
SELECT post_id, COUNT(*) as clicks_anterior
FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days2 DAY)
AND ts < DATE_SUB(NOW(), INTERVAL :days DAY)
GROUP BY post_id
) pa
LEFT JOIN (
SELECT post_id, COUNT(*) as clicks_actual
FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days3 DAY)
GROUP BY post_id
) curr ON pa.post_id = curr.post_id
JOIN {$this->prefix}posts p ON pa.post_id = p.ID
WHERE pa.clicks_anterior >= 3
AND (COALESCE(curr.clicks_actual, 0) - pa.clicks_anterior) * 100.0 / pa.clicks_anterior <= -20
ORDER BY cambio_pct ASC
LIMIT :limit";
$stmt = $this->pdo->prepare($sql);
$stmt->bindValue('days', $days, PDO::PARAM_INT);
$stmt->bindValue('days2', $days * 2, PDO::PARAM_INT);
$stmt->bindValue('days3', $days, PDO::PARAM_INT);
$stmt->bindValue('limit', $limit, PDO::PARAM_INT);
$stmt->execute();
return $stmt->fetchAll();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getDecayContent error: ' . $e->getMessage());
return [];
}
}
/**
* Get total counts for pagination
*
* @param int $days Number of days to query
* @return array{total_searches: int, total_clicks: int, total_zero_results: int}
*/
public function getTotalCounts(int $days = 30): array
{
$result = [
'total_searches' => 0,
'total_clicks' => 0,
'total_zero_results' => 0,
];
try {
// Count distinct search terms
$sql1 = "SELECT COUNT(DISTINCT q_term) as total
FROM {$this->prefix}rcp_paginas_querys
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmt1 = $this->pdo->prepare($sql1);
$stmt1->execute(['days' => $days]);
$result['total_searches'] = (int) $stmt1->fetchColumn();
// Count distinct clicked posts
$sql2 = "SELECT COUNT(DISTINCT post_id) as total
FROM {$this->prefix}rcp_paginas_querys_log
WHERE ts >= DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmt2 = $this->pdo->prepare($sql2);
$stmt2->execute(['days' => $days]);
$result['total_clicks'] = (int) $stmt2->fetchColumn();
// Count distinct zero result terms
$sql3 = "SELECT COUNT(DISTINCT q_term) as total
FROM {$this->prefix}rcp_paginas_querys
WHERE zero_results = 1
AND ts >= DATE_SUB(NOW(), INTERVAL :days DAY)";
$stmt3 = $this->pdo->prepare($sql3);
$stmt3->execute(['days' => $days]);
$result['total_zero_results'] = (int) $stmt3->fetchColumn();
} catch (PDOException $e) {
error_log('ROI APU Metrics Repository - getTotalCounts error: ' . $e->getMessage());
}
return $result;
}
}