On SQL explorer page add a button to copy the create tables database schema
This commit is contained in:
10
app.py
10
app.py
@@ -400,13 +400,6 @@ def get_most_recent_topset_for_exercise(person_id, workout_id):
|
||||
(repetitions, weight, exercise_name) = topset
|
||||
return render_template('partials/new_set_form.html', person_id=person_id, workout_id=workout_id, exercise_id=exercise_id, exercise_name=exercise_name, repetitions=repetitions, weight=weight)
|
||||
|
||||
|
||||
def calculate_relative_positions(start_dates):
|
||||
min_date = min(start_dates)
|
||||
max_date = max(start_dates)
|
||||
total_span = (max_date - min_date).days if max_date != min_date else 1
|
||||
return [(date - min_date).days / total_span for date in start_dates]
|
||||
|
||||
@ app.route("/person/<int:person_id>/exercise/<int:exercise_id>/sparkline", methods=['GET'])
|
||||
def get_exercise_progress_for_user(person_id, exercise_id):
|
||||
min_date = convert_str_to_date(request.args.get(
|
||||
@@ -536,7 +529,8 @@ def delete_sql_query(query_id):
|
||||
def sql_schema():
|
||||
schema_info = db.sql_explorer.get_schema_info()
|
||||
mermaid_code = db.sql_explorer.generate_mermaid_er(schema_info)
|
||||
return render_template('partials/sql_explorer/schema.html', mermaid_code=mermaid_code)
|
||||
create_sql = db.sql_explorer.generate_create_script(schema_info)
|
||||
return render_template('partials/sql_explorer/schema.html', mermaid_code=mermaid_code, create_sql=create_sql)
|
||||
|
||||
@app.route("/plot/<int:query_id>", methods=['GET'])
|
||||
def plot_query(query_id):
|
||||
|
||||
@@ -3,7 +3,7 @@ class SQLExplorer:
|
||||
self.execute = db_connection_method
|
||||
|
||||
def get_schema_info(self, schema='public'):
|
||||
# Get all table names in the specified schema
|
||||
# Get tables
|
||||
tables_result = self.execute("""
|
||||
SELECT table_name
|
||||
FROM information_schema.tables
|
||||
@@ -18,10 +18,26 @@ class SQLExplorer:
|
||||
columns_result = self.execute("""
|
||||
SELECT column_name, data_type
|
||||
FROM information_schema.columns
|
||||
WHERE table_schema = %s AND table_name = %s;
|
||||
WHERE table_schema = %s AND table_name = %s
|
||||
ORDER BY ordinal_position;
|
||||
""", [schema, table])
|
||||
columns = [(row['column_name'], row['data_type']) for row in columns_result]
|
||||
|
||||
# Get primary keys
|
||||
# The constraint_type = 'PRIMARY KEY' check ensures we only get PK constraints
|
||||
# This returns all columns that are part of the PK for this table.
|
||||
primary_keys_result = self.execute("""
|
||||
SELECT kcu.column_name
|
||||
FROM information_schema.table_constraints tc
|
||||
JOIN information_schema.key_column_usage kcu
|
||||
ON tc.constraint_name = kcu.constraint_name
|
||||
AND tc.table_schema = kcu.table_schema
|
||||
WHERE tc.constraint_type = 'PRIMARY KEY'
|
||||
AND tc.table_schema = %s
|
||||
AND tc.table_name = %s;
|
||||
""", [schema, table])
|
||||
primary_keys = [row['column_name'] for row in primary_keys_result]
|
||||
|
||||
# Get foreign keys
|
||||
foreign_keys_result = self.execute("""
|
||||
SELECT
|
||||
@@ -31,15 +47,15 @@ class SQLExplorer:
|
||||
FROM
|
||||
information_schema.table_constraints AS tc
|
||||
JOIN information_schema.key_column_usage AS kcu
|
||||
ON tc.constraint_name = kcu.constraint_name
|
||||
AND tc.table_schema = kcu.table_schema
|
||||
ON tc.constraint_name = kcu.constraint_name
|
||||
AND tc.table_schema = kcu.table_schema
|
||||
JOIN information_schema.constraint_column_usage AS ccu
|
||||
ON ccu.constraint_name = tc.constraint_name
|
||||
AND ccu.table_schema = tc.table_schema
|
||||
ON ccu.constraint_name = tc.constraint_name
|
||||
AND ccu.table_schema = tc.table_schema
|
||||
WHERE
|
||||
tc.constraint_type = 'FOREIGN KEY' AND
|
||||
tc.table_schema = %s AND
|
||||
tc.table_name = %s;
|
||||
tc.constraint_type = 'FOREIGN KEY'
|
||||
AND tc.table_schema = %s
|
||||
AND tc.table_name = %s;
|
||||
""", [schema, table])
|
||||
foreign_keys = [
|
||||
(row['fk_column'], row['referenced_table'], row['referenced_column'])
|
||||
@@ -48,10 +64,25 @@ class SQLExplorer:
|
||||
|
||||
schema_info[table] = {
|
||||
'columns': columns,
|
||||
'primary_keys': primary_keys,
|
||||
'foreign_keys': foreign_keys
|
||||
}
|
||||
|
||||
return schema_info
|
||||
|
||||
def map_data_type_for_sql(self, postgres_type):
|
||||
# This is naive. For real usage, you may handle numeric precision, etc.
|
||||
# Or simply return the raw type since your DB is PostgreSQL anyway.
|
||||
return {
|
||||
'character varying': 'VARCHAR',
|
||||
'varchar': 'VARCHAR',
|
||||
'text': 'TEXT',
|
||||
'integer': 'INTEGER',
|
||||
'bigint': 'BIGINT',
|
||||
'boolean': 'BOOLEAN',
|
||||
'timestamp without time zone': 'TIMESTAMP',
|
||||
'timestamp with time zone': 'TIMESTAMPTZ',
|
||||
}.get(postgres_type, postgres_type.upper())
|
||||
|
||||
def map_data_type(self, postgres_type):
|
||||
type_mapping = {
|
||||
@@ -92,6 +123,42 @@ class SQLExplorer:
|
||||
|
||||
return "\n".join(mermaid_lines)
|
||||
|
||||
def generate_create_script(self, schema_info):
|
||||
lines = []
|
||||
|
||||
for table, info in schema_info.items():
|
||||
columns = info['columns']
|
||||
pks = info.get('primary_keys', [])
|
||||
fks = info['foreign_keys']
|
||||
|
||||
column_defs = []
|
||||
for column_name, data_type in columns:
|
||||
sql_type = self.map_data_type_for_sql(data_type)
|
||||
column_defs.append(f' "{column_name}" {sql_type}')
|
||||
|
||||
if pks:
|
||||
pk_columns = ", ".join(f'"{pk}"' for pk in pks)
|
||||
column_defs.append(f' PRIMARY KEY ({pk_columns})')
|
||||
|
||||
create_stmt = 'CREATE TABLE "{}" (\n'.format(table)
|
||||
create_stmt += ",\n".join(column_defs)
|
||||
create_stmt += '\n);'
|
||||
lines.append(create_stmt)
|
||||
|
||||
# Foreign keys
|
||||
for fk_column, ref_table, ref_col in fks:
|
||||
alter_stmt = (
|
||||
f'ALTER TABLE "{table}" '
|
||||
f'ADD CONSTRAINT "fk_{table}_{fk_column}" '
|
||||
f'FOREIGN KEY ("{fk_column}") '
|
||||
f'REFERENCES "{ref_table}" ("{ref_col}");'
|
||||
)
|
||||
lines.append(alter_stmt)
|
||||
|
||||
lines.append("") # separate blocks
|
||||
|
||||
return "\n".join(lines)
|
||||
|
||||
def execute_sql(self, query):
|
||||
results = None
|
||||
columns = []
|
||||
|
||||
@@ -1,7 +1,56 @@
|
||||
<div class="overflow-auto" style="max-height: 80vh;">
|
||||
<div class="mermaid" style="opacity: 0;" _="on load
|
||||
<div class="relative">
|
||||
<!-- Hidden textarea containing the actual SQL (so we preserve line breaks) -->
|
||||
<textarea id="create_sql_text" style="display: none;">{{ create_sql }}</textarea>
|
||||
|
||||
<!-- Floating Clear Button -->
|
||||
<button onclick="copySqlToClipboard()"
|
||||
class="absolute top-0 right-0 m-2 px-3 py-2 flex items-center gap-2 rounded-full bg-gray-800 text-white shadow-md opacity-50 hover:opacity-100 hover:bg-gray-700 transition-all">
|
||||
|
||||
<svg xmlns="http://www.w3.org/2000/svg" fill="none" viewBox="0 0 24 24" stroke-width="1.5" stroke="currentColor"
|
||||
class="h-5 w-5">
|
||||
<path stroke-linecap="round" stroke-linejoin="round"
|
||||
d="M9 12h3.75M9 15h3.75M9 18h3.75m3 .75H18a2.25 2.25 0 0 0 2.25-2.25V6.108c0-1.135-.845-2.098-1.976-2.192a48.424 48.424 0 0 0-1.123-.08m-5.801 0c-.065.21-.1.433-.1.664 0 .414.336.75.75.75h4.5a.75.75 0 0 0 .75-.75 2.25 2.25 0 0 0-.1-.664m-5.8 0A2.251 2.251 0 0 1 13.5 2.25H15c1.012 0 1.867.668 2.15 1.586m-5.8 0c-.376.023-.75.05-1.124.08C9.095 4.01 8.25 4.973 8.25 6.108V8.25m0 0H4.875c-.621 0-1.125.504-1.125 1.125v11.25c0 .621.504 1.125 1.125 1.125h9.75c.621 0 1.125-.504 1.125-1.125V9.375c0-.621-.504-1.125-1.125-1.125H8.25ZM6.75 12h.008v.008H6.75V12Zm0 3h.008v.008H6.75V15Zm0 3h.008v.008H6.75V18Z" />
|
||||
</svg>
|
||||
|
||||
<span>Copy SQL</span>
|
||||
</button>
|
||||
|
||||
<div class="overflow-auto" style="max-height: 80vh;">
|
||||
<div class="mermaid" style="opacity: 0;" _="on load
|
||||
mermaid.init(undefined, this)
|
||||
set me.style.opacity to '1'">
|
||||
{{ mermaid_code }}
|
||||
{{ mermaid_code }}
|
||||
</div>
|
||||
</div>
|
||||
|
||||
<script>
|
||||
function copySqlToClipboard() {
|
||||
const textArea = document.getElementById("create_sql_text");
|
||||
const text = textArea.value;
|
||||
|
||||
if (navigator.clipboard && navigator.clipboard.writeText) {
|
||||
// Modern approach: Use Clipboard API
|
||||
navigator.clipboard.writeText(text)
|
||||
.then(() => {
|
||||
alert("SQL copied to clipboard!");
|
||||
})
|
||||
.catch(err => {
|
||||
alert("Failed to copy: " + err);
|
||||
});
|
||||
} else {
|
||||
// Fallback (older browsers):
|
||||
// - Temporarily show the textarea, select, and use document.execCommand('copy')
|
||||
// - This approach is less reliable but widely supported before navigator.clipboard.
|
||||
textArea.style.display = "block"; // show temporarily
|
||||
textArea.select();
|
||||
try {
|
||||
document.execCommand("copy");
|
||||
alert("SQL copied to clipboard!");
|
||||
} catch (err) {
|
||||
alert("Failed to copy: " + err);
|
||||
}
|
||||
textArea.style.display = "none"; // hide again
|
||||
}
|
||||
}
|
||||
</script>
|
||||
</div>
|
||||
Reference in New Issue
Block a user