jueves, 14 de septiembre de 2023

Oracle Database 23c Free for Developers ORA-600 [pesldl03_MMap: Errno 1 Errmsg Operation Not Permitted] con compilación NATIVA.

Se me ocurrió hacer un testing del nuevo valor máximo de columnas que podemos tener en una tabla a partir de la versión 23c de base de datos Free for Developers y me encontré con una sorpresa: "Un error ORA-600 interno".

Vamos desde el inicio. Tome una nota publicada por Andy Rivenes sobre los nuevos valores para el parámetro MAX_COLUMNS de la base de datos, el cuál puede ser configurado al valor de EXTENDED. Este parámetro que de facto tiene el valor de STANDARD y cambio al parámetro al valor EXTENDED, me permite habilitar la posibilidad de crear una tabla que tenga 4000 columnas.

Este es el desarrollo de los procedimientos implementados por Andy Rivenes, para la creación de la tabla.

SQL> connect hr/hr@pdb1

Connected.

SQL> create or replace procedure create_table_wide(
table_name IN VARCHAR2,
num_cols IN NUMBER )
is
ct varchar2(32000);
ctsql clob;
cur integer;
begin
ct := 'create table '||table_name||' (c1 number';
dbms_lob.createtemporar 2 y(ctsql, false);
dbms_lob.write(ctsql, length(ct), 1, ct);
ct := '';
dbms_output.put_line(ct);
for colnum in 2 .. num_cols loop
ct := ct || ', c'||colnum||' number';
if mod(colnum, 1000) = 0 then
-- append the chunk we have and reset the temp varchar2
dbms_lob.writeappend(ctsql, length(c 3 t), ct);
ct := '';
end if;
end loop;
append the final chunk
ct := ct || ')';
dbms_lob.writeappend(ctsql, length(ct), ct);
--dbms_output.put_line(ctsql);
--
-- dbms_sql.parse auto executes the DDL, don't need to call dbms_sql.execute
cur := dbms_sql.open_cursor;
dbms_sql.parse(
c => cur,
statement => ctsql,
language_flag => dbms_sql.native );
--
-- cleanup
--
dbms_sql.close_cursor(cur);
dbms_lob.freetemporary(ctsql);
end;


Procedure created.

SQL> create or replace procedure insert_table_wide(
table_name IN VARCHAR2,
num_cols IN NUMBER,
num_rows IN NUMBER DEFAULT 1 )
is
ct clob;
ctsql clob;
cur integer;
rwnum number := 0;
clnum number := 0;
val number := 0;
l_offset pls_integer := 1;
begin
for r_iter in 1 .. num_rows loop
rwnum := rwnum + 1;
ct := 'insert into '|| table_name ||' (c1';
for c_iter in 2 .. num_cols loop
ct := ct || ',c' || to_char(c_iter) ;
end loop;
ct := ct || ') ';
--
ct := ct || 'values (' || to_char(rwnum);
--
for c_iter in 2 .. num_cols loop
clnum := clnum + 1;
val := rwnum + clnum;
ct := ct || ',' || to_char(val) ;
end loop;
--
ct := ct || ')';
--
-- Output the first line to verify
 --
if rwnum = 1 then
loop
exit when l_offset > dbms_lob.getlength(ct);
dbms_output.put_line(dbms_lob.substr(ct, 4000, l_offset));
l_offset := l_offset + 4000;
end loop;
end if;
--
execute immediate ct;
clnum := 0;
end loop;
end;


Procedure created.

SQL> create or replace procedure select_table_wide(
p_table_name IN VARCHAR2,
p_num_cols IN NUMBER,
p_num_rows IN NUMBER )
 is
v_tab_col_num number;
ct clob;
ctsql clob;
cur integer;
rwnum number := 0;
clnum number := 0;
begin
select max(column_id) into v_tab_col_num
from user_tab_columns where table_name = p_table_name;
 --
 for r_iter in 1 .. p_num_rows loop
rwnum := rwnum + 1;
ct := 'select ';
--
for c_iter in 1 .. p_num_cols loop
clnum := floor(dbms_random.value(1,v_tab_col_num));
 if c_iter = 1 then
