Skip to content

Commit

Permalink
Implemented sqlite-utils transform command, closes #164
Browse files Browse the repository at this point in the history
  • Loading branch information
simonw committed Sep 22, 2020
1 parent f8648ca commit a8601c2
Show file tree
Hide file tree
Showing 5 changed files with 309 additions and 39 deletions.
65 changes: 64 additions & 1 deletion docs/cli.rst
Original file line number Diff line number Diff line change
Expand Up @@ -545,7 +545,70 @@ Dropping tables

You can drop a table using the ``drop-table`` command::

$ sqlite-utils drop-table mytable
$ sqlite-utils drop-table mydb.db mytable

.. _cli_transform_table:

Transforming tables
===================

The ``transform`` command allows you to apply complex transformations to a table that cannot be implemented using a regular SQLite ``ALTER TABLE`` command. See :ref:`python_api_transform` for details of how this works.

::

$ sqlite-utils transform mydb.db mytable \
--drop column1 \
--rename column2 column_renamed

Every option for this table (with the exception of ``--pk-none``) can be specified multiple times. The options are as follows:

``--type column-name new-type``
Change the type of the specified column. Valid types are ``integer``, ``text``, ``float``, ``blob``.

``--drop column-name``
Drop the specified column.

``--rename column-name new-name``
Rename this column to a new name.

``--not-null column-name``
Set this column as ``NOT NULL``.

``--not-null-false column-name``
For a column that is currently set as ``NOT NULL``, remove the ``NOT NULL``.

``--pk column-name``
Change the primary key column for this table. Pass ``--pk`` multiple times if you want to create a compound primary key.

``--pk-none``
Remove the primary key from this table, turning it into a ``rowid`` table.

``--default column-name value``
Set the default value of this column.

``--default-none column``
Remove the default value for this column.

``--drop-foreign-key col other_table other_column``
Drop the specified foreign key.

If you want to see the SQL that will be executed to make the change without actually executing it, add the ``--sql`` flag. For example::

% sqlite-utils transform fixtures.db roadside_attractions \
--rename pk id \
--default name Untitled \
--drop address \
--sql
CREATE TABLE [roadside_attractions_new_4033a60276b9] (
[id] INTEGER PRIMARY KEY,
[name] TEXT DEFAULT 'Untitled',
[latitude] FLOAT,
[longitude] FLOAT
);
INSERT INTO [roadside_attractions_new_4033a60276b9] ([id], [name], [latitude], [longitude])
SELECT [pk], [name], [latitude], [longitude] FROM [roadside_attractions];
DROP TABLE [roadside_attractions];
ALTER TABLE [roadside_attractions_new_4033a60276b9] RENAME TO [roadside_attractions];

.. _cli_create_view:

Expand Down
100 changes: 100 additions & 0 deletions sqlite_utils/cli.py
Original file line number Diff line number Diff line change
Expand Up @@ -887,6 +887,106 @@ def rows(ctx, path, dbtable, nl, arrays, csv, no_headers, table, fmt, json_cols)
)


@cli.command()
@click.argument(
"path",
type=click.Path(file_okay=True, dir_okay=False, allow_dash=False),
required=True,
)
@click.argument("table")
@click.option(
"--type",
type=(str, str),
multiple=True,
help="Change column type to X",
)
@click.option("--drop", type=str, multiple=True, help="Drop this column")
@click.option(
"--rename", type=(str, str), multiple=True, help="Rename this column to X"
)
@click.option("--not-null", type=str, multiple=True, help="Set this column to NOT NULL")
@click.option(
"--not-null-false", type=str, multiple=True, help="Remove NOT NULL from this column"
)
@click.option("--pk", type=str, multiple=True, help="Make this column the primary key")
@click.option(
"--pk-none", is_flag=True, help="Remove primary key (convert to rowid table)"
)
@click.option(
"--default",
type=(str, str),
multiple=True,
help="Set default value for this column",
)
@click.option(
"--default-none", type=str, multiple=True, help="Remove default from this column"
)
@click.option(
"--drop-foreign-key",
type=(str, str, str),
multiple=True,
help="Drop this foreign key constraint",
)
@click.option("--sql", is_flag=True, help="Output SQL without executing it")
def transform(
path,
table,
type,
drop,
rename,
not_null,
not_null_false,
pk,
pk_none,
default,
default_none,
drop_foreign_key,
sql,
):
db = sqlite_utils.Database(path)
types = {}
kwargs = {}
for column, ctype in type:
if ctype.upper() not in VALID_COLUMN_TYPES:
raise click.ClickException(
"column types must be one of {}".format(VALID_COLUMN_TYPES)
)
types[column] = ctype.upper()

