Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Export schemas #4260

Draft
wants to merge 19 commits into
base: develop
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
12 changes: 12 additions & 0 deletions db/schemas.py
Original file line number Diff line number Diff line change
Expand Up @@ -47,3 +47,15 @@ def create_schema(schema_name, conn, owner_oid, description=None):

def drop_schemas(conn, sch_oids):
db_conn.exec_msar_func(conn, 'drop_schemas', sch_oids)


def schema_has_custom_type_dependency(sch_oid, conn):
"""
Determine whether any column within the specified schema uses a custom type
from the 'mathesar_types' namespace.
"""
return db_conn.exec_msar_func(
conn,
'schema_has_custom_type_dependency',
sch_oid
).fetchone()[0]
1 change: 1 addition & 0 deletions db/sql/00_msar_all_objects_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1158,6 +1158,7 @@ INSERT INTO msar.all_mathesar_objects VALUES
('msar', 'msar.role_info_table()', 'FUNCTION', NULL),
('msar', 'msar.sanitize_direction(text)', 'FUNCTION', NULL),
('msar', 'msar.schema_exists(text)', 'FUNCTION', NULL),
('msar', 'msar.schema_has_custom_type_dependency(regnamespace)', 'FUNCTION', NULL),
('msar', 'msar.schema_info_table()', 'FUNCTION', NULL),
('msar', 'msar.search_records_from_table(oid,jsonb,integer,boolean)', 'FUNCTION', NULL),
('msar', 'msar.search_records_from_table(oid,jsonb,integer,boolean,jsonb)', 'FUNCTION', NULL),
Expand Down
24 changes: 24 additions & 0 deletions db/sql/05_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2004,6 +2004,30 @@ BEGIN
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;

----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------
-- SCHEMA UTILITY FUNCTIONS
--
-- Helper functions for schema.
----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------

CREATE OR REPLACE FUNCTION
msar.schema_has_custom_type_dependency(sch_id regnamespace) RETURNS boolean AS $$/*
Determine whether any column within the specified schema uses a custom type
from the 'mathesar_types' namespace.

Args:
sch_ids: The OID of the schema to inspect.
*/
SELECT EXISTS (
SELECT 1 FROM pg_catalog.pg_attribute pga
LEFT JOIN pg_catalog.pg_class pgc ON pga.attrelid = pgc.oid
LEFT JOIN pg_catalog.pg_type pgt ON pga.atttypid = pgt.oid
WHERE pgt.typnamespace='mathesar_types'::regnamespace::oid
AND pgc.relnamespace = sch_id
);
$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;