ct := ct || 'c' || to_char(clnum) ;
else
ct := ct || ',c' || to_char(clnum) ;
end if;
end loop;
--
ct := ct || ' from ' || p_table_name;
dbms_output.put_line(ct);
execute immediate ct;
end loop;
end;


Procedure created.

Una vez creados los procedimientos podemos llamar a los mismos para la creación de tabla.

SQL> exec create_table_wide('TABLA_GIGANTE_COLUMNS',4000);
PL/SQL procedure successfully completed.

Ahora ingresamos 1000 registros ocupando los 4000 campos

SQL> set timing on
SQL> exec insert_table_wide('TABLA_GIGANTE_COLUMNS',4000,1000);
PL/SQL procedure successfully completed.
Elapsed: 00:03:53.23

Verificamos la cantidad de registros ingresados.

SQL> select count(*) from TABLA_GIGANTE_COLUMNS;

COUNT(*)
----------
1000

Deseo hacer una prueba compilando el paquete en modo NATIVO para validar si existe alguna diferencia en el tiempo de ejecución de los casi 4 minutos empleados.

SQL> alter session set plsql_code_type = 'NATIVE';

Session altered.

Elapsed: 00:00:00.00

Al compilar mi procedimiento de forma NATIVA, la compilación concluye con errores.

SQL> alter procedure insert_table_wide compile;
Warning: Procedure altered with compilation errors.

Elapsed: 00:00:01.68

SQL> truncate table TABLA_GIGANTE_COLUMNS;

Table truncated.

Elapsed: 00:00:00.18

El ejecutar el procedimiento, me indica que el objeto no esta válido.

SQL> exec insert_table_wide('TABLA_GIGANTE_COLUMNS',4000,1000);
BEGIN insert_table_wide('TABLA_GIGANTE_COLUMNS',4000,1000); END;
*
ERROR at line 1:
ORA-06550: line 1, column 7:
PLS-00905: object HR.INSERT_TABLE_WIDE is invalid
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored
Elapsed: 00:00:00.01

Recompilo nuevamente el procedimiento.

SQL> alter procedure insert_table_wide compile;
Warning: Procedure altered with compilation errors.

Elapsed: 00:00:01.26

Al verificar los errores, observo un error ORA-00600 interno como producto de la compilación.

SQL> show errors
Errors for PROCEDURE INSERT_TABLE_WIDE:

LINE/COL ERROR
-------- -----------------------------------------------------------------
0/0 ORA-00600: internal error code, arguments: [pesldl03_MMap: errno
1 errmsg Operation not permitted
], [
1 : 1
2 : /PESLD_FREE_7_48bace6300000000
3 : 0100700
4 : 0500002
5 : 0x7
6 : 0x1
], [], [], [], [], [], [], [], [], [], []

SQL> alter session set plsql_code_type = 'INTERPRETED';
Session altered.

Elapsed: 00:00:00.00
SQL> alter procedure insert_table_wide compile;
Procedure altered.
Elapsed: 00:00:00.03

SQL> exit

Disconnected from Oracle Database 23c Free, Release 23.0.0.0.0 - Developer-Release
Version 23.2.0.0.0

