Files
mcp-outline-postgresql/src/tools/attachments.ts
Emanuel Almeida 6f5d17516b fix: Adapt SQL queries to actual Outline database schema
- Users: Use role enum instead of isAdmin/isViewer/isSuspended booleans
- Users: Remove non-existent username column
- Groups: Fix group_users table (no deletedAt, composite PK)
- Attachments: Remove url and deletedAt columns, use hard delete

All 10/10 core queries now pass validation.

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2026-01-31 13:32:41 +00:00

487 lines
12 KiB
TypeScript

/**
* MCP Outline PostgreSQL - Attachments Tools
* @author Descomplicar® | @link descomplicar.pt | @copyright 2026
*/
import { Pool } from 'pg';
import { BaseTool, ToolResponse, CreateAttachmentArgs, GetAttachmentArgs, PaginationArgs } from '../types/tools.js';
import { validatePagination, isValidUUID } from '../utils/security.js';
interface AttachmentListArgs extends PaginationArgs {
document_id?: string;
user_id?: string;
team_id?: string;
}
/**
* attachments.list - List attachments with optional filters
*/
const listAttachments: BaseTool<AttachmentListArgs> = {
name: 'outline_attachments_list',
description: 'List file attachments with optional filtering by document, user, or team. Supports pagination.',
inputSchema: {
type: 'object',
properties: {
document_id: {
type: 'string',
description: 'Filter by document ID (UUID)',
},
user_id: {
type: 'string',
description: 'Filter by user ID who uploaded (UUID)',
},
team_id: {
type: 'string',
description: 'Filter by team ID (UUID)',
},
limit: {
type: 'number',
description: 'Maximum number of results (default: 25, max: 100)',
},
offset: {
type: 'number',
description: 'Number of results to skip (default: 0)',
},
},
},
handler: async (args, pgClient): Promise<ToolResponse> => {
const { limit, offset } = validatePagination(args.limit, args.offset);
const conditions: string[] = [];
const params: any[] = [];
let paramIndex = 1;
if (args.document_id) {
if (!isValidUUID(args.document_id)) {
throw new Error('Invalid document_id format');
}
conditions.push(`a."documentId" = $${paramIndex++}`);
params.push(args.document_id);
}
if (args.user_id) {
if (!isValidUUID(args.user_id)) {
throw new Error('Invalid user_id format');
}
conditions.push(`a."userId" = $${paramIndex++}`);
params.push(args.user_id);
}
if (args.team_id) {
if (!isValidUUID(args.team_id)) {
throw new Error('Invalid team_id format');
}
conditions.push(`a."teamId" = $${paramIndex++}`);
params.push(args.team_id);
}
const whereClause = conditions.length > 0 ? `WHERE ${conditions.join(' AND ')}` : '';
const query = `
SELECT
a.id,
a.key,
a."contentType",
a.size,
a.acl,
a."documentId",
a."userId",
a."teamId",
a."createdAt",
a."updatedAt",
a."lastAccessedAt",
a."expiresAt",
d.title as "documentTitle",
u.name as "uploadedByName",
u.email as "uploadedByEmail"
FROM attachments a
LEFT JOIN documents d ON a."documentId" = d.id
LEFT JOIN users u ON a."userId" = u.id
${whereClause}
ORDER BY a."createdAt" DESC
LIMIT $${paramIndex++} OFFSET $${paramIndex}
`;
params.push(limit, offset);
const result = await pgClient.query(query, params);
return {
content: [
{
type: 'text',
text: JSON.stringify(
{
data: result.rows,
pagination: {
limit,
offset,
total: result.rows.length,
},
},
null,
2
),
},
],
};
},
};
/**
* attachments.info - Get detailed information about a specific attachment
*/
const getAttachment: BaseTool<GetAttachmentArgs> = {
name: 'outline_attachments_info',
description: 'Get detailed information about a specific attachment by ID.',
inputSchema: {
type: 'object',
properties: {
id: {
type: 'string',
description: 'Attachment ID (UUID)',
},
},
required: ['id'],
},
handler: async (args, pgClient): Promise<ToolResponse> => {
if (!isValidUUID(args.id)) {
throw new Error('Invalid attachment ID format');
}
const query = `
SELECT
a.id,
a.key,
a."contentType",
a.size,
a.acl,
a."documentId",
a."userId",
a."teamId",
a."createdAt",
a."updatedAt",
a."lastAccessedAt",
a."expiresAt",
d.title as "documentTitle",
d."collectionId",
u.name as "uploadedByName",
u.email as "uploadedByEmail",
t.name as "teamName"
FROM attachments a
LEFT JOIN documents d ON a."documentId" = d.id
LEFT JOIN users u ON a."userId" = u.id
LEFT JOIN teams t ON a."teamId" = t.id
WHERE a.id = $1
`;
const result = await pgClient.query(query, [args.id]);
if (result.rows.length === 0) {
throw new Error('Attachment not found');
}
return {
content: [
{
type: 'text',
text: JSON.stringify(
{
data: result.rows[0],
},
null,
2
),
},
],
};
},
};
/**
* attachments.create - Create a new attachment record
*/
const createAttachment: BaseTool<CreateAttachmentArgs> = {
name: 'outline_attachments_create',
description: 'Create a new attachment record. Note: This creates the database record only, actual file upload is handled separately.',
inputSchema: {
type: 'object',
properties: {
name: {
type: 'string',
description: 'Attachment filename/key',
},
document_id: {
type: 'string',
description: 'Document ID to attach to (UUID, optional)',
},
content_type: {
type: 'string',
description: 'MIME type (e.g., "image/png", "application/pdf")',
},
size: {
type: 'number',
description: 'File size in bytes',
},
},
required: ['name', 'content_type', 'size'],
},
handler: async (args, pgClient): Promise<ToolResponse> => {
if (args.document_id && !isValidUUID(args.document_id)) {
throw new Error('Invalid document_id format');
}
// Verify document exists if provided
if (args.document_id) {
const docCheck = await pgClient.query(
'SELECT id, "teamId" FROM documents WHERE id = $1 AND "deletedAt" IS NULL',
[args.document_id]
);
if (docCheck.rows.length === 0) {
throw new Error('Document not found or deleted');
}
}
// Get first admin user and team
const userQuery = await pgClient.query(
"SELECT u.id, u.\"teamId\" FROM users u WHERE u.role = 'admin' AND u.\"deletedAt\" IS NULL LIMIT 1"
);
if (userQuery.rows.length === 0) {
throw new Error('No valid user found to create attachment');
}
const userId = userQuery.rows[0].id;
const teamId = userQuery.rows[0].teamId;
// Generate key (path in storage)
const key = `attachments/${Date.now()}-${args.name}`;
const query = `
INSERT INTO attachments (
id,
key,
"contentType",
size,
acl,
"documentId",
"userId",
"teamId",
"createdAt",
"updatedAt"
) VALUES (gen_random_uuid(), $1, $2, $3, $4, $5, $6, $7, NOW(), NOW())
RETURNING *
`;
const result = await pgClient.query(query, [
key,
args.content_type,
args.size,
'private', // Default ACL
args.document_id || null,
userId,
teamId,
]);
return {
content: [
{
type: 'text',
text: JSON.stringify(
{
data: result.rows[0],
},
null,
2
),
},
],
};
},
};
/**
* attachments.delete - Delete an attachment (soft delete)
*/
const deleteAttachment: BaseTool<GetAttachmentArgs> = {
name: 'outline_attachments_delete',
description: 'Delete an attachment permanently.',
inputSchema: {
type: 'object',
properties: {
id: {
type: 'string',
description: 'Attachment ID (UUID)',
},
},
required: ['id'],
},
handler: async (args, pgClient): Promise<ToolResponse> => {
if (!isValidUUID(args.id)) {
throw new Error('Invalid attachment ID format');
}
const query = `
DELETE FROM attachments
WHERE id = $1
RETURNING id, key, "documentId"
`;
const result = await pgClient.query(query, [args.id]);
if (result.rows.length === 0) {
throw new Error('Attachment not found');
}
return {
content: [
{
type: 'text',
text: JSON.stringify(
{
success: true,
message: 'Attachment deleted successfully',
data: result.rows[0],
},
null,
2
),
},
],
};
},
};
/**
* attachments.stats - Get attachment statistics
*/
const getAttachmentStats: BaseTool<{ team_id?: string; document_id?: string }> = {
name: 'outline_attachments_stats',
description: 'Get statistics about attachments including total count, size, and breakdown by content type.',
inputSchema: {
type: 'object',
properties: {
team_id: {
type: 'string',
description: 'Filter statistics by team ID (UUID)',
},
document_id: {
type: 'string',
description: 'Filter statistics by document ID (UUID)',
},
},
},
handler: async (args, pgClient): Promise<ToolResponse> => {
const conditions: string[] = [];
const params: any[] = [];
let paramIndex = 1;
if (args.team_id) {
if (!isValidUUID(args.team_id)) {
throw new Error('Invalid team_id format');
}
conditions.push(`a."teamId" = $${paramIndex++}`);
params.push(args.team_id);
}
if (args.document_id) {
if (!isValidUUID(args.document_id)) {
throw new Error('Invalid document_id format');
}
conditions.push(`a."documentId" = $${paramIndex++}`);
params.push(args.document_id);
}
const whereClause = conditions.length > 0 ? `WHERE ${conditions.join(' AND ')}` : '';
// Overall statistics
const overallStatsQuery = await pgClient.query(
`SELECT
COUNT(*) as "totalAttachments",
SUM(size) as "totalSize",
AVG(size) as "averageSize",
COUNT(DISTINCT "documentId") as "documentsWithAttachments",
COUNT(DISTINCT "userId") as "uniqueUploaders"
FROM attachments a
${whereClause}`,
params
);
// By content type
const byContentTypeQuery = await pgClient.query(
`SELECT
a."contentType",
COUNT(*) as count,
SUM(size) as "totalSize"
FROM attachments a
${whereClause}
GROUP BY a."contentType"
ORDER BY count DESC`,
params
);
// Top uploaders
const topUploadersQuery = await pgClient.query(
`SELECT
a."userId",
u.name as "userName",
u.email as "userEmail",
COUNT(*) as "attachmentCount",
SUM(a.size) as "totalSize"
FROM attachments a
LEFT JOIN users u ON a."userId" = u.id
${whereClause}
GROUP BY a."userId", u.name, u.email
ORDER BY "attachmentCount" DESC
LIMIT 10`,
params
);
// Recent uploads
const recentUploadsQuery = await pgClient.query(
`SELECT
a.id,
a.key,
a."contentType",
a.size,
a."createdAt",
u.name as "uploadedByName",
d.title as "documentTitle"
FROM attachments a
LEFT JOIN users u ON a."userId" = u.id
LEFT JOIN documents d ON a."documentId" = d.id
${whereClause}
ORDER BY a."createdAt" DESC
LIMIT 10`,
params
);
return {
content: [
{
type: 'text',
text: JSON.stringify(
{
overall: overallStatsQuery.rows[0],
byContentType: byContentTypeQuery.rows,
topUploaders: topUploadersQuery.rows,
recentUploads: recentUploadsQuery.rows,
},
null,
2
),
},
],
};
},
};
// Export all attachment tools
export const attachmentsTools: BaseTool<any>[] = [
listAttachments,
getAttachment,
createAttachment,
deleteAttachment,
getAttachmentStats,
];