----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------
Expand Down
28 changes: 28 additions & 0 deletions db/sql/test_sql_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1348,6 +1348,34 @@ END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION __setup_schemas_with_custom_type_dep() RETURNS SETOF TEXT AS $$
BEGIN
CREATE SCHEMA type_dep_schema;
CREATE SCHEMA no_type_dep_schema;
CREATE TABLE type_dep_schema.actors (
id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
actor_name TEXT,
actor_email mathesar_types.email
);
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_schema_has_custom_type_dependency() RETURNS SETOF TEXT AS $$
BEGIN
PERFORM __setup_schemas_with_custom_type_dep();
RETURN NEXT is(
msar.schema_has_custom_type_dependency('type_dep_schema'::regnamespace),
true
);
RETURN NEXT is(
msar.schema_has_custom_type_dependency('no_type_dep_schema'::regnamespace),
false
);
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_patch_schema() RETURNS SETOF TEXT AS $$
DECLARE sch_oid oid;
BEGIN
Expand Down
1 change: 1 addition & 0 deletions mathesar/urls.py
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,7 @@
urlpatterns = [
path('api/rpc/v0/', views.MathesarRPCEntryPoint.as_view()),
path('api/db/v0/', include(db_router.urls)),
path('api/export/v0/schemas/', views.export.export_schema, name="export_schema"),
path('api/export/v0/tables/', views.export.export_table, name="export_table"),
path('complete_installation/', installation_incomplete(CompleteInstallationFormView.as_view()), name='complete_installation'),
path('auth/password_reset_confirm/', MathesarPasswordResetConfirmView.as_view(), name='password_reset_confirm'),
Expand Down
66 changes: 64 additions & 2 deletions mathesar/views/export.py
Original file line number Diff line number Diff line change
@@ -1,16 +1,24 @@
import csv
from io import StringIO
import subprocess
from io import StringIO, BytesIO

from psycopg import sql
from django.contrib.auth.decorators import login_required
from django import forms
from django.http import StreamingHttpResponse, JsonResponse
from django.http import StreamingHttpResponse, JsonResponse, FileResponse

from mathesar.rpc.utils import connect
from mathesar.rpc.records import Filter, OrderBy

from db.schemas import get_schema, schema_has_custom_type_dependency
from db.tables import fetch_table_in_chunks


class ExportSchemaQueryForm(forms.Form):
database_id = forms.IntegerField(required=True)
schema_oid = forms.IntegerField(required=True)


class ExportTableQueryForm(forms.Form):
database_id = forms.IntegerField(required=True)
table_oid = forms.IntegerField(required=True)
Expand Down Expand Up @@ -71,6 +79,60 @@ def stream_table_as_csv(
return response


def dump_schema(
request,
database_id: int,
schema_oid: int
) -> FileResponse:
user = request.user
with connect(database_id, user) as conn:
schema_name = get_schema(schema_oid, conn)['name']
has_type_deps = schema_has_custom_type_dependency(schema_oid, conn)
pg_dump_cmd = [
'pg_dump',
'-h', conn.info.host,
'-p', str(conn.info.port),
'-U', conn.info.user,
'-d', conn.info.dbname
] + (
# Include mathesar_types if a schema depend on our custom types
['-n', sql.Identifier('mathesar_types').as_string()] if has_type_deps else []
) + [
'-n', sql.Identifier(schema_name).as_string(),
'-O' # Don't include owner info in the dump
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think you should add the --inserts flag here. We should prioritize compatibility over performance, unless the performance really becomes a problem for someone.

I'd also like you to look into whether there's a flag to add that will get rid of the SET commands at the start of the file. Those can also cause problems when loading, and aren't usually needed.

Copy link
Member Author

@Anish9901 Anish9901 Feb 17, 2025

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'd also like you to look into whether there's a flag to add that will get rid of the SET commands at the start of the file.

There is no such flag, unfortunately, users would have to take those statements out manually. Apparently, postgres includes those statements to make sure that upon restore, the server behaves exactly the same as when the dump was created.

Given this, and the fact that we use GENERATED BY DEFAULT AS IDENTITY for id columns, would it make sense for us to prioritize compatibility over performance? The performance for someone dumping their local database and restoring it on a remote server would be terrible if there's a lot of data. Assuming this being a fairly common use case for someone using our product.

]
db_pass = {'PGPASSWORD': conn.info.password}
process = subprocess.Popen(
pg_dump_cmd,
stdout=subprocess.PIPE,
stderr=subprocess.PIPE,
env=db_pass
)
dump_data, err = process.communicate()
assert process.returncode == 0, 'Schema export failed: ' + err.decode('utf-8')
dump_file = BytesIO(dump_data)
dump_file.seek(0)
return FileResponse(
dump_file,
as_attachment=True,
content_type='application/sql'
)


@login_required
def export_schema(request):
form = ExportSchemaQueryForm(request.GET)
if form.is_valid():
data = form.cleaned_data
return dump_schema(
request,
database_id=data['database_id'],
schema_oid=data['schema_oid']
)
else:
return JsonResponse({'errors': form.errors}, status=400)


@login_required
def export_table(request):
form = ExportTableQueryForm(request.GET)
Expand Down
2 changes: 2 additions & 0 deletions mathesar_ui/src/i18n/languages/en/dict.json
Original file line number Diff line number Diff line change
Expand Up @@ -241,6 +241,8 @@
"exploring_from": "Exploring from",
"export": "Export",
"export_csv_help": "Export the {tableName} table as a CSV file. Your current filters and sorting will be applied to the exported data.",
"export_schema_help": "Export the {schemaName} schema as a SQL file.",
"export_sql": "Export SQL",
"extract_columns_to_new_table": "{count, plural, one {Extract Column Into a New Table} other {Extract Columns Into a New Table}}",
"failed_load_preview": "Failed to load preview",
"failed_to_fetch_column_information": "Failed to fetch column information.",
Expand Down
1 change: 1 addition & 0 deletions mathesar_ui/src/models/Database.ts
Original file line number Diff line number Diff line change
Expand Up @@ -101,6 +101,7 @@ export class Database {
postProcess: (currentRole) => ({
currentRoleOid: currentRole.current_role.oid,
parentRoleOids: new Set(currentRole.parent_roles.map((pr) => pr.oid)),
isSuper: currentRole.current_role.super,
}),
});
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -72,6 +72,9 @@
database_id: database.id,
}),
databaseRouteContext.roles.batchRunner({ database_id: database.id }),
databaseRouteContext.currentRole.batchRunner({
database_id: database.id,
}),
]);
void fetchSchemasForCurrentDatabase();
}
Expand Down
58 changes: 56 additions & 2 deletions mathesar_ui/src/pages/schema/SchemaPage.svelte
Original file line number Diff line number Diff line change
@@ -1,17 +1,32 @@
<script lang="ts">
import { _ } from 'svelte-i18n';