[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ df -h
Filesystem Size Used Avail Use% Mounted on
devtmpfs 16G 0 16G 0% /dev
tmpfs 16G 4.0K 16G 1% /dev/shm
tmpfs 16G 233M 16G 2% /run
tmpfs 16G 0 16G 0% /sys/fs/cgroup
/dev/mapper/ocivolume-root 189G 32G 158G 17% /
/dev/sda2 1014M 323M 692M 32% /boot
/dev/sda1 100M 5.1M 95M 6% /boot/efi
/dev/mapper/ocivolume-oled 10G 156M 9.9G 2% /var/oled
tmpfs 3.2G 0 3.2G 0% /run/user/0
tmpfs 3.2G 0 3.2G 0% /run/user/1000
tmpfs 3.2G 0 3.2G 0% /run/user/988


Revisando el error en MOS con la herramienta de errores, me encuentro, que es un bug asociado a la manera en como esta montado el sistema de archivos de swap.

Pequeñísimo detalle, ya que el modo de monta del sistema de archivos, es el valor de facto.

[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ more /etc/fstab

#
# /etc/fstab
# Created by anaconda on Tue Jan 17 19:39:49 2023
#
# Accessible filesystems, by reference, are maintained under '/dev/disk/'.
# See man pages fstab(5), findfs(8), mount(8) and/or blkid(8) for more info.
#
# After editing this file, run 'systemctl daemon-reload' to update systemd
# units generated from this file.
#
/dev/mapper/ocivolume-root / xfs defaults 0 0
UUID=f7cf63bd-4975-44bb-ba99-b81e037be7e1 /boot xfs defaults 0 0
UUID=9814-8B9E /boot/efi vfat defaults,uid=0,gid=0,umask=077,shortname=winnt 0 2
/dev/mapper/ocivolume-oled /var/oled xfs defaults 0 0
tmpfs /dev/shm tmpfs defaults,nodev,nosuid,noexec 0 0
######################################
## ORACLE CLOUD INFRASTRUCTURE CUSTOMERS
##
## If you are adding an iSCSI remote block volume to this file you MUST
## include the '_netdev' mount option or your instance will become
## unavailable after the next reboot.
## SCSI device names are not stable across reboots; please use the device UUID instead of /dev path.
##
## Example:
## UUID="94c5aade-8bb1-4d55-ad0c-388bb8aa716a" /data1 xfs defaults,noatime,_netdev 0 2
##
## More information:
## https://docs.us-phoenix-1.oraclecloud.com/Content/Block/Tasks/connectingtoavolume.htm
/.swapfile none swap sw,comment=cloudconfig 0 0

[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ exit
logout

[opc@oracle-database-23c-free-for-developers-taller-gratuito ~]$ sudo -s /bin/bash

[root@oracle-database-23c-free-for-developers-taller-gratuito opc]# vi /etc/fstab

Editando el archivo de monta de los sistemas de archivos de Linux y agregando comentarios y los cambios sugeridos por la nota Doc ID 1625010.1, nos queda el archivo de la siguiente manera:

[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ more /etc/fstab

#
# /etc/fstab
# Created by anaconda on Tue Jan 17 19:39:49 2023
#
# Accessible filesystems, by reference, are maintained under '/dev/disk/'.
# See man pages fstab(5), findfs(8), mount(8) and/or blkid(8) for more info.
#
# After editing this file, run 'systemctl daemon-reload' to update systemd
# units generated from this file.
#
/dev/mapper/ocivolume-root / xfs defaults 0 0
UUID=f7cf63bd-4975-44bb-ba99-b81e037be7e1 /boot xfs defaults 0 0
UUID=9814-8B9E /boot/efi vfat defaults,uid=0,gid=0,umask=077,shortname=winnt 0 2
/dev/mapper/ocivolume-oled /var/oled xfs defaults 0 0
# BUG: ORA-600 [pesldl03_MMap: Errno 1 Errmsg Operation Not Permitted] (Doc ID 1625010.1)
# SINTOMAS: ORA-00600 occurred when compiling a PLSQL object with plsql_code_type='NATIVE';
# SOLUCION: This requires that /dev/shm is of type tmpfs and is mounted with the following options:
# With rw and exec permissions set on it
# Without noexec or nosuid set on it
# 14 de setiembre de 2023


# RVQ
#tmpfs /dev/shm tmpfs defaults,nodev,nosuid,noexec 0 0
tmpfs /dev/shm tmpfs defaults,nodev 0 0
######################################
## ORACLE CLOUD INFRASTRUCTURE CUSTOMERS
##
## If you are adding an iSCSI remote block volume to this file you MUST
## include the '_netdev' mount option or your instance will become
## unavailable after the next reboot.
## SCSI device names are not stable across reboots; please use the device UUID instead of /dev path.
##
## Example:
## UUID="94c5aade-8bb1-4d55-ad0c-388bb8aa716a" /data1 xfs defaults,noatime,_netdev 0 2
##
## More information:
## https://docs.us-phoenix-1.oraclecloud.com/Content/Block/Tasks/connectingtoavolume.htm
/.swapfile none swap sw,comment=cloudconfig 0 0

Reiniciamos el ambiente del OCI y levantamos los servicios del LISTENER y de la base de datos de arquitectura de contenedor.

[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$

[root@oracle-database-23c-free-for-developers-taller-gratuito opc]#
Using username "opc".
Authenticating with public key "rsa-key-20200507"
Passphrase for key "rsa-key-20200507":

Activate the web console with: systemctl enable --now cockpit.socket

Last login: Fri Sep 15 03:22:19 2023 from 201.198.177.72
[opc@oracle-database-23c-free-for-developers-taller-gratuito ~]$ sudo su - oracle
Last login: Fri Sep 15 03:22:28 GMT 2023 on pts/0
[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ . oraenv
ORACLE_SID = [oracle] ? FREE
The Oracle base has been set to /opt/oracle
[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ lsnrctl start

LSNRCTL for Linux: Version 23.0.0.0.0 - Developer-Release on 15-SEP-2023 04:31:01
Copyright (c) 1991, 2023, Oracle. All rights reserved.
Starting /opt/oracle/product/23c/dbhomeFree/bin/tnslsnr: please wait...
TNSLSNR for Linux: Version 23.0.0.0.0 - Developer-Release

System parameter file is /opt/oracle/product/23c/dbhomeFree/network/admin/listener.ora

Log messages written to /opt/oracle/diag/tnslsnr/oracle-database-23c-free-for-developers-taller-gratuito/listener/alert/log.xml

Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=oracle-database-23c-free-for-developers-taller-gratuito.vcnlandb.vcntestinglab.oraclevcn.com)(PORT=1521)))

Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=oracle-database-23c-free-for-developers-taller-gratuito.vcnlandb.vcntestinglab.oraclevcn.com)(PORT=1521)))

STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for Linux: Version 23.0.0.0.0 - Developer-Release
Start Date 15-SEP-2023 04:31:02
Uptime 0 days 0 hr. 0 min. 0 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Default Service FREE
Listener Parameter File /opt/oracle/product/23c/dbhomeFree/network/admin/listener.ora
Listener Log File /opt/oracle/diag/tnslsnr/oracle-database-23c-free-for-developers-taller-gratuito/listener/alert/log.xml
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=oracle-database-23c-free-for-developers-taller-gratuito.vcnlandb.vcntestinglab.oraclevcn.com)(PORT=1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
The listener supports no services
The command completed successfully

[oracle@oracle-database-23c-free-for-developers-taller-gratuito ~]$ sqlplus /nolog

SQL*Plus: Release 23.0.0.0.0 - Developer-Release on Fri Sep 15 04:31:07 2023
Version 23.2.0.0.0
Copyright (c) 1982, 2023, Oracle. All rights reserved.
SQL> connect / as sysdba
Connected to an idle instance.

SQL> startup
ORACLE instance started.
Total System Global Area 1608409464 bytes
Fixed Size 10043768 bytes
Variable Size 1006632960 bytes
Database Buffers 587202560 bytes
Redo Buffers 4530176 bytes
Database mounted.
Database opened.

SQL> show pdbs

CON_ID CON_NAME OPEN MODE RESTRICTED
---------- ------------------------------ ---------- ----------
2 PDB$SEED READ ONLY NO
3 FREEPDB1 READ WRITE NO

Nos conectamos nuevamente con el usuario de la prueba.

SQL> connect hr/hr@pdb1
Connected.

Seteamos los parámetros a nivel de sesión

SQL> alter session set plsql_code_type = 'NATIVE';
Session altered.

Recompilamos nuestro procedimiento.

SQL> alter procedure insert_table_wide compile;
Procedure altered.

Ahora ya no tenemos error. Para este proceso en específico, no existen mejoras en el modo de empleo de compilación NATIVA.

SQL> set timing on
SQL> exec insert_table_wide('TABLA_GIGANTE_COLUMNS',4000,1000);
PL/SQL procedure successfully completed.

Elapsed: 00:03:36.25

No hay comentarios:

Publicar un comentario

Te agradezco tus comentarios. Te esperamos de vuelta.

Todos los Sábados a las 8:00PM

Optimismo para una vida Mejor

Optimismo para una vida Mejor
Noticias buenas que comentar