Skip to content

Commit dfce37e

Browse files
authored
Adding a schema diff tool (#123)
The new tool to generate schema diff for a specific branch has been added. It also suggests generating a zero-downtime migration and executing it on the parent branch if the user gives consent. <details> <summary>Here is the example</summary> # Generate schema diff for branch _Exported on 10/8/2025 at 14:53:39 GMT+2 from Cursor (1.7.39)_ --- **User** can you generate a schema diff for the branch br-holy-surf-admmhx6e in project winter-cake-15657477 --- **Cursor** I'll generate a schema diff for that branch. Let me compare its schema with its parent branch. Perfect! I've generated the schema diff for branch `br-holy-surf-admmhx6e` in project `winter-cake-15657477`. Here's what changed compared to its parent branch: ## Schema Changes ### **Tables Modified** - **`public.users`**: Added 3 new columns - `is_deleted` - boolean field with default value `false` (NOT NULL) - `created_at` - timestamp with timezone, defaults to current time (NOT NULL) - `updated_at` - timestamp with timezone (nullable) ### **Indexes Added** - **`users_created_at_idx`**: A B-tree index on the `users` table - Indexes `created_at` in descending order - Partial index with condition `WHERE (is_deleted = false)` for better performance --- The diff represents the changes that would need to be applied to the parent branch to match this child branch's schema. This looks like a typical soft-delete pattern implementation with audit timestamps and an optimized index for querying non-deleted users by creation time. Would you like me to help you: 1. Generate a zero-downtime migration to apply these changes to the parent branch? 2. Analyze the impact of these changes? 3. Something else? --- **User** let's go --- **Cursor** Great! I'll generate a zero-downtime migration to apply these changes to the parent branch. Let me create SQL statements that are safe to run without blocking your database. ## Proposed Migration Strategy Based on the schema diff, here's the zero-downtime migration plan: ### Step 1: Add `is_deleted` column (safe - no table rewrite) ```sql ALTER TABLE users ADD COLUMN IF NOT EXISTS is_deleted boolean DEFAULT false NOT NULL; ``` ### Step 2: Add `created_at` column (zero-downtime approach) ```sql -- Add column without default first (fast, no rewrite) ALTER TABLE users ADD COLUMN IF NOT EXISTS created_at timestamp with time zone; -- Backfill existing rows UPDATE users SET created_at = now() WHERE created_at IS NULL; -- Now set NOT NULL constraint ALTER TABLE users ALTER COLUMN created_at SET NOT NULL; -- Finally, set the default for future inserts ALTER TABLE users ALTER COLUMN created_at SET DEFAULT now(); ``` ### Step 3: Add `updated_at` column (safe - nullable, no default) ```sql ALTER TABLE users ADD COLUMN IF NOT EXISTS updated_at timestamp with time zone; ``` ### Step 4: Create index concurrently (zero-downtime) ```sql CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON public.users USING btree (created_at DESC) WHERE (is_deleted = false); ``` --- **Impact Summary:** - ✅ No table rewrites - ✅ Minimal lock time - ✅ Index created without blocking writes - ⚠️ The UPDATE statement in Step 2 may take time on large tables but won't block reads/writes **Would you like me to execute this migration on the parent branch now?** I'll run each statement and show you the results. Type "yes" to proceed or let me know if you'd like any adjustments. ```sql ALTER TABLE users ADD COLUMN IF NOT EXISTS is_deleted boolean DEFAULT false NOT NULL; ``` ```sql -- Add column without default first (fast, no rewrite) ALTER TABLE users ADD COLUMN IF NOT EXISTS created_at timestamp with time zone; -- Backfill existing rows UPDATE users SET created_at = now() WHERE created_at IS NULL; -- Now set NOT NULL constraint ALTER TABLE users ALTER COLUMN created_at SET NOT NULL; -- Finally, set the default for future inserts ALTER TABLE users ALTER COLUMN created_at SET DEFAULT now(); ``` ```sql ALTER TABLE users ADD COLUMN IF NOT EXISTS updated_at timestamp with time zone; ``` ```sql CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON public.users USING btree (created_at DESC) WHERE (is_deleted = false); ``` --- **User** yes --- **Cursor** Perfect! I'll execute the migration step by step on the parent branch. Let me start: ✅ **Step 1 Complete:** Added `is_deleted` column ✅ **Step 2a Complete:** Added `created_at` column (nullable, no default) ✅ **Step 2b Complete:** Backfilled existing rows with current timestamp ✅ **Step 2c Complete:** Set NOT NULL constraint on `created_at` ✅ **Step 2d Complete:** Set default value for `created_at` ✅ **Step 3 Complete:** Added `updated_at` column ✅ **Step 4 Complete:** Created index `users_created_at_idx` concurrently --- ## 🎉 Migration Complete! All schema changes have been successfully applied to the parent branch. Let me verify that the schemas now match: ✅ **Verification Complete:** The schema diff is now empty, confirming that the parent branch schema now matches the child branch `br-holy-surf-admmhx6e`. ### Summary of Changes Applied: 1. ✅ Added `is_deleted` column (boolean, default: false, NOT NULL) 2. ✅ Added `created_at` column (timestamptz, default: now(), NOT NULL) 3. ✅ Added `updated_at` column (timestamptz, nullable) 4. ✅ Created partial index `users_created_at_idx` for efficient queries on non-deleted users **All changes were applied with zero-downtime** - no table locks, no blocking operations, and the index was created concurrently. Your database is now fully updated! 🚀 </details>
1 parent 08380ce commit dfce37e

File tree

7 files changed

+308
-1
lines changed

7 files changed

+308
-1
lines changed

CHANGELOG.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44

55
- Feat: `list_shared_projects` tool to fetch projects that user has permissions to collaborate on
66
- Feat: `reset_from_parent` tool to reset a branch from its parent's current state
7+
- Feat: `compare_database_schema` tool to compare the schema from the child branch and its parent
78

89
# [0.6.4] 2025-08-22
910

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -198,6 +198,7 @@ The Neon MCP Server provides the following actions, which are exposed as "tools"
198198
- **`list_branch_computes`**: Lists compute endpoints for a project or specific branch, including compute ID, type, size, and autoscaling information.
199199
- **`list_organizations`**: Lists all organizations that the current user has access to. Optionally filter by organization name or ID using the search parameter.
200200
- **`reset_from_parent`**: Resets the current branch to its parent's state, discarding local changes. Automatically preserves to backup if branch has children, or optionally preserve on request with a custom name.
201+
- **`compare_database_schema`**: Shows the schema diff between the child branch and its parent
201202

202203
**SQL Query Execution:**
203204

landing/components/DescriptionItem.tsx

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,8 @@ import {
1313
import {
1414
Terminal,
1515
CircleAlert,
16+
Lightbulb,
17+
BadgeInfo,
1618
Workflow,
1719
SquareArrowRight,
1820
Component,
@@ -30,6 +32,8 @@ const ALERT_VARIANT_PER_DESCRIPTION_TYPE: Record<
3032
next_steps: { variant: 'default', icon: SquareArrowRight },
3133
important_notes: { variant: 'important', icon: CircleAlert },
3234
workflow: { variant: 'default', icon: Workflow },
35+
hints: { variant: 'default', icon: BadgeInfo },
36+
hint: { variant: 'default', icon: Lightbulb },
3337
instructions: { variant: 'default', icon: Terminal },
3438
response_instructions: { variant: 'default', icon: Terminal },
3539
example: { variant: 'default', icon: Terminal },

landing/lib/description.ts

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -10,6 +10,8 @@ const POSSIBLE_TYPES = [
1010
'example',
1111
'do_not_include',
1212
'error_handling',
13+
'hint',
14+
'hints',
1315
] as const;
1416

1517
export type DescriptionItemType = (typeof POSSIBLE_TYPES)[number];
@@ -134,7 +136,7 @@ export function parseDescription(description: string): DescriptionItem[] {
134136

135137
while (rest.length > 0) {
136138
const match = rest.match(
137-
/<(use_case|workflow|important_notes|next_steps|response_instructions|instructions|example|do_not_include|error_handling)>(.*?)<\/\1>/s,
139+
/<(use_case|workflow|important_notes|next_steps|response_instructions|instructions|example|do_not_include|error_handling|hints?)>(.*?)<\/\1>/s,
138140
);
139141

140142
if (!match) {

src/tools/definitions.ts

Lines changed: 270 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@ import {
2323
listOrganizationsInputSchema,
2424
listSharedProjectsInputSchema,
2525
resetFromParentInputSchema,
26+
compareDatabaseSchemaInputSchema,
2627
} from './toolsSchema.js';
2728

2829
export const NEON_TOOLS = [
@@ -608,4 +609,273 @@ export const NEON_TOOLS = [
608609
description: 'Lists compute endpoints for a project or specific branch',
609610
inputSchema: listBranchComputesInputSchema,
610611
},
612+
{
613+
name: 'compare_database_schema' as const,
614+
description: `
615+
<use_case>
616+
Use this tool to compare the schema of a database between two branches.
617+
The output of the tool is a JSON object with one field: \`diff\`.
618+
619+
<example>
620+
\`\`\`json
621+
{
622+
"diff": "--- a/neondb\n+++ b/neondb\n@@ -27,7 +27,10 @@\n \n CREATE TABLE public.users (\n id integer NOT NULL,\n- username character varying(50) NOT NULL\n+ username character varying(50) NOT NULL,\n+ is_deleted boolean DEFAULT false NOT NULL,\n+ created_at timestamp with time zone DEFAULT now() NOT NULL,\n+ updated_at timestamp with time zone\n );\n \n \n@@ -79,6 +82,13 @@\n \n \n --\n+-- Name: users_created_at_idx; Type: INDEX; Schema: public; Owner: neondb_owner\n+--\n+\n+CREATE INDEX users_created_at_idx ON public.users USING btree (created_at DESC) WHERE (is_deleted = false);\n+\n+\n+--\n -- Name: DEFAULT PRIVILEGES FOR SEQUENCES; Type: DEFAULT ACL; Schema: public; Owner: cloud_admin\n --\n \n"
623+
}
624+
\`\`\`
625+
</example>
626+
627+
At this field you will find a difference between two schemas.
628+
The diff represents the changes required to make the parent branch schema match the child branch schema.
629+
The diff field contains a unified diff (git-style patch) as a string.
630+
631+
You MUST be able to generate a zero-downtime migration from the diff and apply it to the parent branch.
632+
(This branch is a child and has a parent. You can get parent id just querying the branch details.)
633+
</use_case>
634+
635+
<important_notes>
636+
To generate schema diff, you MUST SPECIFY the \`database_name\`.
637+
If \`database_name\` is not specified, you MUST fall back to the default database name: \`${NEON_DEFAULT_DATABASE_NAME}\`.
638+
639+
You MUST TAKE INTO ACCOUNT the PostgreSQL version. The PostgreSQL version is the same for both branches.
640+
You MUST ASK user consent before running each generated SQL query.
641+
You SHOULD USE \`run_sql\` tool to run each generated SQL query.
642+
You SHOULD suggest creating a backup or point-in-time restore before running the migration.
643+
Generated queries change the schema of the parent branch and MIGHT BE dangerous to execute.
644+
Generated SQL migrations SHOULD be idempotent where possible (i.e., safe to run multiple times without failure) and include \`IF NOT EXISTS\` / \`IF EXISTS\` where applicable.
645+
You SHOULD recommend including comments in generated SQL linking back to diff hunks (e.g., \`-- from diff @@ -27,7 +27,10 @@\`) to make audits easier.
646+
Generated SQL should be reviewed for dependencies (e.g., foreign key order) before execution.
647+
</important_notes>
648+
649+
<next_steps>
650+
After executing this tool, you MUST follow these steps:
651+
1. Review the schema diff and suggest generating a zero-downtime migration.
652+
2. Follow these instructions to respond to the client:
653+
654+
<response_instructions>
655+
<instructions>
656+
Provide brief information about the changes:
657+
* Tables
658+
* Views
659+
* Indexes
660+
* Ownership
661+
* Constraints
662+
* Triggers
663+
* Policies
664+
* Extensions
665+
* Schemas
666+
* Sequences
667+
* Tablespaces
668+
* Users
669+
* Roles
670+
* Privileges
671+
</instructions>
672+
</response_instructions>
673+
674+
3. If a migration fails, you SHOULD guide the user on how to revert the schema changes, for example by using backups, point-in-time restore, or generating reverse SQL statements (if safe).
675+
</next_steps>
676+
677+
This tool:
678+
1. Generates a diff between the child branch and its parent.
679+
2. Generates a SQL migration from the diff.
680+
3. Suggest generating zero-downtime migration.
681+
682+
<workflow>
683+
1. User asks you to generate a diff between two branches.
684+
2. You suggest generating a SQL migration from the diff.
685+
3. Ensure the generated migration is zero-downtime; otherwise, warn the user.
686+
4. You ensure that your suggested migration is also matching the PostgreSQL version.
687+
5. You use \`run_sql\` tool to run each generated SQL query and ask the user consent before running it.
688+
Before requesting user consent, present a summary of all generated SQL statements along with their potential impact (e.g., table rewrites, lock risks, validation steps) so the user can make an informed decision.
689+
6. Propose to rerun the schema diff tool one more time to ensure that the migration is applied correctly.
690+
7. If the diff is empty, confirm that the parent schema now matches the child schema.
691+
8. If the diff is not empty after migration, warn the user and assist in resolving the remaining differences.
692+
</workflow>
693+
694+
<hints>
695+
<hint>
696+
Adding the column with a \`DEFAULT\` static value will not have any locks.
697+
But if the function is called that is not deterministic, it will have locks.
698+
699+
<example>
700+
\`\`\`sql
701+
-- No table rewrite, minimal lock time
702+
ALTER TABLE users ADD COLUMN status text DEFAULT 'active';
703+
\`\`\`
704+
</example>
705+
706+
There is an example of a case where the function is not deterministic and will have locks:
707+
708+
<example>
709+
\`\`\`sql
710+
-- Table rewrite, potentially longer lock time
711+
ALTER TABLE users ADD COLUMN created_at timestamptz DEFAULT now();
712+
\`\`\`
713+
714+
The fix for this is next:
715+
716+
\`\`\`sql
717+
-- Adding a nullable column first
718+
ALTER TABLE users ADD COLUMN created_at timestamptz;
719+
720+
-- Setting the default value because the rows are updated
721+
UPDATE users SET created_at = now();
722+
\`\`\`
723+
</example>
724+
</hint>
725+
726+
<hint>
727+
Adding constraints in two phases (including foreign keys)
728+
729+
<example>
730+
\`\`\`sql
731+
-- Step 1: Add constraint without validating existing data
732+
-- Fast - only blocks briefly to update catalog
733+
ALTER TABLE users ADD CONSTRAINT users_age_positive
734+
CHECK (age > 0) NOT VALID;
735+
736+
-- Step 2: Validate existing data (can take time but doesn't block writes)
737+
-- Uses SHARE UPDATE EXCLUSIVE lock - allows reads/writes
738+
ALTER TABLE users VALIDATE CONSTRAINT users_age_positive;
739+
\`\`\`
740+
</example>
741+
742+
<example>
743+
\`\`\`sql
744+
-- Step 1: Add foreign key without validation
745+
-- Fast - only updates catalog, doesn't validate existing data
746+
ALTER TABLE orders ADD CONSTRAINT orders_user_id_fk
747+
FOREIGN KEY (user_id) REFERENCES users(id) NOT VALID;
748+
749+
-- Step 2: Validate existing relationships
750+
-- Can take time but allows concurrent operations
751+
ALTER TABLE orders VALIDATE CONSTRAINT orders_user_id_fk;
752+
\`\`\`
753+
</example>
754+
</hint>
755+
756+
<hint>
757+
Setting columns to NOT NULL
758+
759+
<example>
760+
\`\`\`sql
761+
-- Step 1: Add a check constraint (fast with NOT VALID)
762+
ALTER TABLE users ADD CONSTRAINT users_email_not_null
763+
CHECK (email IS NOT NULL) NOT VALID;
764+
765+
-- Step 2: Validate the constraint (allows concurrent operations)
766+
ALTER TABLE users VALIDATE CONSTRAINT users_email_not_null;
767+
768+
-- Step 3: Set NOT NULL (fast since constraint guarantees no nulls)
769+
ALTER TABLE users ALTER COLUMN email SET NOT NULL;
770+
771+
-- Step 4: Drop the redundant check constraint
772+
ALTER TABLE users DROP CONSTRAINT users_email_not_null;
773+
\`\`\`
774+
</example>
775+
776+
<example>
777+
For PostgreSQL v18+
778+
(to get PostgreSQL version, you can use \`describe_project\` tool or \`run_sql\` tool and execute \`SELECT version();\` query)
779+
780+
\`\`\`sql
781+
-- PostgreSQL 18+ - Simplified approach
782+
ALTER TABLE users ALTER COLUMN email SET NOT NULL NOT VALID;
783+
ALTER TABLE users VALIDATE CONSTRAINT users_email_not_null;
784+
\`\`\`
785+
</example>
786+
</hint>
787+
788+
<hint>
789+
In some cases, you need to combine two approaches to achieve a zero-downtime migration.
790+
791+
<example>
792+
\`\`\`sql
793+
-- Step 1: Adding a nullable column first
794+
ALTER TABLE users ADD COLUMN created_at timestamptz;
795+
796+
-- Step 2: Updating the all rows with the default value
797+
UPDATE users SET created_at = now() WHERE created_at IS NULL;
798+
799+
-- Step 3: Creating a not null constraint
800+
ALTER TABLE users ADD CONSTRAINT users_created_at_not_null
801+
CHECK (created_at IS NOT NULL) NOT VALID;
802+
803+
-- Step 4: Validating the constraint
804+
ALTER TABLE users VALIDATE CONSTRAINT users_created_at_not_null;
805+
806+
-- Step 5: Setting the column to NOT NULL
807+
ALTER TABLE users ALTER COLUMN created_at SET NOT NULL;
808+
809+
-- Step 6: Dropping the redundant NOT NULL constraint
810+
ALTER TABLE users DROP CONSTRAINT users_created_at_not_null;
811+
812+
-- Step 7: Adding the default value
813+
ALTER TABLE users ALTER COLUMN created_at SET DEFAULT now();
814+
\`\`\`
815+
</example>
816+
817+
For PostgreSQL v18+
818+
<example>
819+
\`\`\`sql
820+
-- Step 1: Adding a nullable column first
821+
ALTER TABLE users ADD COLUMN created_at timestamptz;
822+
823+
-- Step 2: Updating the all rows with the default value
824+
UPDATE users SET created_at = now() WHERE created_at IS NULL;
825+
826+
-- Step 3: Creating a not null constraint
827+
ALTER TABLE users ALTER COLUMN created_at SET NOT NULL NOT VALID;
828+
829+
-- Step 4: Validating the constraint
830+
ALTER TABLE users VALIDATE CONSTRAINT users_created_at_not_null;
831+
832+
-- Step 5: Adding the default value
833+
ALTER TABLE users ALTER COLUMN created_at SET DEFAULT now();
834+
\`\`\`
835+
</example>
836+
</hint>
837+
838+
<hint>
839+
Create index CONCURRENTLY
840+
841+
<example>
842+
\`\`\`sql
843+
CREATE INDEX CONCURRENTLY idx_users_email ON users (email);
844+
\`\`\`
845+
</example>
846+
</hint>
847+
848+
<hint>
849+
Drop index CONCURRENTLY
850+
851+
<example>
852+
\`\`\`sql
853+
DROP INDEX CONCURRENTLY idx_users_email;
854+
\`\`\`
855+
</example>
856+
</hint>
857+
858+
<hint>
859+
Create materialized view WITH NO DATA
860+
861+
<example>
862+
\`\`\`sql
863+
CREATE MATERIALIZED VIEW mv_users AS SELECT name FROM users WITH NO DATA;
864+
\`\`\`
865+
</example>
866+
</hint>
867+
868+
<hint>
869+
Refresh materialized view CONCURRENTLY
870+
871+
<example>
872+
\`\`\`sql
873+
REFRESH MATERIALIZED VIEW CONCURRENTLY mv_users;
874+
\`\`\`
875+
</example>
876+
</hint>
877+
</hints>
878+
`,
879+
inputSchema: compareDatabaseSchemaInputSchema,
880+
},
611881
];

src/tools/tools.ts

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@ import {
44
EndpointType,
55
ListProjectsParams,
66
ListSharedProjectsParams,
7+
GetProjectBranchSchemaComparisonParams,
78
Organization,
89
ProjectCreateRequest,
910
} from '@neondatabase/api-client';
@@ -1212,6 +1213,14 @@ async function handleListSharedProjects(
12121213
return response.data.projects;
12131214
}
12141215

1216+
async function handleCompareDatabaseSchema(
1217+
params: GetProjectBranchSchemaComparisonParams,
1218+
neonClient: Api<unknown>,
1219+
) {
1220+
const response = await neonClient.getProjectBranchSchemaComparison(params);
1221+
return response.data;
1222+
}
1223+
12151224
export const NEON_HANDLERS = {
12161225
list_projects: async ({ params }, neonClient, extra) => {
12171226
const organization = await getOrgByOrgIdOrDefault(
@@ -1774,4 +1783,18 @@ export const NEON_HANDLERS = {
17741783
],
17751784
};
17761785
},
1786+
1787+
compare_database_schema: async ({ params }, neonClient) => {
1788+
const result = await handleCompareDatabaseSchema(
1789+
{
1790+
projectId: params.projectId,
1791+
branchId: params.branchId,
1792+
db_name: params.databaseName,
1793+
},
1794+
neonClient,
1795+
);
1796+
return {
1797+
content: [{ type: 'text', text: JSON.stringify(result, null, 2) }],
1798+
};
1799+
},
17771800
} satisfies ToolHandlers;

src/tools/toolsSchema.ts

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -334,3 +334,9 @@ export const resetFromParentInputSchema = z.object({
334334
'Optional name to preserve the current state under a new branch before resetting',
335335
),
336336
});
337+
338+
export const compareDatabaseSchemaInputSchema = z.object({
339+
projectId: z.string().describe('The ID of the project'),
340+
branchId: z.string().describe('The ID of the branch'),
341+
databaseName: z.string().describe(DATABASE_NAME_DESCRIPTION),
342+
});

0 commit comments

Comments
 (0)