import { getQueryStringFromParams } from '@mathesar/api/rest/utils/requestUtils';
import AppSecondaryHeader from '@mathesar/components/AppSecondaryHeader.svelte';
import { iconEdit, iconPermissions, iconSchema } from '@mathesar/icons';
import { DatabaseRouteContext } from '@mathesar/contexts/DatabaseRouteContext';
import {
iconEdit,
iconExport,
iconMoreActions,
iconPermissions,
iconSchema,
} from '@mathesar/icons';
import LayoutWithHeader from '@mathesar/layouts/LayoutWithHeader.svelte';
import type { Database } from '@mathesar/models/Database';
import type { Schema } from '@mathesar/models/Schema';
import { makeSimplePageTitle } from '@mathesar/pages/pageTitleUtils';
import AsyncRpcApiStore from '@mathesar/stores/AsyncRpcApiStore';
import { modal } from '@mathesar/stores/modal';
import { queries } from '@mathesar/stores/queries';
import { currentTablesData as tablesStore } from '@mathesar/stores/tables';
import AddEditSchemaModal from '@mathesar/systems/schemas/AddEditSchemaModal.svelte';
import { Button, Icon } from '@mathesar-component-library';
import {
Button,
DropdownMenu,
Icon,
LinkMenuItem,
Tooltip,
} from '@mathesar-component-library';

import AddTableModal from './AddTableModal.svelte';
import SchemaOverview from './SchemaOverview.svelte';
Expand All @@ -20,6 +35,13 @@
export let database: Database;
export let schema: Schema;

const databaseContext = DatabaseRouteContext.get();
$: ({ currentRole } = $databaseContext);
$: void AsyncRpcApiStore.runBatchConservatively([
currentRole.batchRunner({ database_id: database.id }),
]);
$: isCurrentRoleSuper = !!$currentRole.resolvedValue?.isSuper;

const editSchemaModal = modal.spawnModalController();
const addTableModal = modal.spawnModalController();
const permissionsModal = modal.spawnModalController();
Expand All @@ -35,6 +57,10 @@

$: ({ name, description, currentAccess } = schema);
$: ({ currentRoleOwns } = currentAccess);
$: exportLinkParams = getQueryStringFromParams({
database_id: database.id,
schema_oid: schema.oid,
});
</script>

<svelte:head><title>{makeSimplePageTitle($name)}</title></svelte:head>
Expand Down Expand Up @@ -65,6 +91,34 @@
<Icon {...iconPermissions} />
<span>{$_('schema_permissions')}</span>
</Button>
{#if isCurrentRoleSuper}
<DropdownMenu
showArrow={false}
triggerAppearance="plain"
icon={iconMoreActions}
preferredPlacement="bottom-end"
>
<Tooltip allowHover>
<LinkMenuItem
slot="trigger"
icon={iconExport}
href="/api/export/v0/schemas/?{exportLinkParams}"
data-tinro-ignore
appearance="secondary"
size="medium"
aria-label={$_('export_sql')}
download="{$name}.sql"
>
<span>{$_('export_sql')}</span>
</LinkMenuItem>
<span slot="content">
{$_('export_schema_help', {
values: { schemaName: $name },
})}
</span>
</Tooltip>
</DropdownMenu>
{/if}
</div>

<svelte:fragment slot="bottom">
Expand Down
Loading