This commit is contained in:
2025-08-05 15:15:36 +02:00
parent 4bd960ed05
commit 7fabb4163a
192 changed files with 14901 additions and 0 deletions

View File

@@ -0,0 +1,49 @@
CREATE OR REPLACE FUNCTION create_table_from_json(definition JSONB, reset BOOLEAN DEFAULT FALSE)
RETURNS VOID AS $$
local json = require("cjson")
local def = json.decode(definition)
local table_name = def.table_name
local table_fields = def.table_fields
local fts_fields = def.fts_fields or {}
local columns = ""
for key, value in pairs(table_fields) do
columns = columns .. key .. " " .. value .. ", "
end
-- Add the necessary columns
columns = columns .. "id TEXT PRIMARY KEY, "
columns = columns .. "name TEXT NOT NULL, "
columns = columns .. "creation_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP, "
columns = columns .. "mod_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP, "
columns = columns .. "data JSON"
-- Construct the CREATE TABLE statement
local create_table_sql = string.format("CREATE TABLE IF NOT EXISTS %s (%s);", table_name, columns)
print("Create table " .. tostring(create_table_sql))
-- Conditionally construct the DROP TABLE statement
if reset then
local drop_table_sql = string.format("DROP TABLE IF EXISTS %s;", table_name)
create_table_sql = drop_table_sql .. create_table_sql
end
-- Add the FTS table and index if full-text search fields are provided
if #fts_fields > 0 then
local fts_table_sql = string.format([[
CREATE TABLE IF NOT EXISTS %s_fts (
id TEXT PRIMARY KEY,
%s_id TEXT REFERENCES %s(id),
document tsvector
);
CREATE INDEX IF NOT EXISTS idx_%s_fts_document ON %s_fts USING GIN(document);
]], table_name, table_name, table_name, table_name, table_name)
create_table_sql = create_table_sql .. fts_table_sql
end
print("Create table fts" .. tostring(create_table_sql))
-- Execute the dynamic SQL
SPI.execute(create_table_sql)
$$ LANGUAGE pllua;

View File

@@ -0,0 +1,100 @@
CREATE OR REPLACE FUNCTION create_table_from_json(definition JSONB, reset BOOLEAN DEFAULT FALSE)
RETURNS VOID AS $$
local spi = require("pllua.spi")
local function execute_sql(sql)
local status, result = pcall(function()
return spi.execute(sql)
end)
if not status then
error("Failed to execute SQL: " .. tostring(result))
end
return result
end
local nullval = {} -- use some unique object to mark nulls
local def = definition{ null = nullval, pg_numeric = true }
local table_name = def.table_name
local table_fields = def.table_fields
local fts_fields = def.fts_fields or {}
local columns = {}
local existing_columns = {}
local has_id_primary_key = false
local index_columns = {}
if reset then
local drop_table_sql = string.format("DROP TABLE IF EXISTS %s CASCADE;", table_name)
execute_sql(drop_table_sql)
end
for key, value in pairs(table_fields) do
if key:lower() == "id" then
-- Ensure 'id' is always PRIMARY KEY
table.insert(columns, key .. " " .. value .. " PRIMARY KEY")
has_id_primary_key = true
else
table.insert(columns, key .. " " .. value)
if key:lower() ~= "data" then
table.insert(index_columns, key)
end
end
existing_columns[key:lower()] = true
end
print("INdex columns " .. tostring(index_columns))
-- Add necessary columns only if they don't exist
local required_columns = {
{name = "name", type = "TEXT NOT NULL"},
{name = "creation_date", type = "TIMESTAMP DEFAULT CURRENT_TIMESTAMP"},
{name = "mod_date", type = "TIMESTAMP DEFAULT CURRENT_TIMESTAMP"},
{name = "data", type = "JSONB"}
}
for _, col in ipairs(required_columns) do
if not existing_columns[col.name:lower()] then
table.insert(columns, col.name .. " " .. col.type)
table.insert(index_columns, col.name)
end
end
-- If 'id' wasn't provided, add it as PRIMARY KEY
if not has_id_primary_key then
table.insert(columns, 1, "id TEXT PRIMARY KEY")
end
-- Join columns with commas
local columns_string = table.concat(columns, ", ")
-- Construct the CREATE TABLE statement
local create_table_sql = string.format("CREATE TABLE IF NOT EXISTS %s (%s);", table_name, columns_string)
-- Conditionally construct the DROP TABLE statement
-- Execute the CREATE TABLE statement
execute_sql(create_table_sql)
-- Create an index for each column
for _, column in ipairs(index_columns) do
local index_sql = string.format("CREATE INDEX IF NOT EXISTS idx_%s_%s ON %s (%s);",
table_name, column, table_name, column)
execute_sql(index_sql)
end
-- Add the FTS table and index if full-text search fields are provided
if #fts_fields > 0 then
local fts_table_sql = string.format([[
CREATE TABLE IF NOT EXISTS %s_fts (
id TEXT PRIMARY KEY,
%s_id TEXT REFERENCES %s(id),
document tsvector
);
CREATE INDEX IF NOT EXISTS idx_%s_fts_document ON %s_fts USING GIN(document);
]], table_name, table_name, table_name, table_name, table_name)
execute_sql(fts_table_sql)
end
return
$$ LANGUAGE pllua;

