file: - Added DB Schema json

- Added splash_wifi_connection_report SQL
This commit is contained in:
2025-09-05 07:08:59 -06:00
parent a61bb821ca
commit 9d499e809e
2 changed files with 3227 additions and 0 deletions

3147
db_schema.json Normal file

File diff suppressed because it is too large Load Diff

View File

@@ -0,0 +1,80 @@
-- 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;