# Even if the table field type is CHAR, we use PG_VARCHAR, because PG_CHAR is for a single character, and if we used it, it would truncate the data to one character.
return( $self->error( "An error occured while preparing SQL query to create database: ", $@ ) );
}
$sthor return( $self->error( "An error occured while preparing SQL query to create database: ", $dbh->errstr ) );
# try-catch
$rc= eval
{
$sth->execute;
};
if( $@ )
{
return( $self->error( "An error occured while executing SQL query to create database: ", $@ ) );
}
$rcor return( $self->error( "An error occured while executing SQL query to create database: ", $sth->errstr ) );
# try-catch
eval
{
$sth->finish;
};
if( $@ )
{
return( $self->error( "An unexpected error occurred while trying to finish the SQL query to create database: ", $@, "\n$sql") );
}
my$ref= {};
my@keys= qw( host port login passwd schema opt debug );
@$ref{ @keys} = @$self{ @keys};
$ref->{database} = $name;
$dbh= $self->connect( $ref) || return( $self->error( "I could create the database \"$name\" but oddly enough, I could not connect to it with user \"$ref->{login}\" on host \"$ref->{host}\" with port \"$ref->{port}\".") );
return( $dbh);
}
subcreate_table
{
my$self= shift( @_);
my$name= shift( @_) || return( $self->error( "No table name to create was provided.") );
my$opts= $self->_get_args_as_hash( @_);
return( $self->error( "Table \"$name\" already exists in the database.") ) if( $self->table_exists( $name) );
my$schema= $self->schema;
my$sql= $opts->{sql} || return( $self->error( "No sql query was provided to create table \"$name\".") );
return( $self->error( "There is no table in database $db.") ) if( !@$tables);
my@schema_tables= ();
my$max_field_size= <<SQL;
SELECT MAX(LENGTH(a.attname)) AS "max_length"
FROM pg_class c, pg_attribute a, pg_authid o
WHERE c.relkind IN ('r', 'v', 'm', 'f') AND a.attrelid=c.oid AND c.relowner=o.oid AND o.rolname != 'postgres'
SQL
my$inherited_fields= <<SQL;
SELECT c.relname AS table, a.attname AS field
FROM pg_class c
JOIN pg_inherits i ON c.oid = i.inhrelid
JOIN pg_attribute a ON i.inhparent = a.attrelid
WHERE attnum > 0
SQL
my$table_info= <<SQL;
SELECT c.oid, c.relchecks, c.relkind, c.relhasindex, c.relhasrules, c.relhastriggers, c.relhasoids, '', c.reltablespace, CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, c.relpersistence FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)
WHERE c.relname ~ '^(%s)\$'
SQL
my$field_info= <<SQL;
SELECT a.attname,
pg_catalog.format_type(a.atttypid, a.atttypmod),
(SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
FROM pg_catalog.pg_attrdef d
WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef),
a.attnotnull, a.attnum,
(SELECT c.collname FROM pg_catalog.pg_collation c, pg_catalog.pg_type t
WHERE c.oid = a.attcollation AND t.oid = a.atttypid AND a.attcollation <> t.typcollation) AS attcollation,
NULL AS indexdef,
NULL AS attfdwoptions
FROM pg_catalog.pg_attribute a
WHERE a.attrelid = ? AND a.attnum > 0 AND NOT a.attisdropped
pg_catalog.pg_get_constraintdef(r.oid, true) as condef
FROM pg_catalog.pg_constraint r
WHERE r.conrelid = ? AND r.contype = 'f' ORDER BY 1
SQL
my$inheritance= "SELECT c.oid::pg_catalog.regclass FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i WHERE c.oid=i.inhparent AND i.inhrelid = ? ORDER BY inhseqno";
my$get_tbl_comment= "SELECT description FROM pg_description WHERE (SELECT relname FROM pg_class WHERE oid=objoid) = ? and objsubid = 0";
my$get_field_comment= "SELECT d.description, a.attname FROM pg_description d, pg_attribute a WHERE (SELECT relname FROM pg_class WHERE oid=d.objoid) = ? AND a.attnum=d.objsubid AND a.attrelid=d.objoid AND d.objsubid > 0";
# Get the max size of the fields to properly format the schema
,CASE c.relkind WHEN 'r' THEN 'table' WHEN 'v' THEN 'view' WHEN 'm' THEN 'materialized view' WHEN 's' THEN 'special' WHEN 'f' THEN 'foreign table' WHEN 'p' THEN 'table' END AS "type"
,pg_catalog.pg_get_userbyid(c.relowner) AS "owner"
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname = ANY(regexp_split_to_array((SELECT REPLACE(setting,'"$user"', (SELECT CURRENT_USER)) FROM pg_catalog.pg_settings WHERE name = 'search_path'), '\,\s*')) AND c.relname = ?
# The original query was fetched by connecting to Postgres with psql -E and executing the command \z
# This revised query will fetch only tables, views, materialised view and foreign tables, but will avoid the mysterious view called sequence_setvals
# my $query = <<SQL;
# SELECT n.nspname as "schema",
# c.relname as "name"
# FROM pg_catalog.pg_class c
# LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
# WHERE c.relkind IN ('r', 'v', 'm', 'f')
# AND n.nspname !~ '^pg_' AND pg_catalog.pg_table_is_visible(c.oid) AND c.relname != 'sequence_setvals'
# ORDER BY c.oid
# SQL
# AND n.nspname OPERATOR(pg_catalog.~) '^((auth|public))$'
my$query= <<'EOT';
SELECT
n.nspname as "schema"
,c.relname as "name"
,CASE c.relkind WHEN 'r' THEN 'table' WHEN 'v' THEN 'view' WHEN 'm' THEN 'materialized view' WHEN 's' THEN 'special' WHEN 'f' THEN 'foreign table' WHEN 'p' THEN 'table' END as "type"
,pg_catalog.pg_get_userbyid(c.relowner) as "owner"
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
print( STDERR "DESTROY database handle ($self) [$self->{query}]\ncalled within sub '$sub' ($sub2) from package '$pack' ($pack2) in file '$file' ($file2) at line '$line' ($line2).\n");
}
$self->disconnect();
}
my$locks= $self->{_locks};
if( $locks&& $self->_is_array( $locks) )
{
foreachmy$name( @$locks)
{
$self->unlock( $name);
}
}
}
# NOTE: END
END
{
# foreach my $dbh ( @DBH )
# {
# $dbh->disconnect();
# }
};
1;
# NOTE: POD
__END__
=encoding utf8
=head1 NAME
DB::Object::Postgres - SQL API
=head1 SYNOPSIS
use DB::Object::Postgres;
my $dbh = DB::Object::Postgres->connect({
driver => 'Pg',
conf_file => 'db-settings.json',
database => 'webstore',
host => 'localhost',
login => 'store-admin',
schema => 'auth',
debug => 3,
}) || bailout( "Unable to connect to sql server on host localhost: ", DB::Object->error );
# Legacy regular query
my $sth = $dbh->prepare( "SELECT login,name FROM login WHERE login='jack'" ) ||
# mandatory, can be a constraint name or a field name or array of fields
target => 'on constraint idx_prefs_unique',
action => 'update',
# where => '',
# which fields to update. It can also be more specific by providing a hash ref like fields => { val => 'plop' }
fields => [qw( val )],
});
# would become:
insert into login (..) values(...) on conflict on constraint idx_prefs_unique do update set val = EXCLUDED.val;
# Get the last used insert id
my $id = $dbh->last_insert_id();
$cust->where( email => 'john@example.org' );
$cust->order( 'last_name' );
$cust->having( email => qr/\@example/ );
$cust->limit( 10 );
my $cust_sth_sel = $cust->select || die( "An error occurred while creating a query to select data frm table customers: " . $cust->error );
# Becomes:
# SELECT id, first_name, last_name, email, created, modified, active, created::ABSTIME::INTEGER AS created_unixtime, modified::ABSTIME::INTEGER AS modified_unixtime, CONCAT(first_name, ' ', last_name) AS name FROM customers WHERE email='john\@example.org' HAVING email ~ '\@example' ORDER BY last_name LIMIT 10
$cust->reset;
$cust->where( email => 'john@example.org' );
my $cust_sth_upd = $cust->update( active => 0 )
# Would become:
# UPDATE ONLY customers SET active='0' WHERE email='john\@example.org'
# Lets' dump the result of our query
# First to STDERR
$login->where( "login='jack'" );
$login->select->dump();
# Now dump the result to a file
$login->select->dump( "my_file.txt" );
=head1 VERSION
v1.2.2
=head1 DESCRIPTION
This package inherits from L<DB::Object>, so any method not here, but there you can use.
L<DB::Object::Postgres> is a SQL API much alike L<DBD::Pg>.
So why use a private module instead of using that great L<DBD::Pg> package?
At first, I started to inherit from C<DBI> to conform to C<perlmod> perl
manual page and to general perl coding guidlines. It became very quickly a
real hassle. Barely impossible to inherit, difficulty to handle error, too
much dependent from an API that change its behaviour with new versions.
In short, I wanted a better, more accurate control over the SQL connection.
So, L<DB::Object::Postgres> acts as a convenient, modifiable wrapper that provide the
programmer with an intuitive, user-friendly and hassle free interface.
=head1 CONSTRUCTOR
=head2 new
Create a new instance of L<DB::Object::Postgres>. Nothing much to say.
=head2 connect
Provided with a database, login, password, server, driver, and this will attempt a database connection.
Create a new instance of L<DB::Object::Postgres>, but also attempts a connection to SQL server.
You can specify the following parameters:
=over 4
=item * C<cache_connections>
See L<DB::Object/connect> for more information
=item * C<database>
The database name you wish to connect to
=item * C<login>
The login used to access that database
=item * C<password>
The password that goes along
=item * C<server>
The server, that is hostname of the machine serving a SQL server.
=item * C<driver>
The driver you want to use. It needs to be of the same type than the server you want to connect to. If you are connecting to a MySQL server, you would use C<mysql>, if you would connecto to an Oracle server, you would use C<oracle>.
You need to make sure that those driver are properly installed in the system before attempting to connect.
To install the required driver, you could start with the command line:
perl -MCPAN -e shell
which will provide you a special shell to install modules in a convenient way.
=back
=head1 METHODS
=head2 attribute
Sets or gets one more pg attributes.
Valid attributes are:
=over 4
=item * C<ActiveKids>
Is read-only.
=item * C<AutoCommit>
Can be changed.
=item * C<AutoInactiveDestroy>
Can be changed.
=item * C<CachedKids>
Is read-only.
=item * C<ChildHandles>
Is read-only.
=item * C<ChopBlanks>
Can be changed.
=item * C<CursorName>
Is read-only.
=item * C<Driver>
Is read-only.
=item * C<ErrCount>
Can be changed.
=item * C<Executed>
Is read-only.
=item * C<FetchHashKeyName>
Can be changed.
=item * C<HandleError>
Can be changed.
=item * C<HandleSetErr>
Can be changed.
=item * C<InactiveDestroy>
Can be changed.
=item * C<Kids>
Is read-only.
=item * C<NAME>
Is read-only.
=item * C<NULLABLE>
Is read-only.
=item * C<NUM_OF_FIELDS>
Is read-only.
=item * C<NUM_OF_PARAMS>
Is read-only.
=item * C<Name>
Is read-only.
=item * C<PRECISION>
Is read-only.
=item * C<PrintError>
Can be changed.
=item * C<PrintWarn>
Can be changed.
=item * C<Profile>
Can be changed.
=item * C<RaiseError>
Can be changed.
=item * C<ReadOnly>
Can be changed.
Specifies if the current database connection should be in read-only mode or not.
=item * C<RowCacheSize>
Is read-only.
=item * C<RowsInCache>
Is read-only.
=item * C<SCALE>
Is read-only.
=item * C<ShowErrorStatement>
Can be changed.
=item * C<Statement>
Is read-only.
=item * C<TYPE>
Is read-only.
=item * C<Taint>
Can be changed.
=item * C<TaintIn>
Can be changed.
=item * C<TaintOut>
Can be changed.
=item * C<TraceLevel>
Can be changed.
=item * C<Type>
Can be changed.
=item * C<Username>
Is read-only.
=item * C<Warn>
Can be changed.
=item * C<pg_INV_READ>
Is read-only.
=item * C<pg_INV_WRITE>
Is read-only.
=item * C<pg_async_status>
Is read-only.
=item * C<pg_bool_tf>
Can be changed.
If true, boolean values will be returned as the characters 't' and 'f' instead of '1' and '0'.
=item * C<pg_db>
Is read-only.
=item * C<pg_default_port>
Is read-only.
=item * C<pg_enable_utf8>
Can be changed.
=item * C<pg_errorlevel>
Can be changed.
Valid entries are 0, 1 and 2
=item * C<pg_expand_array>
Can be changed.
=item * C<pg_host>
Is read-only.
=item * C<pg_lib_version>
Is read-only.
=item * C<pg_options>
Is read-only.
=item * C<pg_pass>
Is read-only.
=item * C<pg_pid>
Is read-only.
=item * C<pg_placeholder_dollaronly>
Can be changed.
When true, question marks inside of statements are not treated as placeholders, e.g. geometric operators
=item * C<pg_placeholder_nocolons>
Can be changed.
When true, colons inside of statements are not treated as placeholders
=item * C<pg_port>
Is read-only.
=item * C<pg_prepare_now>
Can be changed.
=item * C<pg_protocol>
Is read-only.
=item * C<pg_server_prepare>
Can be changed.
Indicates if L<DBD::Pg> should attempt to use server-side prepared statements. On by default
=item * C<pg_server_version>
Is read-only.
=item * C<pg_socket>
Is read-only.
=item * C<pg_standard_conforming_strings>
Is read-only.
=item * C<pg_switch_prepared>
Can be changed.
=item * C<pg_user>
Is read-only.
=back
=head2 begin_work
Mark the beginning of a transaction.
Any arguments provided are passed along to L<DBD::Pg/begin_work>
=head2 commit
Make any change to the database irreversible.
This must be used only after having called L</begin_work>
Any arguments provided are passed along to L<DBD::Pg/commit>
=head2 connect
Same as L<DB::Object/connect>, only specific to PostgreSQL.
See L</_connection_params2hash>
=head2 create_db
Provided with a database name and some optional parameters and this will prepare and execute the query to create the database.
Upon failure, this will return an error, and upon success, this will connect to the newly created database and return the database handler.
Possible options are:
=over 4
=item * C<allowcon>
Sets the C<ALLOW_CONNECTIONS> attribute
"If false then no one can connect to this database. The default is true, allowing connections."
=item * C<connlimit>
Sets the C<CONNECTION LIMIT> attribute
"How many concurrent connections can be made to this database. -1 (the default) means no limit."
=item * C<encoding>
Sets the C<ENCODING> attribute
"Character set encoding to use in the new database."
=item * C<lc_collate>
Sets the C<LC_COLLATE> attribute
"Collation order (LC_COLLATE) to use in the new database."
=item * C<lc_ctype>
Sets the C<LC_CTYPE> attribute
"Character classification (LC_CTYPE) to use in the new database."
=item * C<istemplate>
Sets the C<IS_TEMPLATE> attribute
"If true, then this database can be cloned by any user with CREATEDB privileges; if false (the default), then only superusers or the owner of the database can clone it."
=item * C<owner>
Sets the C<OWNER> attribute
"The role name of the user who will own the new database"
=item * C<tablespace>
Sets the C<TABLESPACE> attribute
"The name of the tablespace that will be associated with the new database"
=item * C<template>
Sets the C<TEMPLATE> attribute
"The name of the template from which to create the new database"
If the lock failed (NULL), it returns undef(), otherwise, it returns the return value.
=head2 make_schema
Provided with a database name and this will create its schema.
In list context, it returns an array of schema lines, and in scalar context, it returns the schema as a string.
=head2 on_conflict
See L<DB::Object::Postgres::Tables/on_conflict>
=head2 for Pod::Coverage pg_notifies
=head2 pg_ping
Calls L<DBD::Pg/pg_ping>
=head2 query_object
Set or gets the PostgreSQL query object (L<DB::Object::Postgres::Query>) used to process and format queries.
=head2 quote
Provided with a data and some data type, and this will possibly put surrounding single quotes and return the result.
=head2 release
$dbh->release( 'mysavepoint' );
Calls L<DBD::pg_release> passing it through whatever arguments were provided.
See also L<savepoint|/savepoint> and L<rollback_to|/rollback_to>
=head2 replace
Replace queries are not supported in PostgreSQL
=head2 returning
A convenient wrapper to L<DB::Object::Postgres::Query/returning>
=head2 rollback
Will roll back any changes made to the database since the last transaction point marked with L</begin_work>
=head2 rollback_to
$dbh->rollback_to( 'mysavepoint' );
To be used inside a transaction. This will rollback any change up to the specified savepoint.
Will call L<DBD::Pg/pg_rollback_to> and passing it through whatever arguments were provided.
See also L<release|/release> and L<savepoint|/savepoint>
=head2 savepoint
$dbh->savepoint( 'mysavepoint' );
To be used inside a transaction. This creates a savepoint, which you can L<rollback to|/rollback_to> or L<release/release>
Will call L<DBD::Pg/pg_savepoint> and passing it through whatever arguments were provided.
See also L<rollback_to|/rollback_to> and L<release|/release>
=head2 schema
Sets or gets the database schema.
It returns the value as a L<Module:Generic::Scalar> object
=head2 search_path
If a search path is provided, this will issue the query to set it using C<SET search_path = $search_path> whatever C<$search_path> is. It returns the returned value from L<DBD::Pg/execute>
If no arguments is provided, this will issue the query C<SHOW search_path> to retrieve the current search path.
It returns an array object (L<Module::Generic::Array>) containing the search paths found.
This returns the database handler property C<pg_socket>
=head2 table_exists
Provided with a table name and this will check if the table exists.
It accepts the following options:
=over 4
=item * C<anywhere>
If true, this will search anywhere.
=item * C<schema>
A database schema.
=back
=head2 table_info
Provided with a table name and some optional parameters and this will retrieve the table information.
It returns an array reference of tables information found if no schema was provided or if C<anywhere> is true.
If a schema was provided, and the table found it returns an hash reference for that table.
Otherwise, if nothing can be found, it returns an empty array reference.
Optional parameters are:
=over 4
=item * C<anywhere>
If true, it will search anywhere.
=item * C<schema>
A database schema.
=back
Information retrieved are:
=over 4
=item * C<name>
The table name
=item * C<schema>
Database schema, if any.
=item * C<type>
The object type, which may be one of: C<table>, C<view>, C<materialized view>, C<special>, C<foreign table>
=back
=head2 tables_info
Provided with a database name and this returns all the tables information.
Information retrieved from the PostgreSQL system tables for every table found in the given database are:
=over 4
=item * C<name>
The object name
=item * C<owner>
The object owner (role)
=item * C<schema>
Database schema, if any.
=item * C<type>
The object type, which may be one of: C<table>, C<view>, C<materialized view>, C<special>, C<foreign table>
=back
=head2 trace
Calls L<DBD::Pg/trace> passing through whatever arguments were provided.
=head2 trace_msg
Calls L<DBD::Pg/trace_msg> and pass it whatever arguments were provided.
=head2 unlock
Unlock does not work with PostgreSQL
=head2 table_info
It returns an array reference of hash reference containing information about each table column.
=head2 variables
Variables are currently unsupported in Postgres
=head2 version
Returns the PostgreSQL database server version.
This information is cached per object for efficiency.
=head2 _check_connect_param
Given some parameters hash and this will return a proper hash reference of parameters suitable for connection parameters.
This will call L</_connection_parameters> to get the valid parameters and L</_connection_options> to get valid connection options based on the arguments provided.
It returns the hash reference of connection parameters.
=head2 _check_default_option
Based on optional arguments and this will enable default options for the parameters provided.
Currently this only check C<client_encoding> and set the default to C<utf8>
It returns an hash reference of those parameters.
=head2 _connection_options
Based on an hash reference of parameters and this will call L<DB::Object/_connection_options> and return a new hash reference of keys starting with C<pg_>
=head2 _connection_parameters
Based on an hash reference of parameters, this will return an array reference of core properties plus additional PostgreSQL specific properties that start with C<pg_>
Based on an hash reference of parameters and this will transcode any datetime column into a L<DateTime> object.
It returns the I<data> hash reference
Possible parameters are:
=over 4
=item * C<data>
An hash reference of data typically returned from a L<DBD::Pg/fetchrow_hashref>
=item * C<statement>
This is the statement from which to check for columns
=back
=head2 _convert_json2hash
Based on an hash reference of parameters, and this will check for the I<data> for any json column and if found, it will transcode the json to hash reference.
It returns the I<data> hash reference
Possible parameters are:
=over 4
=item * C<data>
An hash reference of data typically returned from a L<DBD::Pg/fetchrow_hashref>
=item * C<statement>
This is the statement from which to check for columns
=back
=head2 _dsn
This returns a properly formatted C<dsn> as a string.
=head1 SEE ALSO
L<DBI>, L<Apache::DBI>
=head1 AUTHOR
Jacques Deguest E<lt>F<jack@deguest.jp>E<gt>
=head1 COPYRIGHT & LICENSE
Copyright (c) 2019-2021 DEGUEST Pte. Ltd.
You can use, copy, modify and redistribute this package and associated
files under the same terms as Perl itself.
=cut
Keyboard Shortcuts
Global
s
Focus search bar
?
Bring up this help dialog
GitHub
gp
Go to pull requests
gi
go to github issues (only if github is preferred repository)