View File

@@ -0,0 +1,75 @@
CREATE OR REPLACE FUNCTION create_table_from_json(definition_json JSONB, reset BOOLEAN DEFAULT FALSE)
RETURNS VOID AS $$
import plpy
import json
def execute_sql(sql):
try:
plpy.execute(sql)
except Exception as e:
plpy.error(f"Failed to execute SQL: {str(e)}")
# Parse the JSONB input into a Python dictionary
definition = json.loads(definition_json)
table_name = definition['table_name']
table_fields = definition['table_fields']
fts_fields = definition.get('fts_fields', [])
columns = []
existing_columns = set()
has_id_primary_key = False
index_columns = []
if reset:
drop_table_sql = f"DROP TABLE IF EXISTS {table_name} CASCADE;"
execute_sql(drop_table_sql)
for key, value in table_fields.items():
if key.lower() == "id":
columns.append(f"{key} {value} PRIMARY KEY")
has_id_primary_key = True
else:
columns.append(f"{key} {value}")
if key.lower() != "data":
index_columns.append(key)
existing_columns.add(key.lower())
plpy.notice(f"Index columns {index_columns}")
required_columns = [
{"name": "name", "type": "TEXT NOT NULL"},
{"name": "creation_date", "type": "TIMESTAMP DEFAULT CURRENT_TIMESTAMP"},
{"name": "mod_date", "type": "TIMESTAMP DEFAULT CURRENT_TIMESTAMP"},
{"name": "data", "type": "JSONB"}
]
for col in required_columns:
if col['name'].lower() not in existing_columns:
columns.append(f"{col['name']} {col['type']}")
index_columns.append(col['name'])
if not has_id_primary_key:
columns.insert(0, "id TEXT PRIMARY KEY")
columns_string = ", ".join(columns)
create_table_sql = f"CREATE TABLE IF NOT EXISTS {table_name} ({columns_string});"
execute_sql(create_table_sql)
for column in index_columns:
index_sql = f"CREATE INDEX IF NOT EXISTS idx_{table_name}_{column} ON {table_name} ({column});"
execute_sql(index_sql)
if fts_fields:
fts_table_sql = f"""
CREATE TABLE IF NOT EXISTS {table_name}_fts (
id TEXT PRIMARY KEY,
{table_name}_id TEXT REFERENCES {table_name}(id),
document tsvector
);
CREATE INDEX IF NOT EXISTS idx_{table_name}_fts_document ON {table_name}_fts USING GIN(document);
"""
execute_sql(fts_table_sql)
$$ LANGUAGE plpython3u;

View File

@@ -0,0 +1,56 @@
CREATE OR REPLACE FUNCTION create_table_from_json(
definition JSONB,
reset BOOLEAN DEFAULT FALSE
) RETURNS VOID AS $$
DECLARE
table_name TEXT;
table_fields JSONB;
fts_fields TEXT[];
columns TEXT := '';
create_table_sql TEXT;
drop_table_sql TEXT;
fts_table_sql TEXT := '';
field RECORD;
BEGIN
-- Extract the values from the JSON object
table_name := definition->>'table_name';
table_fields := definition->'table_fields';
fts_fields := ARRAY(SELECT jsonb_array_elements_text(definition->'fts_fields'));
-- Iterate over the JSONB object to build the columns definition
FOR field IN SELECT * FROM jsonb_each_text(table_fields)
LOOP
columns := columns || field.key || ' ' || field.value || ', ';
END LOOP;
-- Add the necessary columns
columns := columns || 'id TEXT PRIMARY KEY, ';
columns := columns || 'name TEXT NOT NULL, ';
columns := columns || 'creation_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP, ';
columns := columns || 'mod_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP, ';
columns := columns || 'data JSON';
-- Construct the CREATE TABLE statement
create_table_sql := 'CREATE TABLE IF NOT EXISTS ' || table_name || ' (' || columns || ');';
-- Conditionally construct the DROP TABLE statement
IF reset THEN
drop_table_sql := 'DROP TABLE IF EXISTS ' || table_name || ';';
create_table_sql := drop_table_sql || create_table_sql;
END IF;
-- Add the FTS table and index if full-text search fields are provided
IF array_length(fts_fields, 1) > 0 THEN
fts_table_sql := 'CREATE TABLE IF NOT EXISTS ' || table_name || '_fts (' ||
'id TEXT PRIMARY KEY, ' ||
table_name || '_id TEXT REFERENCES ' || table_name || '(id), ' ||
'document tsvector);' ||
'CREATE INDEX IF NOT EXISTS idx_' || table_name || '_fts_document ' ||
'ON ' || table_name || '_fts USING GIN(document);';
create_table_sql := create_table_sql || fts_table_sql;
END IF;
-- Execute the dynamic SQL
EXECUTE create_table_sql;
END;
$$ LANGUAGE plpgsql;