not_null_dict = {}
for column in not_null:
not_null_dict[column] = True
for column in not_null_false:
not_null_dict[column] = False

default_dict = {}
for column, value in default:
default_dict[column] = value
for column in default_none:
default_dict[column] = None

kwargs["types"] = types
kwargs["drop"] = set(drop)
kwargs["rename"] = dict(rename)
kwargs["not_null"] = not_null_dict
if pk:
if len(pk) == 1:
kwargs["pk"] = pk[0]
else:
kwargs["pk"] = pk
elif pk_none:
kwargs["pk"] = None
kwargs["defaults"] = default_dict
if drop_foreign_key:
kwargs["drop_foreign_keys"] = drop_foreign_key

if sql:
for line in db[table].transform_sql(**kwargs):
click.echo(line)
else:
db[table].transform(**kwargs)


@cli.command(name="insert-files")
@click.argument(
"path",
Expand Down
31 changes: 20 additions & 11 deletions sqlite_utils/db.py
Original file line number Diff line number Diff line change
Expand Up @@ -731,7 +731,7 @@ def transform(
sqls = self.transform_sql(
types=types,
rename=rename,
drop=None,
drop=drop,
pk=pk,
not_null=not_null,
defaults=defaults,
Expand Down Expand Up @@ -790,7 +790,7 @@ def transform_sql(
sqls = []

if should_flip_foreign_keys_pragma:
sqls.append("PRAGMA foreign_keys=OFF")
sqls.append("PRAGMA foreign_keys=OFF;")

if pk is DEFAULT:
pks_renamed = tuple(rename.get(p) or p for p in self.pks)
Expand All @@ -800,7 +800,12 @@ def transform_sql(
pk = pks_renamed

# not_null may be a set or dict, need to convert to a set
create_table_not_null = {c.name for c in self.columns if c.notnull}
create_table_not_null = {
rename.get(c.name) or c.name
for c in self.columns
if c.notnull
if c.name not in drop
}
if isinstance(not_null, dict):
# Remove any columns with a value of False
for key, value in not_null.items():
Expand All @@ -811,13 +816,16 @@ def transform_sql(
else:
create_table_not_null.add(key)
elif isinstance(not_null, set):
create_table_not_null.update(rename.get(k) or k for k in not_null)

create_table_not_null.update((rename.get(k) or k) for k in not_null)
elif not_null is None:
pass
else:
assert False, "not_null must be a dict or a set or None"
# defaults=
create_table_defaults = {
(rename.get(c.name) or c.name): c.default_value
for c in self.columns
if c.default_value is not None
if c.default_value is not None and c.name not in drop
}
if defaults is not None:
create_table_defaults.update(
Expand All @@ -844,27 +852,28 @@ def transform_sql(
foreign_keys=create_table_foreign_keys,
).strip()
)

# Copy across data, respecting any renamed columns
new_cols = []
old_cols = []
for from_, to_ in copy_from_to.items():
old_cols.append(from_)
new_cols.append(to_)
copy_sql = "INSERT INTO [{new_table}] ({new_cols}) SELECT {old_cols} FROM [{old_table}]".format(
copy_sql = "INSERT INTO [{new_table}] ({new_cols})\n SELECT {old_cols} FROM [{old_table}];".format(
new_table=new_table_name,
old_table=self.name,
old_cols=", ".join("[{}]".format(col) for col in old_cols),
new_cols=", ".join("[{}]".format(col) for col in new_cols),
)
sqls.append(copy_sql)
# Drop the old table
sqls.append("DROP TABLE [{}]".format(self.name))
sqls.append("DROP TABLE [{}];".format(self.name))
# Rename the new one
sqls.append("ALTER TABLE [{}] RENAME TO [{}]".format(new_table_name, self.name))
sqls.append("ALTER TABLE [{}] RENAME TO [{}];".format(new_table_name, self.name))

if should_flip_foreign_keys_pragma:
sqls.append("PRAGMA foreign_key_check")
sqls.append("PRAGMA foreign_keys=ON")
sqls.append("PRAGMA foreign_key_check;")
sqls.append("PRAGMA foreign_keys=ON;")

return sqls

Expand Down
98 changes: 98 additions & 0 deletions tests/test_cli.py
Original file line number Diff line number Diff line change
Expand Up @@ -1451,3 +1451,101 @@ def test_add_foreign_keys(db_path):
table="books", column="author_id", other_table="authors", other_column="id"
)
]


@pytest.mark.parametrize(
"args,expected_schema",
[
(
[],
"CREATE TABLE \"dogs\" (\n [id] INTEGER PRIMARY KEY,\n [age] INTEGER NOT NULL DEFAULT '1',\n [name] TEXT\n)",
),
(
["--type", "age", "text"],
"CREATE TABLE \"dogs\" (\n [id] INTEGER PRIMARY KEY,\n [age] TEXT NOT NULL DEFAULT '1',\n [name] TEXT\n)",
),
(
["--drop", "age"],
'CREATE TABLE "dogs" (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT\n)',
),
(
["--rename", "age", "age2", "--rename", "id", "pk"],
"CREATE TABLE \"dogs\" (\n [pk] INTEGER PRIMARY KEY,\n [age2] INTEGER NOT NULL DEFAULT '1',\n [name] TEXT\n)",
),
(
["--not-null", "name"],
"CREATE TABLE \"dogs\" (\n [id] INTEGER PRIMARY KEY,\n [age] INTEGER NOT NULL DEFAULT '1',\n [name] TEXT NOT NULL\n)",
),
(
["--not-null-false", "age"],
"CREATE TABLE \"dogs\" (\n [id] INTEGER PRIMARY KEY,\n [age] INTEGER DEFAULT '1',\n [name] TEXT\n)",
),
(
["--pk", "name"],
"CREATE TABLE \"dogs\" (\n [id] INTEGER,\n [age] INTEGER NOT NULL DEFAULT '1',\n [name] TEXT PRIMARY KEY\n)",
),
(
["--pk-none"],
"CREATE TABLE \"dogs\" (\n [id] INTEGER,\n [age] INTEGER NOT NULL DEFAULT '1',\n [name] TEXT\n)",
),
(
["--default", "name", "Turnip"],
"CREATE TABLE \"dogs\" (\n [id] INTEGER PRIMARY KEY,\n [age] INTEGER NOT NULL DEFAULT '1',\n [name] TEXT DEFAULT 'Turnip'\n)",
),
(
["--default-none", "age"],
'CREATE TABLE "dogs" (\n [id] INTEGER PRIMARY KEY,\n [age] INTEGER NOT NULL,\n [name] TEXT\n)',
),
],
)
def test_transform(db_path, args, expected_schema):
db = Database(db_path)
with db.conn:
db["dogs"].insert(
{"id": 1, "age": 4, "name": "Cleo"},
not_null={"age"},
defaults={"age": 1},
pk="id",
)
result = CliRunner().invoke(cli.cli, ["transform", db_path, "dogs"] + args)
print(result.output)
assert result.exit_code == 0
schema = db["dogs"].schema
assert schema == expected_schema


def test_transform_drop_foreign_key(db_path):
db = Database(db_path)
with db.conn:
# Create table with three foreign keys so we can drop two of them
db["country"].insert({"id": 1, "name": "France"}, pk="id")
db["city"].insert({"id": 24, "name": "Paris"}, pk="id")
db["places"].insert(
{
"id": 32,
"name": "Caveau de la Huchette",
"country": 1,
"city": 24,
},
foreign_keys=("country", "city"),
pk="id",
)
result = CliRunner().invoke(
cli.cli,
[
"transform",
db_path,
"places",
"--drop-foreign-key",
"country",
"country",
"id",
],
)
print(result.output)
assert result.exit_code == 0
schema = db["places"].schema
assert (
schema
== 'CREATE TABLE "places" (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT,\n [country] INTEGER,\n [city] INTEGER REFERENCES [city]([id])\n)'
)
Loading

0 comments on commit a8601c2

Please sign in to comment.