Hi,
I'm running 32-bit version of SQL Developer v. 3.2.20.09 build 09.87, and I used the built in context menu (right-clicking from the schema browser) today to copy a table. However, none of the comments copied. When I dug into the PL/SQL that the menu-item is using, I realized that it fails because it doesn't handle single quotes within the comment string.
For example, I have a table named WE_ENROLL_SNAPSHOT that I wanted to copy as WE_ENROLL_SNAPSHOT_V1 (within same schema name)
1. I right-clicked on the object in the schema browser and selected Table > Copy...
2. In the pop-up Copy window, I entered the new table name "WE_ENROLL_SNAPSHOT_V1" and ticked the box for "Include Data" option. -- The PL/SQL that the menu-command is using is in the "SQL" tab of this window. This is what I extracted later for testing the issue after the comments did not copy.
Result: Table and data copied as-expected, but no column or table comments existed.
I examined the PL/SQL block that the pop-up window issued, and saw this:
declare
l_sql varchar2(32767);
c_tab_comment varchar2(32767);
procedure run(p_sql varchar2) as
begin
execute immediate p_sql;
end;
begin
run('create table "BI_ETL".WE_ENROLL_SNAPSHOT_V1 as select * from "BI_ETL"."WE_ENROLL_SNAPSHOT" where '||11||' = 11');
select comments into c_tab_comment from sys.all_TAB_comments where owner = 'BI_ETL' and table_name = 'WE_ENROLL_SNAPSHOT' and comments is not null;
run('comment on table BI_ETL.WE_ENROLL_SNAPSHOT_V1 is '||''''||c_tab_comment||'''');
for tc in (select column_name from sys.all_tab_cols where owner = 'BI_ETL' and table_name = 'WE_ENROLL_SNAPSHOT')
loop
for c in (select comments from sys.all_col_comments where owner = 'BI_ETL' and table_name = 'WE_ENROLL_SNAPSHOT' and column_name=tc.column_name)
loop
run ('comment on column BI_ETL.WE_ENROLL_SNAPSHOT_V1.'||tc.column_name||' is '||''''||c.comments||'''');
end loop;
end loop;
EXCEPTION
WHEN OTHERS THEN NULL;
end;
The string of the table comment on WE_ENROLL_SNAPSHOT is this:
WBIG table of frozen, point-in-time snapshots of Enrolled Students by Category/term/pidm. "Category" is historically, and commonly, our CENSUS snapshot; but, can also describe other frequencies, or categorizations, such as: End-of-Term (EOT), etc. Note: Prior to this table existing, Census-snapshots were stored in SATURN.SNAPREG_ALL. All FALL and SPRING term records prior-to-and-including Spring 2013 ('201230') have been migrated into this table -- EXCEPT a few select prior to Fall 2004 (200410) records where there are duplicates on term/pidm. NO Summer snapshots existed in SNAPREG_ALL, but were queried and stored retroactively (including terms prior to Spring 2013) for the purpose of future on-going year-over-year analysis and comparison.
Note the single quotes in the comment: ... ('201230')
So, in the above PL/SQL line 11 grabs this string into "c_tab_comment", but then line 12 fails because of the single quotes. It doesn't know how to end the string because the single quotes in the string are not "escaped", and this messes up the concatenation on line 12. (So, then no other column comments are created either because the block throws an error, and goes to line 22 for the exception and exits.)
When I modify the above PL/SQL as my own anonymous block like this, it is successful:
declare
c_tab_comment VARCHAR2(32767);
begin
SELECT REPLACE(comments,chr(39),chr(39)||chr(39)) INTO c_tab_comment FROM sys.all_TAB_comments WHERE owner = 'BI_ETL' AND table_name = 'WE_ENROLL_SNAPSHOT' AND comments IS NOT NULL;
EXECUTE IMMEDIATE 'comment on table BI_ETL.WE_ENROLL_SNAPSHOT_V1 is '''||c_tab_comment||'''';
for tc in (select column_name from sys.all_tab_cols where owner = 'BI_ETL' and table_name = 'WE_ENROLL_SNAPSHOT')
loop
for c in (select REPLACE(comments,chr(39),chr(39)||chr(39)) comments from sys.all_col_comments where owner = 'BI_ETL' and table_name = 'WE_ENROLL_SNAPSHOT' and column_name=tc.column_name)
loop
EXECUTE IMMEDIATE 'comment on column BI_ETL.WE_ENROLL_SNAPSHOT_V1.'||tc.column_name||' is '||''''||c.comments||'''';
end loop;
end loop;
EXCEPTION
WHEN OTHERS THEN NULL;
end;
On lines 4 and 8 I wrapped the "comments" from sys.all_tab_comments and sys.all_col_comments with a replace command finding every chr(39) and replacing with chr(39)||chr(39). (On line 8 I also had to alias the wrapped column as "comments" so line 10 would succeed.)
Is this an issue with SQL Developer? Is there any chance that the menu-items can handle single quotes in comment strings? ... And, of course this makes me wonder which other context menu commands in the tool might have a similar issue.
Thoughts?
thanks//jacob