Production Outline DB uses 'icon' column instead of 'emoji' for documents and revisions. Fixed all affected queries: - documents.ts: SELECT queries - advanced-search.ts: Search queries - analytics.ts: Analytics + GROUP BY - export-import.ts: Export/import metadata - templates.ts: Template queries + INSERT - collections.ts: Collection document listing - revisions.ts: Revision comparison reactions.emoji kept unchanged (correct schema) Tested: 448 documents successfully queried from hub.descomplicar.pt Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
500 lines
17 KiB
TypeScript
500 lines
17 KiB
TypeScript
/**
|
|
* MCP Outline PostgreSQL - Analytics Tools
|
|
* Usage statistics, reports, insights
|
|
* @author Descomplicar® | @link descomplicar.pt | @copyright 2026
|
|
*/
|
|
|
|
import { Pool } from 'pg';
|
|
import { BaseTool, ToolResponse } from '../types/tools.js';
|
|
import { isValidUUID, validateDaysInterval, isValidISODate, validatePeriod } from '../utils/security.js';
|
|
|
|
interface DateRangeArgs {
|
|
date_from?: string;
|
|
date_to?: string;
|
|
}
|
|
|
|
/**
|
|
* analytics.overview - Get overall workspace analytics
|
|
*/
|
|
const getAnalyticsOverview: BaseTool<DateRangeArgs> = {
|
|
name: 'outline_analytics_overview',
|
|
description: 'Get overall workspace analytics including document counts, user activity, etc.',
|
|
inputSchema: {
|
|
type: 'object',
|
|
properties: {
|
|
date_from: { type: 'string', description: 'Start date (ISO format)' },
|
|
date_to: { type: 'string', description: 'End date (ISO format)' },
|
|
},
|
|
},
|
|
handler: async (args, pgClient): Promise<ToolResponse> => {
|
|
// Validate date parameters if provided
|
|
if (args.date_from && !isValidISODate(args.date_from)) {
|
|
throw new Error('Invalid date_from format. Use ISO format (YYYY-MM-DD)');
|
|
}
|
|
if (args.date_to && !isValidISODate(args.date_to)) {
|
|
throw new Error('Invalid date_to format. Use ISO format (YYYY-MM-DD)');
|
|
}
|
|
|
|
// Build date condition with parameterized query
|
|
const dateParams: any[] = [];
|
|
let dateCondition = '';
|
|
if (args.date_from && args.date_to) {
|
|
dateCondition = `AND "createdAt" BETWEEN $1 AND $2`;
|
|
dateParams.push(args.date_from, args.date_to);
|
|
}
|
|
|
|
// Document stats (no date filter needed for totals)
|
|
const docStats = await pgClient.query(`
|
|
SELECT
|
|
COUNT(*) as "totalDocuments",
|
|
COUNT(*) FILTER (WHERE template = true) as "templates",
|
|
COUNT(*) FILTER (WHERE "archivedAt" IS NOT NULL) as "archived",
|
|
COUNT(*) FILTER (WHERE "publishedAt" IS NOT NULL) as "published",
|
|
COUNT(*) FILTER (WHERE "deletedAt" IS NOT NULL) as "deleted"
|
|
FROM documents
|
|
`);
|
|
|
|
// Collection stats
|
|
const collStats = await pgClient.query(`
|
|
SELECT
|
|
COUNT(*) as "totalCollections",
|
|
COUNT(*) FILTER (WHERE "deletedAt" IS NULL) as "active"
|
|
FROM collections
|
|
`);
|
|
|
|
// User stats
|
|
const userStats = await pgClient.query(`
|
|
SELECT
|
|
COUNT(*) as "totalUsers",
|
|
COUNT(*) FILTER (WHERE "suspendedAt" IS NULL AND "deletedAt" IS NULL) as "active",
|
|
COUNT(*) FILTER (WHERE role = 'admin') as "admins"
|
|
FROM users
|
|
`);
|
|
|
|
// Recent activity
|
|
const recentActivity = await pgClient.query(`
|
|
SELECT
|
|
COUNT(*) FILTER (WHERE "createdAt" >= NOW() - INTERVAL '24 hours') as "documentsLast24h",
|
|
COUNT(*) FILTER (WHERE "createdAt" >= NOW() - INTERVAL '7 days') as "documentsLast7d",
|
|
COUNT(*) FILTER (WHERE "createdAt" >= NOW() - INTERVAL '30 days') as "documentsLast30d"
|
|
FROM documents
|
|
WHERE "deletedAt" IS NULL
|
|
`);
|
|
|
|
// View stats
|
|
const viewStats = await pgClient.query(`
|
|
SELECT
|
|
COUNT(*) as "totalViews",
|
|
COUNT(DISTINCT "userId") as "uniqueViewers",
|
|
COUNT(DISTINCT "documentId") as "viewedDocuments"
|
|
FROM views
|
|
`);
|
|
|
|
return {
|
|
content: [{ type: 'text', text: JSON.stringify({
|
|
documents: docStats.rows[0],
|
|
collections: collStats.rows[0],
|
|
users: userStats.rows[0],
|
|
recentActivity: recentActivity.rows[0],
|
|
views: viewStats.rows[0],
|
|
generatedAt: new Date().toISOString(),
|
|
}, null, 2) }],
|
|
};
|
|
},
|
|
};
|
|
|
|
/**
|
|
* analytics.user_activity - Get user activity analytics
|
|
*/
|
|
const getUserActivityAnalytics: BaseTool<{ user_id?: string; days?: number }> = {
|
|
name: 'outline_analytics_user_activity',
|
|
description: 'Get detailed user activity analytics.',
|
|
inputSchema: {
|
|
type: 'object',
|
|
properties: {
|
|
user_id: { type: 'string', description: 'Specific user ID (UUID), or all users if omitted' },
|
|
days: { type: 'number', description: 'Number of days to analyze (default: 30)' },
|
|
},
|
|
},
|
|
handler: async (args, pgClient): Promise<ToolResponse> => {
|
|
// Validate user_id FIRST before using it
|
|
if (args.user_id && !isValidUUID(args.user_id)) {
|
|
throw new Error('Invalid user_id');
|
|
}
|
|
|
|
// Validate and sanitize days parameter
|
|
const safeDays = validateDaysInterval(args.days, 30, 365);
|
|
|
|
// Build query with safe interval (number is safe after validation)
|
|
const params: any[] = [];
|
|
let paramIdx = 1;
|
|
let userCondition = '';
|
|
|
|
if (args.user_id) {
|
|
userCondition = `AND u.id = $${paramIdx++}`;
|
|
params.push(args.user_id);
|
|
}
|
|
|
|
// Most active users - using make_interval for safety
|
|
const activeUsers = await pgClient.query(`
|
|
SELECT
|
|
u.id, u.name, u.email,
|
|
COUNT(DISTINCT d.id) FILTER (WHERE d."createdAt" >= NOW() - make_interval(days => ${safeDays})) as "documentsCreated",
|
|
COUNT(DISTINCT d2.id) FILTER (WHERE d2."updatedAt" >= NOW() - make_interval(days => ${safeDays})) as "documentsEdited",
|
|
COUNT(DISTINCT v."documentId") FILTER (WHERE v."createdAt" >= NOW() - make_interval(days => ${safeDays})) as "documentsViewed",
|
|
COUNT(DISTINCT c.id) FILTER (WHERE c."createdAt" >= NOW() - make_interval(days => ${safeDays})) as "commentsAdded"
|
|
FROM users u
|
|
LEFT JOIN documents d ON d."createdById" = u.id
|
|
LEFT JOIN documents d2 ON d2."lastModifiedById" = u.id
|
|
LEFT JOIN views v ON v."userId" = u.id
|
|
LEFT JOIN comments c ON c."createdById" = u.id
|
|
WHERE u."deletedAt" IS NULL ${userCondition}
|
|
GROUP BY u.id, u.name, u.email
|
|
ORDER BY "documentsCreated" DESC
|
|
LIMIT 20
|
|
`, params);
|
|
|
|
// Activity by day of week
|
|
const activityByDay = await pgClient.query(`
|
|
SELECT
|
|
EXTRACT(DOW FROM d."createdAt") as "dayOfWeek",
|
|
COUNT(*) as "documentsCreated"
|
|
FROM documents d
|
|
WHERE d."createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
AND d."deletedAt" IS NULL
|
|
GROUP BY EXTRACT(DOW FROM d."createdAt")
|
|
ORDER BY "dayOfWeek"
|
|
`);
|
|
|
|
// Activity by hour
|
|
const activityByHour = await pgClient.query(`
|
|
SELECT
|
|
EXTRACT(HOUR FROM d."createdAt") as "hour",
|
|
COUNT(*) as "documentsCreated"
|
|
FROM documents d
|
|
WHERE d."createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
AND d."deletedAt" IS NULL
|
|
GROUP BY EXTRACT(HOUR FROM d."createdAt")
|
|
ORDER BY "hour"
|
|
`);
|
|
|
|
return {
|
|
content: [{ type: 'text', text: JSON.stringify({
|
|
activeUsers: activeUsers.rows,
|
|
activityByDayOfWeek: activityByDay.rows,
|
|
activityByHour: activityByHour.rows,
|
|
periodDays: safeDays,
|
|
}, null, 2) }],
|
|
};
|
|
},
|
|
};
|
|
|
|
/**
|
|
* analytics.content_insights - Get content insights
|
|
*/
|
|
const getContentInsights: BaseTool<{ collection_id?: string }> = {
|
|
name: 'outline_analytics_content_insights',
|
|
description: 'Get insights about content: popular documents, stale content, etc.',
|
|
inputSchema: {
|
|
type: 'object',
|
|
properties: {
|
|
collection_id: { type: 'string', description: 'Filter by collection ID (UUID)' },
|
|
},
|
|
},
|
|
handler: async (args, pgClient): Promise<ToolResponse> => {
|
|
// Validate collection_id FIRST before using it
|
|
if (args.collection_id && !isValidUUID(args.collection_id)) {
|
|
throw new Error('Invalid collection_id');
|
|
}
|
|
|
|
// Build parameterized query
|
|
const params: any[] = [];
|
|
let paramIdx = 1;
|
|
let collectionCondition = '';
|
|
|
|
if (args.collection_id) {
|
|
collectionCondition = `AND d."collectionId" = $${paramIdx++}`;
|
|
params.push(args.collection_id);
|
|
}
|
|
|
|
// Most viewed documents
|
|
const mostViewed = await pgClient.query(`
|
|
SELECT
|
|
d.id, d.title, d.icon, c.name as "collectionName",
|
|
COUNT(v.id) as "viewCount",
|
|
COUNT(DISTINCT v."userId") as "uniqueViewers"
|
|
FROM documents d
|
|
LEFT JOIN views v ON v."documentId" = d.id
|
|
LEFT JOIN collections c ON d."collectionId" = c.id
|
|
WHERE d."deletedAt" IS NULL ${collectionCondition}
|
|
GROUP BY d.id, d.title, d.icon, c.name
|
|
ORDER BY "viewCount" DESC
|
|
LIMIT 10
|
|
`, params);
|
|
|
|
// Most starred documents
|
|
const mostStarred = await pgClient.query(`
|
|
SELECT
|
|
d.id, d.title, d.icon, c.name as "collectionName",
|
|
COUNT(s.id) as "starCount"
|
|
FROM documents d
|
|
LEFT JOIN stars s ON s."documentId" = d.id
|
|
LEFT JOIN collections c ON d."collectionId" = c.id
|
|
WHERE d."deletedAt" IS NULL ${collectionCondition}
|
|
GROUP BY d.id, d.title, d.icon, c.name
|
|
HAVING COUNT(s.id) > 0
|
|
ORDER BY "starCount" DESC
|
|
LIMIT 10
|
|
`, params);
|
|
|
|
// Stale documents (not updated in 90 days)
|
|
const staleDocuments = await pgClient.query(`
|
|
SELECT
|
|
d.id, d.title, d.icon, c.name as "collectionName",
|
|
d."updatedAt",
|
|
EXTRACT(DAY FROM NOW() - d."updatedAt") as "daysSinceUpdate"
|
|
FROM documents d
|
|
LEFT JOIN collections c ON d."collectionId" = c.id
|
|
WHERE d."deletedAt" IS NULL
|
|
AND d."archivedAt" IS NULL
|
|
AND d.template = false
|
|
AND d."updatedAt" < NOW() - INTERVAL '90 days'
|
|
${collectionCondition}
|
|
ORDER BY d."updatedAt" ASC
|
|
LIMIT 20
|
|
`, params);
|
|
|
|
// Documents without views
|
|
const neverViewed = await pgClient.query(`
|
|
SELECT
|
|
d.id, d.title, d.icon, c.name as "collectionName",
|
|
d."createdAt"
|
|
FROM documents d
|
|
LEFT JOIN views v ON v."documentId" = d.id
|
|
LEFT JOIN collections c ON d."collectionId" = c.id
|
|
WHERE d."deletedAt" IS NULL
|
|
AND d.template = false
|
|
AND v.id IS NULL
|
|
${collectionCondition}
|
|
ORDER BY d."createdAt" DESC
|
|
LIMIT 20
|
|
`, params);
|
|
|
|
return {
|
|
content: [{ type: 'text', text: JSON.stringify({
|
|
mostViewed: mostViewed.rows,
|
|
mostStarred: mostStarred.rows,
|
|
staleDocuments: staleDocuments.rows,
|
|
neverViewed: neverViewed.rows,
|
|
}, null, 2) }],
|
|
};
|
|
},
|
|
};
|
|
|
|
/**
|
|
* analytics.collection_stats - Get collection statistics
|
|
*/
|
|
const getCollectionStats: BaseTool<{ collection_id?: string }> = {
|
|
name: 'outline_analytics_collection_stats',
|
|
description: 'Get detailed statistics for collections.',
|
|
inputSchema: {
|
|
type: 'object',
|
|
properties: {
|
|
collection_id: { type: 'string', description: 'Specific collection ID (UUID), or all collections if omitted' },
|
|
},
|
|
},
|
|
handler: async (args, pgClient): Promise<ToolResponse> => {
|
|
// Validate collection_id FIRST before using it
|
|
if (args.collection_id && !isValidUUID(args.collection_id)) {
|
|
throw new Error('Invalid collection_id');
|
|
}
|
|
|
|
// Build parameterized query
|
|
const params: any[] = [];
|
|
let collectionCondition = '';
|
|
|
|
if (args.collection_id) {
|
|
collectionCondition = `AND c.id = $1`;
|
|
params.push(args.collection_id);
|
|
}
|
|
|
|
const stats = await pgClient.query(`
|
|
SELECT
|
|
c.id, c.name, c.icon, c.color,
|
|
COUNT(DISTINCT d.id) as "documentCount",
|
|
COUNT(DISTINCT d.id) FILTER (WHERE d.template = true) as "templateCount",
|
|
COUNT(DISTINCT d.id) FILTER (WHERE d."archivedAt" IS NOT NULL) as "archivedCount",
|
|
COUNT(DISTINCT cu."userId") as "memberCount",
|
|
COUNT(DISTINCT cg."groupId") as "groupCount",
|
|
MAX(d."updatedAt") as "lastDocumentUpdate",
|
|
AVG(LENGTH(d.text)) as "avgDocumentLength"
|
|
FROM collections c
|
|
LEFT JOIN documents d ON d."collectionId" = c.id AND d."deletedAt" IS NULL
|
|
LEFT JOIN collection_users cu ON cu."collectionId" = c.id
|
|
LEFT JOIN collection_group_memberships cg ON cg."collectionId" = c.id
|
|
WHERE c."deletedAt" IS NULL ${collectionCondition}
|
|
GROUP BY c.id, c.name, c.icon, c.color
|
|
ORDER BY "documentCount" DESC
|
|
`, params);
|
|
|
|
return {
|
|
content: [{ type: 'text', text: JSON.stringify({ data: stats.rows }, null, 2) }],
|
|
};
|
|
},
|
|
};
|
|
|
|
/**
|
|
* analytics.growth_metrics - Get growth metrics over time
|
|
*/
|
|
const getGrowthMetrics: BaseTool<{ period?: string }> = {
|
|
name: 'outline_analytics_growth_metrics',
|
|
description: 'Get growth metrics: documents, users, activity over time.',
|
|
inputSchema: {
|
|
type: 'object',
|
|
properties: {
|
|
period: { type: 'string', description: 'Period: week, month, quarter, year (default: month)' },
|
|
},
|
|
},
|
|
handler: async (args, pgClient): Promise<ToolResponse> => {
|
|
// Validate period against allowed values
|
|
const allowedPeriods = ['week', 'month', 'quarter', 'year'];
|
|
const period = validatePeriod(args.period, allowedPeriods, 'month');
|
|
|
|
// Map periods to safe integer days (no string interpolation needed)
|
|
const periodDays: Record<string, number> = {
|
|
week: 7,
|
|
month: 30,
|
|
quarter: 90,
|
|
year: 365,
|
|
};
|
|
const safeDays = periodDays[period];
|
|
|
|
// Document growth by day
|
|
const documentGrowth = await pgClient.query(`
|
|
SELECT
|
|
DATE(d."createdAt") as date,
|
|
COUNT(*) as "newDocuments",
|
|
SUM(COUNT(*)) OVER (ORDER BY DATE(d."createdAt")) as "cumulativeDocuments"
|
|
FROM documents d
|
|
WHERE d."createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
AND d."deletedAt" IS NULL
|
|
GROUP BY DATE(d."createdAt")
|
|
ORDER BY date
|
|
`);
|
|
|
|
// User growth
|
|
const userGrowth = await pgClient.query(`
|
|
SELECT
|
|
DATE(u."createdAt") as date,
|
|
COUNT(*) as "newUsers",
|
|
SUM(COUNT(*)) OVER (ORDER BY DATE(u."createdAt")) as "cumulativeUsers"
|
|
FROM users u
|
|
WHERE u."createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
AND u."deletedAt" IS NULL
|
|
GROUP BY DATE(u."createdAt")
|
|
ORDER BY date
|
|
`);
|
|
|
|
// Collection growth
|
|
const collectionGrowth = await pgClient.query(`
|
|
SELECT
|
|
DATE(c."createdAt") as date,
|
|
COUNT(*) as "newCollections"
|
|
FROM collections c
|
|
WHERE c."createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
AND c."deletedAt" IS NULL
|
|
GROUP BY DATE(c."createdAt")
|
|
ORDER BY date
|
|
`);
|
|
|
|
// Period comparison
|
|
const comparison = await pgClient.query(`
|
|
SELECT
|
|
(SELECT COUNT(*) FROM documents WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays}) AND "deletedAt" IS NULL) as "currentPeriodDocs",
|
|
(SELECT COUNT(*) FROM documents WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays * 2}) AND "createdAt" < NOW() - make_interval(days => ${safeDays}) AND "deletedAt" IS NULL) as "previousPeriodDocs",
|
|
(SELECT COUNT(*) FROM users WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays}) AND "deletedAt" IS NULL) as "currentPeriodUsers",
|
|
(SELECT COUNT(*) FROM users WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays * 2}) AND "createdAt" < NOW() - make_interval(days => ${safeDays}) AND "deletedAt" IS NULL) as "previousPeriodUsers"
|
|
`);
|
|
|
|
return {
|
|
content: [{ type: 'text', text: JSON.stringify({
|
|
documentGrowth: documentGrowth.rows,
|
|
userGrowth: userGrowth.rows,
|
|
collectionGrowth: collectionGrowth.rows,
|
|
periodComparison: comparison.rows[0],
|
|
period,
|
|
}, null, 2) }],
|
|
};
|
|
},
|
|
};
|
|
|
|
/**
|
|
* analytics.search_analytics - Get search analytics
|
|
*/
|
|
const getSearchAnalytics: BaseTool<{ days?: number }> = {
|
|
name: 'outline_analytics_search',
|
|
description: 'Get search analytics: popular queries, search patterns.',
|
|
inputSchema: {
|
|
type: 'object',
|
|
properties: {
|
|
days: { type: 'number', description: 'Number of days to analyze (default: 30)' },
|
|
},
|
|
},
|
|
handler: async (args, pgClient): Promise<ToolResponse> => {
|
|
// Validate and sanitize days parameter
|
|
const safeDays = validateDaysInterval(args.days, 30, 365);
|
|
|
|
// Popular search queries
|
|
const popularQueries = await pgClient.query(`
|
|
SELECT
|
|
query,
|
|
COUNT(*) as "searchCount",
|
|
COUNT(DISTINCT "userId") as "uniqueSearchers"
|
|
FROM search_queries
|
|
WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
GROUP BY query
|
|
ORDER BY "searchCount" DESC
|
|
LIMIT 20
|
|
`);
|
|
|
|
// Search volume by day
|
|
const searchVolume = await pgClient.query(`
|
|
SELECT
|
|
DATE("createdAt") as date,
|
|
COUNT(*) as "searches",
|
|
COUNT(DISTINCT "userId") as "uniqueSearchers"
|
|
FROM search_queries
|
|
WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
GROUP BY DATE("createdAt")
|
|
ORDER BY date
|
|
`);
|
|
|
|
// Zero result queries (if results column exists)
|
|
const zeroResults = await pgClient.query(`
|
|
SELECT
|
|
query,
|
|
COUNT(*) as "searchCount"
|
|
FROM search_queries
|
|
WHERE "createdAt" >= NOW() - make_interval(days => ${safeDays})
|
|
AND results = 0
|
|
GROUP BY query
|
|
ORDER BY "searchCount" DESC
|
|
LIMIT 10
|
|
`).catch(() => ({ rows: [] })); // Handle if results column doesn't exist
|
|
|
|
return {
|
|
content: [{ type: 'text', text: JSON.stringify({
|
|
popularQueries: popularQueries.rows,
|
|
searchVolume: searchVolume.rows,
|
|
zeroResultQueries: zeroResults.rows,
|
|
periodDays: safeDays,
|
|
}, null, 2) }],
|
|
};
|
|
},
|
|
};
|
|
|
|
export const analyticsTools: BaseTool<any>[] = [
|
|
getAnalyticsOverview, getUserActivityAnalytics, getContentInsights,
|
|
getCollectionStats, getGrowthMetrics, getSearchAnalytics
|
|
];
|