From 9b5bd4d3de88276abc91e2a352c4d0d74c49734c Mon Sep 17 00:00:00 2001 From: Akshay Joshi Date: Wed, 24 Sep 2025 17:47:59 +0530 Subject: [PATCH] Add pg_get_database_ddl() function to reconstruct CREATE DATABASE statements. MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit This adds a new system function, pg_get_database_ddl(database_name/database_oid, ddl_options), which reconstructs the CREATE DATABASE statement for a given database name or OID. Supported ddl_options are 'pretty', 'owner', 'tablespace' and 'defaults' and respective values could be 'yes'/'on'/true/'1'. Usage: SELECT pg_get_database_ddl('regression_utf8', 'owner', 'no', 'defaults', 'yes'); SELECT pg_get_database_ddl('regression_utf8', 'owner', '0', 'tablespace', '0', 'defaults', '1'); SELECT pg_get_database_ddl('regression_utf8', 'owner', 'off', 'pretty', 'on'); SELECT pg_get_database_ddl('regression_utf8', 'owner', false, 'defaults', 'true', 'tablespace', 'no'); Reference: PG-150 Author: Akshay Joshi Reviewed-by: Álvaro Herrera Reviewed-by: Euler Taveira Reviewed-by: Quan Zongliang Reviewed-by: Japin Li Reviewed-by: Chao Li --- doc/src/sgml/func/func-info.sgml | 86 +++++ src/backend/catalog/system_functions.sql | 6 + src/backend/utils/adt/ruleutils.c | 397 +++++++++++++++++++++++ src/include/catalog/pg_proc.dat | 7 + src/include/utils/ddl_defaults.h | 39 +++ src/test/regress/expected/database.out | 170 ++++++++++ src/test/regress/sql/database.sql | 108 ++++++ 7 files changed, 813 insertions(+) create mode 100644 src/include/utils/ddl_defaults.h diff --git a/doc/src/sgml/func/func-info.sgml b/doc/src/sgml/func/func-info.sgml index 294f45e82a3d8..c346b8d1fcf83 100644 --- a/doc/src/sgml/func/func-info.sgml +++ b/doc/src/sgml/func/func-info.sgml @@ -3845,4 +3845,90 @@ acl | {postgres=arwdDxtm/postgres,foo=r/postgres} + + Get Object DDL Functions + + + The functions described in + return the Data Definition Language (DDL) statement for any given database object. + This feature is implemented as a set of distinct functions for each object type. + + + + Get Object DDL Functions + + + + + Function + + + Description + + + + + + + + + pg_get_database_ddl + + pg_get_database_ddl + ( database_id regdatabase + , VARIADIC options + "any" ) + text + + + Reconstructs the CREATE DATABASE statement from the + system catalogs for a specified database by name or OID. The optional + variadic arguments are name/value pairs to control the output + formatting and content (e.g., 'pretty', true, 'owner', false). + Supported options are explained below. + + + + +
+ + + The options for pg_get_database_ddl + provide fine-grained control over the generated SQL. Options are passed as + alternating key/value pairs where the key is a text string and the + value is either a boolean or a text string representing a boolean + (true, false, yes, + no, 1, 0, + on, off): + + + + 'pretty', true (or 'pretty', 'yes'): + Adds newlines and indentation for better readability. + + + + + 'owner', false (or 'owner', 'no'): + Omits the OWNER clause from the reconstructed statement. + + + + + 'tablespace', false (or 'tablespace', '0'): + Omits the TABLESPACE clause from the reconstructed statement. + + + + + 'defaults', true (or 'defaults', '1'): + Includes clauses for parameters that are currently at their default values + (e.g., CONNECTION LIMIT -1), which are normally omitted for brevity. + + + + + +
+ diff --git a/src/backend/catalog/system_functions.sql b/src/backend/catalog/system_functions.sql index 69699f8830a6c..ae573e2fb2c88 100644 --- a/src/backend/catalog/system_functions.sql +++ b/src/backend/catalog/system_functions.sql @@ -378,6 +378,12 @@ BEGIN ATOMIC END; +CREATE OR REPLACE FUNCTION + pg_get_database_ddl(database_id regdatabase, VARIADIC options "any" DEFAULT NULL) +RETURNS text +LANGUAGE internal +AS 'pg_get_database_ddl'; + -- -- The default permissions for functions mean that anyone can execute them. -- A number of functions shouldn't be executable by just anyone, but rather diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index f16f15357859a..988d9d2b36aa3 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -28,6 +28,7 @@ #include "catalog/pg_authid.h" #include "catalog/pg_collation.h" #include "catalog/pg_constraint.h" +#include "catalog/pg_database.h" #include "catalog/pg_depend.h" #include "catalog/pg_language.h" #include "catalog/pg_opclass.h" @@ -57,8 +58,10 @@ #include "rewrite/rewriteHandler.h" #include "rewrite/rewriteManip.h" #include "rewrite/rewriteSupport.h" +#include "utils/acl.h" #include "utils/array.h" #include "utils/builtins.h" +#include "utils/ddl_defaults.h" #include "utils/fmgroids.h" #include "utils/guc.h" #include "utils/hsearch.h" @@ -89,11 +92,45 @@ #define PRETTYFLAG_INDENT 0x0002 #define PRETTYFLAG_SCHEMA 0x0004 +/* DDL Options flags */ +#define PG_DDL_PRETTY_INDENT 0x00000001 +#define PG_DDL_WITH_DEFAULTS 0x00000002 +#define PG_DDL_NO_OWNER 0x00000004 +#define PG_DDL_NO_TABLESPACE 0x00000008 + +/* + * Structure to define DDL options for parse_ddl_options(). + * This allows easy addition of new options in the future. + */ +typedef struct DDLOptionDef +{ + const char *name; /* Option name (case-insensitive) */ + uint64 flag; /* Flag to set */ + bool set_on_true; /* If true, set flag when value is true; if + * false, set flag when value is false */ +} DDLOptionDef; + +/* + * Array of supported DDL options. + * To add a new option, simply add an entry to this array. + */ +static const DDLOptionDef ddl_option_defs[] = { + {"pretty", PG_DDL_PRETTY_INDENT, true}, + {"defaults", PG_DDL_WITH_DEFAULTS, true}, + {"owner", PG_DDL_NO_OWNER, false}, + {"tablespace", PG_DDL_NO_TABLESPACE, false}, +}; + + /* Standard conversion of a "bool pretty" option to detailed flags */ #define GET_PRETTY_FLAGS(pretty) \ ((pretty) ? (PRETTYFLAG_PAREN | PRETTYFLAG_INDENT | PRETTYFLAG_SCHEMA) \ : PRETTYFLAG_INDENT) +#define GET_DDL_PRETTY_FLAGS(pretty) \ + ((pretty) ? (PRETTYFLAG_PAREN | PRETTYFLAG_INDENT | PRETTYFLAG_SCHEMA) \ + : 0) + /* Default line length for pretty-print wrapping: 0 means wrap always */ #define WRAP_COLUMN_DEFAULT 0 @@ -547,6 +584,11 @@ static void get_json_table_nested_columns(TableFunc *tf, JsonTablePlan *plan, deparse_context *context, bool showimplicit, bool needcomma); +static void get_formatted_string(StringInfo buf, + int prettyFlags, + int nSpaces, + const char *fmt,...) pg_attribute_printf(4, 5); +static char *pg_get_database_ddl_worker(Oid db_oid, uint64 ddl_flags); #define only_marker(rte) ((rte)->inh ? "" : "ONLY ") @@ -13760,3 +13802,358 @@ get_range_partbound_string(List *bound_datums) return buf.data; } + +/* + * get_formatted_string + * + * Return a formatted version of the string. + * + * prettyFlags - Based on prettyFlags the output includes spaces and + * newlines (\n). + * nSpaces - indent with specified number of space characters. + * fmt - printf-style format string used by appendStringInfoVA. + */ +static void +get_formatted_string(StringInfo buf, int prettyFlags, int nSpaces, const char *fmt,...) +{ + va_list args; + + if (prettyFlags & PRETTYFLAG_INDENT) + { + appendStringInfoChar(buf, '\n'); + /* Indent with spaces */ + for (int i = 0; i < nSpaces; i++) + { + appendStringInfoChar(buf, ' '); + } + } + else + appendStringInfoChar(buf, ' '); + + va_start(args, fmt); + appendStringInfoVA(buf, fmt, args); + va_end(args); +} + +/** + * parse_ddl_options - Generic helper to parse variadic name/value options + * fcinfo: The FunctionCallInfo from the calling function + * variadic_start: The argument position where variadic arguments start + * + * Returns: Bitmask of flags based on the parsed options. + * + * Options are passed as name/value pairs. + * For example: pg_get_database_ddl('mydb', 'owner', false, 'pretty', true) + */ +static uint64 +parse_ddl_options(FunctionCallInfo fcinfo, int variadic_start) +{ + uint64 flags = 0; + Datum *args; + bool *nulls; + Oid *types; + int nargs; + int i; + + /* Extract variadic arguments */ + nargs = extract_variadic_args(fcinfo, variadic_start, true, + &args, &types, &nulls); + + /* If no options provided (VARIADIC NULL), return the empty bitmask */ + if (nargs < 0) + return flags; + + /* + * Handle the case where DEFAULT NULL was used and no explicit variadic + * arguments were provided. In this case, we get a single NULL argument. + */ + if (nargs == 1 && nulls[0]) + return flags; + + /* No arguments provided */ + if (nargs == 0) + return flags; + + /* Arguments must come in name/value pairs */ + if (nargs % 2 != 0) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("argument list must have even number of elements"), + errhint("The arguments of %s must consist of alternating keys and values.", + "pg_get_database_ddl()"))); + + for (i = 0; i < nargs; i += 2) + { + char *name; + bool bval; + + /* Key must not be null */ + if (nulls[i]) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("argument %d: key must not be null", i + 1))); + + /* Key must be text type */ + if (types[i] != TEXTOID) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("argument %d: key must be text type", i + 1))); + + name = TextDatumGetCString(args[i]); + + /* Value must not be null */ + if (nulls[i + 1]) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("argument %d: value must not be null for key \"%s\"", + i + 2, name))); + + /* Value must be boolean or text type */ + if (types[i + 1] == BOOLOID) + { + bval = DatumGetBool(args[i + 1]); + } + else if (types[i + 1] == TEXTOID) + { + char *valstr = TextDatumGetCString(args[i + 1]); + + if (!parse_bool(valstr, &bval)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("argument %d: invalid value \"%s\" for key \"%s\"", + i + 2, valstr, name), + errhint("Valid values are: true, false, yes, no, 1, 0, on, off."))); + pfree(valstr); + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("argument %d: value for key \"%s\" must be boolean or text type", + i + 2, name))); + } + + /* + * Look up the option in the ddl_option_defs array and set the + * appropriate flag based on the value. + */ + { + bool found = false; + int j; + + for (j = 0; j < lengthof(ddl_option_defs); j++) + { + const DDLOptionDef *opt = &ddl_option_defs[j]; + + if (pg_strcasecmp(name, opt->name) == 0) + { + /* + * Set the flag if the value matches the set_on_true + * condition: if set_on_true is true, set flag when bval + * is true; if set_on_true is false, set flag when bval is + * false. + */ + if (bval == opt->set_on_true) + flags |= opt->flag; + + found = true; + break; + } + } + + if (!found) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized option: \"%s\"", name))); + } + + pfree(name); + } + + return flags; +} + +/* + * pg_get_database_ddl + * + * Generate a CREATE DATABASE statement for the specified database name or oid. + * + * db_oid - OID/Name of the database for which to generate the DDL. + * options - Variadic name/value pairs to modify the output. + */ +Datum +pg_get_database_ddl(PG_FUNCTION_ARGS) +{ + Oid db_oid = PG_GETARG_OID(0); + uint64 ddl_flags; + char *res; + + /* Parse variadic options starting from argument 1 */ + ddl_flags = parse_ddl_options(fcinfo, 1); + + res = pg_get_database_ddl_worker(db_oid, ddl_flags); + + if (res == NULL) + PG_RETURN_NULL(); + + PG_RETURN_TEXT_P(string_to_text(res)); +} + +static char * +pg_get_database_ddl_worker(Oid db_oid, uint64 ddl_flags) +{ + char *dbowner = NULL; + bool attr_isnull; + Datum dbvalue; + HeapTuple tuple_database; + Form_pg_database dbform; + StringInfoData buf; + AclResult aclresult; + + /* Variables for ddl_options parsing */ + int pretty_flags = 0; + bool is_with_defaults = false; + + /* Set the appropriate flags */ + if (ddl_flags & PG_DDL_PRETTY_INDENT) + pretty_flags = GET_DDL_PRETTY_FLAGS(1); + + is_with_defaults = (ddl_flags & PG_DDL_WITH_DEFAULTS) ? true : false; + + /* + * User must have connect privilege for target database. + */ + aclresult = object_aclcheck(DatabaseRelationId, db_oid, GetUserId(), + ACL_CONNECT); + if (aclresult != ACLCHECK_OK && + !has_privs_of_role(GetUserId(), ROLE_PG_READ_ALL_STATS)) + { + aclcheck_error(aclresult, OBJECT_DATABASE, + get_database_name(db_oid)); + } + + /* Look up the database in pg_database */ + tuple_database = SearchSysCache1(DATABASEOID, ObjectIdGetDatum(db_oid)); + if (!HeapTupleIsValid(tuple_database)) + ereport(ERROR, + errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("database with oid %u does not exist", db_oid)); + + dbform = (Form_pg_database) GETSTRUCT(tuple_database); + + initStringInfo(&buf); + + /* Look up the owner in the system catalog */ + if (OidIsValid(dbform->datdba)) + dbowner = GetUserNameFromId(dbform->datdba, false); + + /* Build the CREATE DATABASE statement */ + appendStringInfo(&buf, "CREATE DATABASE %s", + quote_identifier(dbform->datname.data)); + get_formatted_string(&buf, pretty_flags, 4, "WITH"); + + /* Set the OWNER in the DDL if owner is not omitted */ + if (OidIsValid(dbform->datdba) && !(ddl_flags & PG_DDL_NO_OWNER)) + { + get_formatted_string(&buf, pretty_flags, 8, "OWNER = %s", + quote_identifier(dbowner)); + } + + /* Set the ENCODING in the DDL */ + if (dbform->encoding != 0) + { + /* If is_with_defaults is true, then we skip default encoding check */ + if (is_with_defaults || + (pg_strcasecmp(pg_encoding_to_char(dbform->encoding), + DDL_DEFAULTS.DATABASE.ENCODING) != 0)) + { + get_formatted_string(&buf, pretty_flags, 8, "ENCODING = %s", + quote_literal_cstr( + pg_encoding_to_char(dbform->encoding))); + } + } + + /* Fetch the value of LC_COLLATE */ + dbvalue = SysCacheGetAttr(DATABASEOID, tuple_database, + Anum_pg_database_datcollate, &attr_isnull); + if (!attr_isnull) + get_formatted_string(&buf, pretty_flags, 8, "LC_COLLATE = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + /* Fetch the value of LC_CTYPE */ + dbvalue = SysCacheGetAttr(DATABASEOID, tuple_database, + Anum_pg_database_datctype, &attr_isnull); + if (!attr_isnull) + get_formatted_string(&buf, pretty_flags, 8, "LC_CTYPE = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + /* Fetch the value of LOCALE */ + dbvalue = SysCacheGetAttr(DATABASEOID, tuple_database, + Anum_pg_database_datlocale, &attr_isnull); + if (!attr_isnull && dbform->datlocprovider == COLLPROVIDER_BUILTIN) + get_formatted_string(&buf, pretty_flags, 8, "BUILTIN_LOCALE = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + else if (!attr_isnull && dbform->datlocprovider == COLLPROVIDER_ICU) + get_formatted_string(&buf, pretty_flags, 8, "ICU_LOCALE = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + else if (!attr_isnull) + get_formatted_string(&buf, pretty_flags, 8, "LOCALE = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + + /* Fetch the value of ICU_RULES */ + dbvalue = SysCacheGetAttr(DATABASEOID, tuple_database, + Anum_pg_database_daticurules, &attr_isnull); + if (!attr_isnull && dbform->datlocprovider == COLLPROVIDER_ICU) + get_formatted_string(&buf, pretty_flags, 8, "ICU_RULES = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + + /* Fetch the value of COLLATION_VERSION */ + dbvalue = SysCacheGetAttr(DATABASEOID, tuple_database, + Anum_pg_database_datcollversion, &attr_isnull); + if (!attr_isnull) + get_formatted_string(&buf, pretty_flags, 8, "COLLATION_VERSION = %s", + quote_literal_cstr(TextDatumGetCString(dbvalue))); + + /* Set the appropriate LOCALE_PROVIDER */ + if (dbform->datlocprovider == COLLPROVIDER_BUILTIN) + get_formatted_string(&buf, pretty_flags, 8, "LOCALE_PROVIDER = builtin"); + else if (dbform->datlocprovider == COLLPROVIDER_ICU) + get_formatted_string(&buf, pretty_flags, 8, "LOCALE_PROVIDER = icu"); + else if (is_with_defaults) + get_formatted_string(&buf, pretty_flags, 8, "LOCALE_PROVIDER = libc"); + + /* Set the TABLESPACE in the DDL if tablespace is not omitted */ + if (OidIsValid(dbform->dattablespace) && !(ddl_flags & PG_DDL_NO_TABLESPACE)) + { + /* Get the tablespace name respective to the given tablespace oid */ + char *dbTablespace = get_tablespace_name(dbform->dattablespace); + + /* If it's with defaults, we skip default tablespace check */ + if (is_with_defaults || + (pg_strcasecmp(dbTablespace, DDL_DEFAULTS.DATABASE.TABLESPACE) != 0)) + get_formatted_string(&buf, pretty_flags, 8, "TABLESPACE = %s", + quote_identifier(dbTablespace)); + } + + if (is_with_defaults || + (dbform->datallowconn != DDL_DEFAULTS.DATABASE.ALLOW_CONN)) + { + get_formatted_string(&buf, pretty_flags, 8, "ALLOW_CONNECTIONS = %s", + dbform->datallowconn ? "true" : "false"); + } + + if (is_with_defaults || + (dbform->datconnlimit != DDL_DEFAULTS.DATABASE.CONN_LIMIT)) + { + get_formatted_string(&buf, pretty_flags, 8, "CONNECTION LIMIT = %d", + dbform->datconnlimit); + } + + if (dbform->datistemplate) + get_formatted_string(&buf, pretty_flags, 8, "IS_TEMPLATE = %s", + dbform->datistemplate ? "true" : "false"); + + appendStringInfoChar(&buf, ';'); + + ReleaseSysCache(tuple_database); + + return buf.data; +} diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index dac40992cbc7f..5c43eee32ec33 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -4031,6 +4031,13 @@ proname => 'pg_get_function_sqlbody', provolatile => 's', prorettype => 'text', proargtypes => 'oid', prosrc => 'pg_get_function_sqlbody' }, +{ oid => '9492', descr => 'get CREATE statement for database name and oid', + proname => 'pg_get_database_ddl', provariadic => 'any', proisstrict => 'f', + prorettype => 'text', + proargtypes => 'regdatabase any', + proargmodes => '{i,v}', + proallargtypes => '{regdatabase,any}', + prosrc => 'pg_get_database_ddl' }, { oid => '1686', descr => 'list of SQL keywords', proname => 'pg_get_keywords', procost => '10', prorows => '500', diff --git a/src/include/utils/ddl_defaults.h b/src/include/utils/ddl_defaults.h new file mode 100644 index 0000000000000..d17e843fe0962 --- /dev/null +++ b/src/include/utils/ddl_defaults.h @@ -0,0 +1,39 @@ +/*------------------------------------------------------------------------- + * + * ddl_defaults.h + * Declarations for DDL defaults. + * + * Portions Copyright (c) 1996-2026, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * src/include/utils/ddl_defaults.h + * + *------------------------------------------------------------------------- + */ +#ifndef DDL_DEFAULTS_H +#define DDL_DEFAULTS_H + +#include + +static const struct +{ + struct + { + const char *ENCODING; + const char *TABLESPACE; + int CONN_LIMIT; + bool ALLOW_CONN; + } DATABASE; + + /* Add more object types as needed */ +} DDL_DEFAULTS = { + + .DATABASE = { + .ENCODING = "UTF8", + .TABLESPACE = "pg_default", + .CONN_LIMIT = -1, + .ALLOW_CONN = true, + } +}; + +#endif /* DDL_DEFAULTS_H */ diff --git a/src/test/regress/expected/database.out b/src/test/regress/expected/database.out index 6b879b0f62a75..5b4aa6c054d59 100644 --- a/src/test/regress/expected/database.out +++ b/src/test/regress/expected/database.out @@ -1,3 +1,57 @@ +-- +-- Reconstruct DDL +-- +-- To produce stable regression test output, it's usually necessary to +-- ignore collation and locale related details. This filter +-- functions removes collation and locale related details. +CREATE OR REPLACE FUNCTION ddl_filter(ddl_input TEXT) +RETURNS TEXT AS $$ +DECLARE + cleaned_ddl TEXT; +BEGIN + -- Remove %LOCALE_PROVIDER% placeholders + cleaned_ddl := regexp_replace( + ddl_input, + '\s*\mLOCALE_PROVIDER\M\s*=\s*([''"]?[^''"\s]+[''"]?)', + '', + 'gi' + ); + + -- Remove LC_COLLATE assignments + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*LC_COLLATE\s*=\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + -- Remove LC_CTYPE assignments + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*LC_CTYPE\s*=\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + -- Remove %LOCALE% placeholders + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*\S*LOCALE\S*\s*=?\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + -- Remove %COLLATION% placeholders + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*\S*COLLATION\S*\s*=?\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + RETURN cleaned_ddl; +END; +$$ LANGUAGE plpgsql; CREATE DATABASE regression_tbd ENCODING utf8 LC_COLLATE "C" LC_CTYPE "C" TEMPLATE template0; ALTER DATABASE regression_tbd RENAME TO regression_utf8; @@ -16,6 +70,122 @@ CREATE ROLE regress_datdba_before; CREATE ROLE regress_datdba_after; ALTER DATABASE regression_utf8 OWNER TO regress_datdba_before; REASSIGN OWNED BY regress_datdba_before TO regress_datdba_after; +-- Test pg_get_database_ddl +-- Database doesn't exists +SELECT pg_get_database_ddl('regression_database'); +ERROR: database "regression_database" does not exist +LINE 1: SELECT pg_get_database_ddl('regression_database'); + ^ +-- Test NULL value +SELECT pg_get_database_ddl(NULL); +ERROR: database with oid 0 does not exist +-- Without options +SELECT ddl_filter(pg_get_database_ddl('regression_utf8')); + ddl_filter +------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH OWNER = regress_datdba_after CONNECTION LIMIT = 123; +(1 row) + +-- With No Owner +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', false)); + ddl_filter +-------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH CONNECTION LIMIT = 123; +(1 row) + +-- With No Tablespace +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'defaults', true, 'tablespace', false)); + ddl_filter +-------------------------------------------------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH OWNER = regress_datdba_after ENCODING = 'UTF8' ALLOW_CONNECTIONS = true CONNECTION LIMIT = 123; +(1 row) + +-- With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'defaults', true)); + ddl_filter +-------------------------------------------------------------------------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH OWNER = regress_datdba_after ENCODING = 'UTF8' TABLESPACE = pg_default ALLOW_CONNECTIONS = true CONNECTION LIMIT = 123; +(1 row) + +-- With No Owner, No Tablespace and With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', false, 'tablespace', false, 'defaults', true)); + ddl_filter +--------------------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH ENCODING = 'UTF8' ALLOW_CONNECTIONS = true CONNECTION LIMIT = 123; +(1 row) + +-- With Pretty formatted +\pset format unaligned +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true)); +ddl_filter +CREATE DATABASE regression_utf8 + WITH + OWNER = regress_datdba_after + CONNECTION LIMIT = 123; +(1 row) +-- With No Owner and No Tablespace +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true, 'owner', false, 'tablespace', false)); +ddl_filter +CREATE DATABASE regression_utf8 + WITH + CONNECTION LIMIT = 123; +(1 row) +-- With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true, 'defaults', true)); +ddl_filter +CREATE DATABASE regression_utf8 + WITH + OWNER = regress_datdba_after + ENCODING = 'UTF8' + TABLESPACE = pg_default + ALLOW_CONNECTIONS = true + CONNECTION LIMIT = 123; +(1 row) +-- With No Owner, No Tablespace and With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true, 'owner', false, 'tablespace', false, 'defaults', true)); +ddl_filter +CREATE DATABASE regression_utf8 + WITH + ENCODING = 'UTF8' + ALLOW_CONNECTIONS = true + CONNECTION LIMIT = 123; +(1 row) +-- Test with text values: 'yes', 'no', '1', '0', 'on', 'off' +\pset format aligned +-- Using 'yes' and 'no' +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', 'no', 'defaults', 'yes')); + ddl_filter +--------------------------------------------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH ENCODING = 'UTF8' TABLESPACE = pg_default ALLOW_CONNECTIONS = true CONNECTION LIMIT = 123; +(1 row) + +-- Using '1' and '0' +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', '0', 'tablespace', '0', 'defaults', '1')); + ddl_filter +--------------------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH ENCODING = 'UTF8' ALLOW_CONNECTIONS = true CONNECTION LIMIT = 123; +(1 row) + +-- Using 'on' and 'off' +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', 'off', 'pretty', 'on')); + ddl_filter +--------------------------------- + CREATE DATABASE regression_utf8+ + WITH + + CONNECTION LIMIT = 123; +(1 row) + +-- Mixed boolean and text values +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', false, 'defaults', 'true', 'tablespace', 'no')); + ddl_filter +--------------------------------------------------------------------------------------------------------- + CREATE DATABASE regression_utf8 WITH ENCODING = 'UTF8' ALLOW_CONNECTIONS = true CONNECTION LIMIT = 123; +(1 row) + +-- Test invalid text value (should error) +SELECT pg_get_database_ddl('regression_utf8', 'owner', 'invalid'); +ERROR: argument 2: invalid value "invalid" for key "owner" +HINT: Valid values are: true, false, yes, no, 1, 0, on, off. DROP DATABASE regression_utf8; DROP ROLE regress_datdba_before; DROP ROLE regress_datdba_after; diff --git a/src/test/regress/sql/database.sql b/src/test/regress/sql/database.sql index 4ef361272911e..888d1e5283f96 100644 --- a/src/test/regress/sql/database.sql +++ b/src/test/regress/sql/database.sql @@ -1,3 +1,59 @@ +-- +-- Reconstruct DDL +-- +-- To produce stable regression test output, it's usually necessary to +-- ignore collation and locale related details. This filter +-- functions removes collation and locale related details. + +CREATE OR REPLACE FUNCTION ddl_filter(ddl_input TEXT) +RETURNS TEXT AS $$ +DECLARE + cleaned_ddl TEXT; +BEGIN + -- Remove %LOCALE_PROVIDER% placeholders + cleaned_ddl := regexp_replace( + ddl_input, + '\s*\mLOCALE_PROVIDER\M\s*=\s*([''"]?[^''"\s]+[''"]?)', + '', + 'gi' + ); + + -- Remove LC_COLLATE assignments + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*LC_COLLATE\s*=\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + -- Remove LC_CTYPE assignments + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*LC_CTYPE\s*=\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + -- Remove %LOCALE% placeholders + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*\S*LOCALE\S*\s*=?\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + -- Remove %COLLATION% placeholders + cleaned_ddl := regexp_replace( + cleaned_ddl, + '\s*\S*COLLATION\S*\s*=?\s*([''"])[^''"]*\1', + '', + 'gi' + ); + + RETURN cleaned_ddl; +END; +$$ LANGUAGE plpgsql; + CREATE DATABASE regression_tbd ENCODING utf8 LC_COLLATE "C" LC_CTYPE "C" TEMPLATE template0; ALTER DATABASE regression_tbd RENAME TO regression_utf8; @@ -19,6 +75,58 @@ CREATE ROLE regress_datdba_after; ALTER DATABASE regression_utf8 OWNER TO regress_datdba_before; REASSIGN OWNED BY regress_datdba_before TO regress_datdba_after; +-- Test pg_get_database_ddl +-- Database doesn't exists +SELECT pg_get_database_ddl('regression_database'); + +-- Test NULL value +SELECT pg_get_database_ddl(NULL); + +-- Without options +SELECT ddl_filter(pg_get_database_ddl('regression_utf8')); + +-- With No Owner +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', false)); + +-- With No Tablespace +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'defaults', true, 'tablespace', false)); + +-- With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'defaults', true)); + +-- With No Owner, No Tablespace and With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', false, 'tablespace', false, 'defaults', true)); + +-- With Pretty formatted +\pset format unaligned +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true)); + +-- With No Owner and No Tablespace +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true, 'owner', false, 'tablespace', false)); + +-- With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true, 'defaults', true)); + +-- With No Owner, No Tablespace and With Defaults +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'pretty', true, 'owner', false, 'tablespace', false, 'defaults', true)); + +-- Test with text values: 'yes', 'no', '1', '0', 'on', 'off' +\pset format aligned +-- Using 'yes' and 'no' +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', 'no', 'defaults', 'yes')); + +-- Using '1' and '0' +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', '0', 'tablespace', '0', 'defaults', '1')); + +-- Using 'on' and 'off' +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', 'off', 'pretty', 'on')); + +-- Mixed boolean and text values +SELECT ddl_filter(pg_get_database_ddl('regression_utf8', 'owner', false, 'defaults', 'true', 'tablespace', 'no')); + +-- Test invalid text value (should error) +SELECT pg_get_database_ddl('regression_utf8', 'owner', 'invalid'); + DROP DATABASE regression_utf8; DROP ROLE regress_datdba_before; DROP ROLE regress_datdba_after;