feat: Added NetworkGroups
- Entity - Dtos - Manage Services - SQL Table creation - View & permissions
This commit is contained in:
105
SQL/NetworkGroups.sql
Normal file
105
SQL/NetworkGroups.sql
Normal file
@@ -0,0 +1,105 @@
|
||||
-- Migration: AddNetworkGroups
|
||||
-- Description: Adds SplashNetworkGroup and SplashNetworkGroupMember tables
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Create SplashNetworkGroups table
|
||||
CREATE TABLE "SplashNetworkGroups" (
|
||||
"Id" serial PRIMARY KEY,
|
||||
"Name" character varying(256) NOT NULL,
|
||||
"Description" character varying(512),
|
||||
"IsActive" boolean NOT NULL DEFAULT true,
|
||||
"TenantId" integer NOT NULL,
|
||||
"CreationTime" timestamp with time zone NOT NULL DEFAULT now(),
|
||||
"CreatorUserId" bigint,
|
||||
"LastModificationTime" timestamp with time zone,
|
||||
"LastModifierUserId" bigint,
|
||||
"IsDeleted" boolean NOT NULL DEFAULT false,
|
||||
"DeleterUserId" bigint,
|
||||
"DeletionTime" timestamp with time zone
|
||||
);
|
||||
|
||||
-- Create SplashNetworkGroupMembers table
|
||||
CREATE TABLE "SplashNetworkGroupMembers" (
|
||||
"Id" serial PRIMARY KEY,
|
||||
"NetworkGroupId" integer NOT NULL,
|
||||
"NetworkId" integer NOT NULL,
|
||||
"TenantId" integer NOT NULL,
|
||||
"CreationTime" timestamp with time zone NOT NULL DEFAULT now(),
|
||||
"CreatorUserId" bigint
|
||||
);
|
||||
|
||||
-- Create indexes for SplashNetworkGroups
|
||||
CREATE UNIQUE INDEX "IX_SplashNetworkGroups_Name_TenantId"
|
||||
ON "SplashNetworkGroups" ("Name", "TenantId");
|
||||
|
||||
CREATE INDEX "IX_SplashNetworkGroups_TenantId"
|
||||
ON "SplashNetworkGroups" ("TenantId");
|
||||
|
||||
CREATE INDEX "IX_SplashNetworkGroups_IsActive"
|
||||
ON "SplashNetworkGroups" ("IsActive");
|
||||
|
||||
-- Create indexes for SplashNetworkGroupMembers
|
||||
CREATE UNIQUE INDEX "IX_SplashNetworkGroupMembers_NetworkGroupId_NetworkId"
|
||||
ON "SplashNetworkGroupMembers" ("NetworkGroupId", "NetworkId");
|
||||
|
||||
CREATE INDEX "IX_SplashNetworkGroupMembers_NetworkGroupId"
|
||||
ON "SplashNetworkGroupMembers" ("NetworkGroupId");
|
||||
|
||||
CREATE INDEX "IX_SplashNetworkGroupMembers_NetworkId"
|
||||
ON "SplashNetworkGroupMembers" ("NetworkId");
|
||||
|
||||
CREATE INDEX "IX_SplashNetworkGroupMembers_TenantId"
|
||||
ON "SplashNetworkGroupMembers" ("TenantId");
|
||||
|
||||
-- Add foreign key constraints
|
||||
ALTER TABLE "SplashNetworkGroupMembers"
|
||||
ADD CONSTRAINT "FK_SplashNetworkGroupMembers_SplashNetworkGroups_NetworkGroupId"
|
||||
FOREIGN KEY ("NetworkGroupId") REFERENCES "SplashNetworkGroups" ("Id") ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE "SplashNetworkGroupMembers"
|
||||
ADD CONSTRAINT "FK_SplashNetworkGroupMembers_SplashMerakiNetworks_NetworkId"
|
||||
FOREIGN KEY ("NetworkId") REFERENCES "SplashMerakiNetworks" ("Id") ON DELETE CASCADE;
|
||||
|
||||
-- Add SelectedNetworkGroups column to SplashDashboards table
|
||||
ALTER TABLE "SplashDashboards"
|
||||
ADD COLUMN "SelectedNetworkGroups" integer[] DEFAULT '{}';
|
||||
|
||||
-- Create index for the new column
|
||||
CREATE INDEX "IX_SplashDashboards_SelectedNetworkGroups"
|
||||
ON "SplashDashboards" USING GIN ("SelectedNetworkGroups");
|
||||
|
||||
-- Insert migration history record (if using EF Core migrations table)
|
||||
INSERT INTO "__EFMigrationsHistory" ("MigrationId", "ProductVersion")
|
||||
VALUES ('20250106000000_AddNetworkGroups', '8.0.0');
|
||||
|
||||
COMMIT;
|
||||
|
||||
Notas importantes sobre el script:
|
||||
|
||||
1. Tipos de datos PostgreSQL: Uso serial para auto-incremento y timestamp with time zone para fechas
|
||||
2. Arrays: PostgreSQL maneja arrays nativamente, por eso SelectedNetworkGroups es integer[]
|
||||
3. Índices GIN: Para el array SelectedNetworkGroups uso un índice GIN que es óptimo para arrays
|
||||
4. Cascada: Las foreign keys tienen ON DELETE CASCADE para mantener integridad
|
||||
5. Valores por defecto: Arrays vacíos se inicializan con '{}'
|
||||
|
||||
Para ejecutar este script:
|
||||
|
||||
# Si usas psql directamente:
|
||||
psql -h localhost -U your_user -d your_database -f migration_script.sql
|
||||
|
||||
# O copiarlo y pegarlo en tu cliente de PostgreSQL preferido
|
||||
|
||||
Verificación después de ejecutar:
|
||||
|
||||
-- Verificar que las tablas se crearon correctamente
|
||||
SELECT table_name FROM information_schema.tables
|
||||
WHERE table_name IN ('SplashNetworkGroups', 'SplashNetworkGroupMembers');
|
||||
|
||||
-- Verificar la nueva columna en SplashDashboards
|
||||
SELECT column_name, data_type FROM information_schema.columns
|
||||
WHERE table_name = 'SplashDashboards' AND column_name = 'SelectedNetworkGroups';
|
||||
|
||||
-- Verificar índices
|
||||
SELECT indexname FROM pg_indexes
|
||||
WHERE tablename IN ('SplashNetworkGroups', 'SplashNetworkGroupMembers');
|
||||
153
SQL/splash_wifi_connection_report/rollback_loyalty_changes.sql
Normal file
153
SQL/splash_wifi_connection_report/rollback_loyalty_changes.sql
Normal file
@@ -0,0 +1,153 @@
|
||||
-- SCRIPT DE ROLLBACK: Restaurar View Original
|
||||
-- Creado: 2025-01-09
|
||||
-- Propósito: Restaurar rápidamente el view splash_wifi_connection_report a su estado original
|
||||
|
||||
-- ===========================================
|
||||
-- PASO 1: Verificar Estado Actual
|
||||
-- ===========================================
|
||||
|
||||
-- Verificar que el view modificado existe
|
||||
SELECT
|
||||
schemaname,
|
||||
viewname,
|
||||
viewowner,
|
||||
definition
|
||||
FROM pg_views
|
||||
WHERE viewname = 'splash_wifi_connection_report';
|
||||
|
||||
-- ===========================================
|
||||
-- PASO 2: ROLLBACK COMPLETO
|
||||
-- ===========================================
|
||||
|
||||
-- Eliminar el view modificado
|
||||
DROP VIEW IF EXISTS public.splash_wifi_connection_report;
|
||||
|
||||
-- Recrear el view original (exactamente como estaba antes)
|
||||
CREATE OR REPLACE VIEW public.splash_wifi_connection_report
|
||||
AS
|
||||
SELECT con."Id" AS "ConnectionId",
|
||||
con."CreationTime" AS "ConnectionDateTime",
|
||||
date((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "ConnectionDate",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'HH24:MI'::text) AS "ConnectionTime",
|
||||
EXTRACT(hour FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "ConnectionHour",
|
||||
EXTRACT(dow FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "WeekDayNumber",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'Day'::text) AS "WeekDayName",
|
||||
EXTRACT(month FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "MonthNumber",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'Month'::text) AS "MonthName",
|
||||
EXTRACT(year FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "Year",
|
||||
usr."UserId",
|
||||
usr."Email",
|
||||
usr."UserName",
|
||||
usr."Age",
|
||||
usr."AgeGroup",
|
||||
-- LÓGICA ORIGINAL DE LEALTAD (SIN RECUPERACIÓN)
|
||||
CASE
|
||||
WHEN row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") = 1 THEN 'New'::text
|
||||
WHEN row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") >= 2 AND row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") <= 3 THEN 'Recurrent'::text
|
||||
WHEN row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") >= 4 THEN 'Loyal'::text
|
||||
ELSE 'New'::text
|
||||
END AS "LoyaltyType",
|
||||
con."MacAddress" AS "DeviceMac",
|
||||
con."Ip" AS "IPAddress",
|
||||
con."Platform",
|
||||
con."Browser",
|
||||
con."NetworkUsage",
|
||||
con."FirstSeen",
|
||||
con."LastSeen",
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric AS "DurationMinutes",
|
||||
net."Name" AS "NetworkName",
|
||||
net."MerakiId" AS "MerakiNetworkId",
|
||||
org."Name" AS "Organization",
|
||||
ap."Name" AS "AccessPoint",
|
||||
ap."Model" AS "APModel",
|
||||
ap."Mac" AS "APMac",
|
||||
ap."Latitude",
|
||||
ap."Longitude",
|
||||
con."Status" AS "ConnectionStatus",
|
||||
con."Description",
|
||||
con."DeviceIdentifier",
|
||||
count(*) OVER (PARTITION BY usr."UserId") AS "TotalDevicesUsed",
|
||||
row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") AS "ConnectionRank",
|
||||
con."NetworkId"
|
||||
FROM "SplashUserConnections" con
|
||||
LEFT JOIN ( SELECT u."Id" AS "UserId",
|
||||
u."Email",
|
||||
u."Name" AS "UserName",
|
||||
u."Age",
|
||||
CASE
|
||||
WHEN u."Age" < 18 THEN 'Under 18'::text
|
||||
WHEN u."Age" >= 18 AND u."Age" <= 24 THEN '18-24'::text
|
||||
WHEN u."Age" >= 25 AND u."Age" <= 34 THEN '25-34'::text
|
||||
WHEN u."Age" >= 35 AND u."Age" <= 44 THEN '35-44'::text
|
||||
WHEN u."Age" >= 45 AND u."Age" <= 54 THEN '45-54'::text
|
||||
WHEN u."Age" >= 55 AND u."Age" <= 64 THEN '55-64'::text
|
||||
WHEN u."Age" >= 65 THEN '65+'::text
|
||||
ELSE 'Unknown'::text
|
||||
END AS "AgeGroup",
|
||||
CASE
|
||||
WHEN u."Loyalty" = 1 THEN 'New'::text
|
||||
WHEN u."Loyalty" = 2 THEN 'Recurrent'::text
|
||||
WHEN u."Loyalty" = 3 THEN 'Loyal'::text
|
||||
ELSE 'Unknown'::text
|
||||
END AS "LoyaltyType"
|
||||
FROM "SplashUsers" u
|
||||
WHERE u."IsDeleted" = false) usr ON con."SplashUserId" = usr."UserId"
|
||||
LEFT JOIN "SplashAccessPoints" ap ON con."ApId" = ap."Id"
|
||||
LEFT JOIN "SplashMerakiNetworks" net ON con."NetworkId" = net."Id"
|
||||
LEFT JOIN "SplashMerakiOrganizations" org ON net."OrganizationId" = org."Id"
|
||||
WHERE con."IsDeleted" = false AND (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text) >= '2025-05-01 00:00:00'::timestamp without time zone;
|
||||
|
||||
-- Restaurar permisos
|
||||
ALTER TABLE public.splash_wifi_connection_report
|
||||
OWNER TO mysql;
|
||||
|
||||
-- ===========================================
|
||||
-- PASO 3: Verificar Rollback Exitoso
|
||||
-- ===========================================
|
||||
|
||||
-- Contar registros (debería ser el mismo número que antes)
|
||||
SELECT COUNT(*) as "TotalRecords" FROM splash_wifi_connection_report;
|
||||
|
||||
-- Verificar que NO existen los nuevos campos de diagnóstico
|
||||
SELECT column_name
|
||||
FROM information_schema.columns
|
||||
WHERE table_name = 'splash_wifi_connection_report'
|
||||
AND column_name IN ('IsRecoveredUser', 'RecoveryConnectionDate', 'DaysInactive', 'PostRecoveryRank');
|
||||
|
||||
-- Si la consulta anterior devuelve filas, el rollback NO fue exitoso
|
||||
|
||||
-- Verificar que solo existen los LoyaltyTypes originales
|
||||
SELECT DISTINCT "LoyaltyType"
|
||||
FROM splash_wifi_connection_report
|
||||
ORDER BY "LoyaltyType";
|
||||
|
||||
-- Resultado esperado: New, Recurrent, Loyal (NO debería aparecer "Recuperado")
|
||||
|
||||
-- ===========================================
|
||||
-- PASO 4: Notificación
|
||||
-- ===========================================
|
||||
|
||||
SELECT
|
||||
'ROLLBACK COMPLETADO' as "Status",
|
||||
NOW() as "RollbackDateTime",
|
||||
'View restaurado a estado original' as "Message";
|
||||
|
||||
-- ===========================================
|
||||
-- NOTAS IMPORTANTES
|
||||
-- ===========================================
|
||||
|
||||
/*
|
||||
DESPUÉS DEL ROLLBACK:
|
||||
1. Los servicios de aplicación seguirán funcionando normalmente
|
||||
2. Los reportes volverán a mostrar solo los estados originales de lealtad
|
||||
3. Los campos de diagnóstico ya no estarán disponibles
|
||||
4. La lógica de "usuarios recuperados" estará desactivada
|
||||
|
||||
PARA REACTIVAR LOS CAMBIOS:
|
||||
- Ejecutar nuevamente el script splash_wifi_connection_report.sql modificado
|
||||
|
||||
ARCHIVOS RELACIONADOS:
|
||||
- splash_wifi_connection_report_backup.sql (backup del original)
|
||||
- splash_wifi_connection_report.sql (versión con cambios)
|
||||
- test_loyalty_recovery_logic.sql (pruebas)
|
||||
*/
|
||||
@@ -0,0 +1,329 @@
|
||||
-- View: public.splash_wifi_connection_report
|
||||
-- Modificado: 2025-01-09 - Implementación de usuarios "Recuperados" después de 2+ meses de inactividad
|
||||
|
||||
-- DROP VIEW public.splash_wifi_connection_report;
|
||||
|
||||
CREATE OR REPLACE VIEW public.splash_wifi_connection_report
|
||||
AS
|
||||
WITH user_connection_sequence AS (
|
||||
-- Obtener secuencia de conexiones por usuario ordenado por FirstSeen (fecha real de conexión)
|
||||
SELECT
|
||||
"Id",
|
||||
"SplashUserId",
|
||||
"FirstSeen",
|
||||
"LastSeen",
|
||||
"CreationTime",
|
||||
LAG("LastSeen") OVER (PARTITION BY "SplashUserId" ORDER BY "FirstSeen") as "PrevConnectionLastSeen"
|
||||
FROM "SplashUserConnections"
|
||||
WHERE "IsDeleted" = false
|
||||
),
|
||||
user_connection_gaps AS (
|
||||
-- Calcular gaps reales entre conexiones consecutivas
|
||||
SELECT
|
||||
"Id" as "ConnectionId",
|
||||
"SplashUserId",
|
||||
"FirstSeen",
|
||||
"CreationTime",
|
||||
"PrevConnectionLastSeen",
|
||||
-- Calcular días entre conexiones consecutivas (solo valores positivos)
|
||||
CASE
|
||||
WHEN "PrevConnectionLastSeen" IS NOT NULL
|
||||
AND "FirstSeen" > "PrevConnectionLastSeen"
|
||||
THEN EXTRACT(days FROM ("FirstSeen" - "PrevConnectionLastSeen"))::integer
|
||||
WHEN "PrevConnectionLastSeen" IS NOT NULL
|
||||
AND "FirstSeen" <= "PrevConnectionLastSeen"
|
||||
THEN 0 -- Evitar valores negativos por datos inconsistentes
|
||||
ELSE 0 -- Primera conexión = 0 días de inactividad (más intuitivo que NULL)
|
||||
END as "DaysInactive",
|
||||
-- Determinar si es una conexión de recuperación (gap >= 60 días = ~2 meses)
|
||||
CASE
|
||||
WHEN "PrevConnectionLastSeen" IS NOT NULL
|
||||
AND "FirstSeen" > "PrevConnectionLastSeen"
|
||||
AND ("FirstSeen" - "PrevConnectionLastSeen") >= INTERVAL '60 days'
|
||||
THEN true
|
||||
ELSE false
|
||||
END as "IsRecoveryConnection"
|
||||
FROM user_connection_sequence
|
||||
),
|
||||
recovery_points AS (
|
||||
-- Identificar puntos de recuperación para calcular ranking post-recuperación
|
||||
SELECT
|
||||
"SplashUserId",
|
||||
"ConnectionId",
|
||||
"FirstSeen",
|
||||
-- Marcar el inicio de cada período post-recuperación
|
||||
SUM(CASE WHEN "IsRecoveryConnection" THEN 1 ELSE 0 END)
|
||||
OVER (PARTITION BY "SplashUserId" ORDER BY "FirstSeen" ROWS UNBOUNDED PRECEDING) as "RecoveryPeriod"
|
||||
FROM user_connection_gaps
|
||||
),
|
||||
user_loyalty_calculation AS (
|
||||
-- Calcular progresión de lealtad considerando reinicios post-recuperación
|
||||
SELECT
|
||||
con.*,
|
||||
gap."PrevConnectionLastSeen",
|
||||
gap."IsRecoveryConnection",
|
||||
gap."DaysInactive",
|
||||
-- Ranking global del usuario ordenado por FirstSeen (fecha real de conexión)
|
||||
row_number() OVER (PARTITION BY con."SplashUserId" ORDER BY con."FirstSeen") as "GlobalRank",
|
||||
-- Ranking desde el último punto de recuperación
|
||||
row_number() OVER (
|
||||
PARTITION BY con."SplashUserId", rp."RecoveryPeriod"
|
||||
ORDER BY con."FirstSeen"
|
||||
) as "PostRecoveryRank"
|
||||
FROM "SplashUserConnections" con
|
||||
LEFT JOIN user_connection_gaps gap ON con."Id" = gap."ConnectionId"
|
||||
LEFT JOIN recovery_points rp ON con."Id" = rp."ConnectionId"
|
||||
WHERE con."IsDeleted" = false
|
||||
)
|
||||
SELECT con."Id" AS "ConnectionId",
|
||||
con."CreationTime" AS "ConnectionDateTime",
|
||||
date((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "ConnectionDate",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'HH24:MI'::text) AS "ConnectionTime",
|
||||
EXTRACT(hour FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "ConnectionHour",
|
||||
EXTRACT(dow FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "WeekDayNumber",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'Day'::text) AS "WeekDayName",
|
||||
EXTRACT(month FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "MonthNumber",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'Month'::text) AS "MonthName",
|
||||
EXTRACT(year FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "Year",
|
||||
usr."UserId",
|
||||
usr."Email",
|
||||
usr."UserName",
|
||||
usr."Age",
|
||||
usr."AgeGroup",
|
||||
-- NUEVA LÓGICA DE LEALTAD CON RECUPERACIÓN CORREGIDA
|
||||
CASE
|
||||
-- Primera conexión después de gap de 60+ días = "Recuperado"
|
||||
WHEN con."IsRecoveryConnection" = true THEN 'Recuperado'::text
|
||||
|
||||
-- Progresión post-recuperación: usar PostRecoveryRank si el usuario ha tenido recuperaciones
|
||||
WHEN EXISTS (
|
||||
SELECT 1 FROM user_connection_gaps prev_gap
|
||||
WHERE prev_gap."SplashUserId" = con."SplashUserId"
|
||||
AND prev_gap."ConnectionId" != con."Id"
|
||||
AND prev_gap."IsRecoveryConnection" = true
|
||||
AND prev_gap."FirstSeen" <= con."FirstSeen"
|
||||
) THEN
|
||||
CASE
|
||||
WHEN con."PostRecoveryRank" = 1 THEN 'Recuperado'::text
|
||||
WHEN con."PostRecoveryRank" = 2 THEN 'Recurrent'::text
|
||||
WHEN con."PostRecoveryRank" >= 3 THEN 'Loyal'::text
|
||||
ELSE 'New'::text
|
||||
END
|
||||
|
||||
-- Lógica original para usuarios sin recuperaciones
|
||||
WHEN con."GlobalRank" = 1 THEN 'New'::text
|
||||
WHEN con."GlobalRank" >= 2 AND con."GlobalRank" <= 3 THEN 'Recurrent'::text
|
||||
WHEN con."GlobalRank" >= 4 THEN 'Loyal'::text
|
||||
ELSE 'New'::text
|
||||
END AS "LoyaltyType",
|
||||
con."MacAddress" AS "DeviceMac",
|
||||
con."Ip" AS "IPAddress",
|
||||
con."Platform",
|
||||
con."Browser",
|
||||
con."NetworkUsage",
|
||||
con."FirstSeen",
|
||||
con."LastSeen",
|
||||
-- Duración estimada: toma el menor entre cálculo por NetworkUsage y período bruto
|
||||
CASE
|
||||
WHEN con."LastSeen" >= con."FirstSeen"
|
||||
THEN
|
||||
LEAST(
|
||||
-- Método 1: Duración bruta del período
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric,
|
||||
-- Método 2: Estimación basada en NetworkUsage
|
||||
CASE
|
||||
-- Si hay uso de red significativo, estimar tiempo activo real
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 1024 THEN -- > 1MB
|
||||
LEAST(
|
||||
-- Factor base: 0.1 minutos por MB (ajustable según patrones reales)
|
||||
(CAST(con."NetworkUsage" AS bigint) / 1024.0) * 0.1,
|
||||
-- Máximo 30% del período total como tiempo activo real
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.3
|
||||
)
|
||||
-- Uso menor: asumir 10% del período como tiempo activo
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 0 THEN
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.1,
|
||||
480.0 -- Máximo 8 horas por sesión
|
||||
)
|
||||
-- Sin uso de red: tiempo mínimo estimado
|
||||
ELSE
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.05,
|
||||
30.0 -- Máximo 30 minutos para sesiones sin datos de uso
|
||||
)
|
||||
END
|
||||
)
|
||||
ELSE 0
|
||||
END AS "DurationMinutes",
|
||||
net."Name" AS "NetworkName",
|
||||
net."MerakiId" AS "MerakiNetworkId",
|
||||
org."Name" AS "Organization",
|
||||
ap."Name" AS "AccessPoint",
|
||||
ap."Model" AS "APModel",
|
||||
ap."Mac" AS "APMac",
|
||||
ap."Latitude",
|
||||
ap."Longitude",
|
||||
con."Status" AS "ConnectionStatus",
|
||||
con."Description",
|
||||
con."DeviceIdentifier",
|
||||
count(*) OVER (PARTITION BY usr."UserId") AS "TotalDevicesUsed",
|
||||
con."GlobalRank" AS "ConnectionRank",
|
||||
con."NetworkId",
|
||||
-- NUEVOS CAMPOS DE DIAGNÓSTICO
|
||||
con."IsRecoveryConnection" AS "IsRecoveredUser",
|
||||
con."PrevConnectionLastSeen" AS "RecoveryConnectionDate",
|
||||
-- CAMPO DE ACTIVIDAD REAL (reemplaza la lógica original de DaysInactive)
|
||||
CASE
|
||||
WHEN con."GlobalRank" = (
|
||||
SELECT MAX("GlobalRank")
|
||||
FROM user_loyalty_calculation ulc2
|
||||
WHERE ulc2."SplashUserId" = con."SplashUserId"
|
||||
) THEN
|
||||
-- Es la última conexión del usuario, usar fecha actual
|
||||
EXTRACT(days FROM (CURRENT_DATE - con."LastSeen"))::integer
|
||||
ELSE
|
||||
-- Conexión histórica, usar la lógica original (días entre conexiones)
|
||||
con."DaysInactive"
|
||||
END AS "DaysInactive",
|
||||
con."PostRecoveryRank" AS "PostRecoveryRank",
|
||||
-- Métricas agregadas por usuario: promedio del menor entre ambos métodos
|
||||
AVG(
|
||||
CASE
|
||||
WHEN con."LastSeen" >= con."FirstSeen"
|
||||
THEN
|
||||
LEAST(
|
||||
-- Método 1: Duración bruta del período
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric,
|
||||
-- Método 2: Estimación basada en NetworkUsage
|
||||
CASE
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 1024 THEN
|
||||
LEAST(
|
||||
(CAST(con."NetworkUsage" AS bigint) / 1024.0) * 0.1,
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.3
|
||||
)
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 0 THEN
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.1,
|
||||
480.0
|
||||
)
|
||||
ELSE
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.05,
|
||||
30.0
|
||||
)
|
||||
END
|
||||
)
|
||||
ELSE NULL
|
||||
END
|
||||
) OVER (PARTITION BY con."SplashUserId") AS "UserAvgEstimatedMinutes",
|
||||
-- Categorización basada en el menor entre ambos métodos
|
||||
CASE
|
||||
WHEN (CASE
|
||||
WHEN con."LastSeen" >= con."FirstSeen"
|
||||
THEN
|
||||
LEAST(
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric,
|
||||
CASE
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 1024 THEN
|
||||
LEAST(
|
||||
(CAST(con."NetworkUsage" AS bigint) / 1024.0) * 0.1,
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.3
|
||||
)
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 0 THEN
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.1,
|
||||
480.0
|
||||
)
|
||||
ELSE
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.05,
|
||||
30.0
|
||||
)
|
||||
END
|
||||
)
|
||||
ELSE 0
|
||||
END) <= 30 THEN 'Quick (<30min)'
|
||||
WHEN (CASE
|
||||
WHEN con."LastSeen" >= con."FirstSeen"
|
||||
THEN
|
||||
LEAST(
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric,
|
||||
CASE
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 1024 THEN
|
||||
LEAST(
|
||||
(CAST(con."NetworkUsage" AS bigint) / 1024.0) * 0.1,
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.3
|
||||
)
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 0 THEN
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.1,
|
||||
480.0
|
||||
)
|
||||
ELSE
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.05,
|
||||
30.0
|
||||
)
|
||||
END
|
||||
)
|
||||
ELSE 0
|
||||
END) BETWEEN 30 AND 120 THEN 'Medium (30min-2h)'
|
||||
WHEN (CASE
|
||||
WHEN con."LastSeen" >= con."FirstSeen"
|
||||
THEN
|
||||
LEAST(
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric,
|
||||
CASE
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 1024 THEN
|
||||
LEAST(
|
||||
(CAST(con."NetworkUsage" AS bigint) / 1024.0) * 0.1,
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.3
|
||||
)
|
||||
WHEN CAST(con."NetworkUsage" AS bigint) > 0 THEN
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.1,
|
||||
480.0
|
||||
)
|
||||
ELSE
|
||||
LEAST(
|
||||
(EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric) * 0.05,
|
||||
30.0
|
||||
)
|
||||
END
|
||||
)
|
||||
ELSE 0
|
||||
END) > 120 THEN 'Extended (>2h)'
|
||||
ELSE 'Invalid'
|
||||
END AS "SessionDurationCategory"
|
||||
FROM user_loyalty_calculation con
|
||||
LEFT JOIN ( SELECT u."Id" AS "UserId",
|
||||
u."Email",
|
||||
u."Name" AS "UserName",
|
||||
u."Age",
|
||||
CASE
|
||||
WHEN u."Age" < 18 THEN 'Under 18'::text
|
||||
WHEN u."Age" >= 18 AND u."Age" <= 24 THEN '18-24'::text
|
||||
WHEN u."Age" >= 25 AND u."Age" <= 34 THEN '25-34'::text
|
||||
WHEN u."Age" >= 35 AND u."Age" <= 44 THEN '35-44'::text
|
||||
WHEN u."Age" >= 45 AND u."Age" <= 54 THEN '45-54'::text
|
||||
WHEN u."Age" >= 55 AND u."Age" <= 64 THEN '55-64'::text
|
||||
WHEN u."Age" >= 65 THEN '65+'::text
|
||||
ELSE 'Unknown'::text
|
||||
END AS "AgeGroup",
|
||||
CASE
|
||||
WHEN u."Loyalty" = 1 THEN 'New'::text
|
||||
WHEN u."Loyalty" = 2 THEN 'Recurrent'::text
|
||||
WHEN u."Loyalty" = 3 THEN 'Loyal'::text
|
||||
ELSE 'Unknown'::text
|
||||
END AS "LoyaltyType"
|
||||
FROM "SplashUsers" u
|
||||
WHERE u."IsDeleted" = false) usr ON con."SplashUserId" = usr."UserId"
|
||||
LEFT JOIN "SplashAccessPoints" ap ON con."ApId" = ap."Id"
|
||||
LEFT JOIN "SplashMerakiNetworks" net ON con."NetworkId" = net."Id"
|
||||
LEFT JOIN "SplashMerakiOrganizations" org ON net."OrganizationId" = org."Id"
|
||||
WHERE (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text) >= '2025-05-01 00:00:00'::timestamp without time zone;
|
||||
|
||||
ALTER TABLE public.splash_wifi_connection_report
|
||||
OWNER TO mysql;
|
||||
|
||||
@@ -0,0 +1,83 @@
|
||||
-- BACKUP del view original splash_wifi_connection_report
|
||||
-- Creado: 2025-01-09
|
||||
-- Propósito: Respaldo antes de implementar lógica de usuarios "Recuperados"
|
||||
|
||||
-- View: public.splash_wifi_connection_report
|
||||
|
||||
-- DROP VIEW public.splash_wifi_connection_report;
|
||||
|
||||
CREATE OR REPLACE VIEW public.splash_wifi_connection_report
|
||||
AS
|
||||
SELECT con."Id" AS "ConnectionId",
|
||||
con."CreationTime" AS "ConnectionDateTime",
|
||||
date((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "ConnectionDate",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'HH24:MI'::text) AS "ConnectionTime",
|
||||
EXTRACT(hour FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "ConnectionHour",
|
||||
EXTRACT(dow FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "WeekDayNumber",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'Day'::text) AS "WeekDayName",
|
||||
EXTRACT(month FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "MonthNumber",
|
||||
to_char((con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text), 'Month'::text) AS "MonthName",
|
||||
EXTRACT(year FROM (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text)) AS "Year",
|
||||
usr."UserId",
|
||||
usr."Email",
|
||||
usr."UserName",
|
||||
usr."Age",
|
||||
usr."AgeGroup",
|
||||
CASE
|
||||
WHEN row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") = 1 THEN 'New'::text
|
||||
WHEN row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") >= 2 AND row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") <= 3 THEN 'Recurrent'::text
|
||||
WHEN row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") >= 4 THEN 'Loyal'::text
|
||||
ELSE 'New'::text
|
||||
END AS "LoyaltyType",
|
||||
con."MacAddress" AS "DeviceMac",
|
||||
con."Ip" AS "IPAddress",
|
||||
con."Platform",
|
||||
con."Browser",
|
||||
con."NetworkUsage",
|
||||
con."FirstSeen",
|
||||
con."LastSeen",
|
||||
EXTRACT(epoch FROM con."LastSeen" - con."FirstSeen") / 60::numeric AS "DurationMinutes",
|
||||
net."Name" AS "NetworkName",
|
||||
net."MerakiId" AS "MerakiNetworkId",
|
||||
org."Name" AS "Organization",
|
||||
ap."Name" AS "AccessPoint",
|
||||
ap."Model" AS "APModel",
|
||||
ap."Mac" AS "APMac",
|
||||
ap."Latitude",
|
||||
ap."Longitude",
|
||||
con."Status" AS "ConnectionStatus",
|
||||
con."Description",
|
||||
con."DeviceIdentifier",
|
||||
count(*) OVER (PARTITION BY usr."UserId") AS "TotalDevicesUsed",
|
||||
row_number() OVER (PARTITION BY usr."UserId" ORDER BY con."CreationTime") AS "ConnectionRank",
|
||||
con."NetworkId"
|
||||
FROM "SplashUserConnections" con
|
||||
LEFT JOIN ( SELECT u."Id" AS "UserId",
|
||||
u."Email",
|
||||
u."Name" AS "UserName",
|
||||
u."Age",
|
||||
CASE
|
||||
WHEN u."Age" < 18 THEN 'Under 18'::text
|
||||
WHEN u."Age" >= 18 AND u."Age" <= 24 THEN '18-24'::text
|
||||
WHEN u."Age" >= 25 AND u."Age" <= 34 THEN '25-34'::text
|
||||
WHEN u."Age" >= 35 AND u."Age" <= 44 THEN '35-44'::text
|
||||
WHEN u."Age" >= 45 AND u."Age" <= 54 THEN '45-54'::text
|
||||
WHEN u."Age" >= 55 AND u."Age" <= 64 THEN '55-64'::text
|
||||
WHEN u."Age" >= 65 THEN '65+'::text
|
||||
ELSE 'Unknown'::text
|
||||
END AS "AgeGroup",
|
||||
CASE
|
||||
WHEN u."Loyalty" = 1 THEN 'New'::text
|
||||
WHEN u."Loyalty" = 2 THEN 'Recurrent'::text
|
||||
WHEN u."Loyalty" = 3 THEN 'Loyal'::text
|
||||
ELSE 'Unknown'::text
|
||||
END AS "LoyaltyType"
|
||||
FROM "SplashUsers" u
|
||||
WHERE u."IsDeleted" = false) usr ON con."SplashUserId" = usr."UserId"
|
||||
LEFT JOIN "SplashAccessPoints" ap ON con."ApId" = ap."Id"
|
||||
LEFT JOIN "SplashMerakiNetworks" net ON con."NetworkId" = net."Id"
|
||||
LEFT JOIN "SplashMerakiOrganizations" org ON net."OrganizationId" = org."Id"
|
||||
WHERE con."IsDeleted" = false AND (con."CreationTime" AT TIME ZONE 'America/Mexico_City'::text) >= '2025-05-01 00:00:00'::timestamp without time zone;
|
||||
|
||||
ALTER TABLE public.splash_wifi_connection_report
|
||||
OWNER TO mysql;
|
||||
@@ -0,0 +1,131 @@
|
||||
-- Script de Prueba: Lógica de Usuarios Recuperados
|
||||
-- Creado: 2025-01-09
|
||||
-- Propósito: Validar la nueva lógica de lealtad con casos específicos
|
||||
|
||||
-- ===========================================
|
||||
-- CASOS DE PRUEBA ESPERADOS
|
||||
-- ===========================================
|
||||
|
||||
/*
|
||||
CASO 1: Usuario "Sara" - Debería aparecer como "Recuperado" en registro 4581
|
||||
- Registro 1643: Junio 29 - Julio 6 (última actividad julio 6)
|
||||
- GAP: ~52 días (julio 6 a agosto 28) - MÁS DE 2 MESES
|
||||
- Registro 4581: Agosto 28 - Sept 4 → Debería ser "Recuperado"
|
||||
|
||||
CASO 2: Usuario Normal - Sin gaps
|
||||
- Progresión normal: New → Recurrent → Loyal
|
||||
|
||||
CASO 3: Usuario con múltiples recuperaciones
|
||||
- Primer gap → Recuperado → Recurrent → Loyal
|
||||
- Segundo gap → Recuperado → Recurrent → Loyal
|
||||
*/
|
||||
|
||||
-- ===========================================
|
||||
-- CONSULTA 1: Validar Usuario "Sara" específicamente
|
||||
-- ===========================================
|
||||
|
||||
SELECT
|
||||
"ConnectionId",
|
||||
"ConnectionDateTime",
|
||||
"ConnectionDate",
|
||||
"UserName",
|
||||
"LoyaltyType",
|
||||
"ConnectionRank",
|
||||
"IsRecoveredUser",
|
||||
"DaysInactive",
|
||||
"PostRecoveryRank",
|
||||
"FirstSeen",
|
||||
"LastSeen"
|
||||
FROM splash_wifi_connection_report
|
||||
WHERE "UserName" = 'Sara'
|
||||
ORDER BY "ConnectionDateTime";
|
||||
|
||||
-- Resultado esperado:
|
||||
-- Registro 1643: LoyaltyType = 'New' o según historial, IsRecoveredUser = false
|
||||
-- Registro 4581: LoyaltyType = 'Recuperado', IsRecoveredUser = true, DaysInactive ≈ 52
|
||||
|
||||
-- ===========================================
|
||||
-- CONSULTA 2: Validar todos los usuarios recuperados
|
||||
-- ===========================================
|
||||
|
||||
SELECT
|
||||
"UserName",
|
||||
"Email",
|
||||
"ConnectionId",
|
||||
"ConnectionDate",
|
||||
"LoyaltyType",
|
||||
"IsRecoveredUser",
|
||||
"DaysInactive",
|
||||
"RecoveryConnectionDate"
|
||||
FROM splash_wifi_connection_report
|
||||
WHERE "IsRecoveredUser" = true
|
||||
ORDER BY "ConnectionDate" DESC;
|
||||
|
||||
-- ===========================================
|
||||
-- CONSULTA 3: Validar progresión post-recuperación
|
||||
-- ===========================================
|
||||
|
||||
SELECT
|
||||
"UserName",
|
||||
"ConnectionDate",
|
||||
"LoyaltyType",
|
||||
"ConnectionRank",
|
||||
"PostRecoveryRank",
|
||||
"IsRecoveredUser"
|
||||
FROM splash_wifi_connection_report
|
||||
WHERE "UserName" IN (
|
||||
SELECT DISTINCT "UserName"
|
||||
FROM splash_wifi_connection_report
|
||||
WHERE "IsRecoveredUser" = true
|
||||
)
|
||||
ORDER BY "UserName", "ConnectionDate";
|
||||
|
||||
-- Resultado esperado: Progresión Recuperado → Recurrent → Loyal
|
||||
|
||||
-- ===========================================
|
||||
-- CONSULTA 4: Estadísticas generales
|
||||
-- ===========================================
|
||||
|
||||
SELECT
|
||||
"LoyaltyType",
|
||||
COUNT(*) as "TotalConnections",
|
||||
COUNT(DISTINCT "UserName") as "UniqueUsers"
|
||||
FROM splash_wifi_connection_report
|
||||
GROUP BY "LoyaltyType"
|
||||
ORDER BY "TotalConnections" DESC;
|
||||
|
||||
-- ===========================================
|
||||
-- CONSULTA 5: Validar lógica de gaps temporales
|
||||
-- ===========================================
|
||||
|
||||
WITH gap_analysis AS (
|
||||
SELECT
|
||||
"UserName",
|
||||
"ConnectionDate",
|
||||
"FirstSeen",
|
||||
"LastSeen",
|
||||
LAG("LastSeen") OVER (PARTITION BY "UserName" ORDER BY "ConnectionDate") as "PrevLastSeen",
|
||||
EXTRACT(days FROM ("FirstSeen" - LAG("LastSeen") OVER (PARTITION BY "UserName" ORDER BY "ConnectionDate"))) as "DaysBetweenConnections"
|
||||
FROM splash_wifi_connection_report
|
||||
)
|
||||
SELECT
|
||||
"UserName",
|
||||
"ConnectionDate",
|
||||
"DaysBetweenConnections",
|
||||
CASE
|
||||
WHEN "DaysBetweenConnections" >= 60 THEN 'GAP_DETECTED'
|
||||
ELSE 'NORMAL'
|
||||
END as "GapStatus"
|
||||
FROM gap_analysis
|
||||
WHERE "DaysBetweenConnections" IS NOT NULL
|
||||
ORDER BY "DaysBetweenConnections" DESC;
|
||||
|
||||
-- ===========================================
|
||||
-- CONSULTA 6: Performance Test
|
||||
-- ===========================================
|
||||
|
||||
EXPLAIN (ANALYZE, BUFFERS)
|
||||
SELECT COUNT(*)
|
||||
FROM splash_wifi_connection_report;
|
||||
|
||||
-- Esta consulta nos dirá el costo computacional del view modificado
|
||||
Reference in New Issue
Block a user