1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193
| create or replace function fnc_table_to_mysql ( i_owner in string, i_table_name in string, i_number_default_type in string := 'decimal', i_auto_incretment_column_name in string := '%ID' )
return clob is Result clob; cnt number; data_type varchar2(128); column_str varchar2(4000); pk_str varchar2(4000); table_comments varchar2(4000); is_pk_column number := 0; begin select count(*) into cnt from all_tables where owner = i_owner and table_name = i_table_name; if (cnt = 0) then RAISE_APPLICATION_ERROR(-20000,'can''t found table,please check input!'); else Result := 'CREATE TABLE `' || lower(i_table_name) || '`('; for c in (select a.column_name, a.data_type, a.data_length, a.data_precision, a.data_scale, a.nullable, a.data_default, b.COMMENTS from all_tab_cols a, all_col_comments b where a.owner = i_owner and a.table_name = i_table_name and a.HIDDEN_COLUMN = 'NO' and a.owner = b.OWNER and a.TABLE_NAME = b.TABLE_NAME and a.COLUMN_NAME = b.COLUMN_NAME order by a.column_id) loop if (c.data_type = 'VARCHAR2' or c.data_type = 'NVARCHAR2') then data_type := 'varchar(' || c.data_length || ')'; elsif (c.data_type = 'CHAR' or c.data_type = 'NCHAR') then data_type := 'char(' || c.data_length || ')'; elsif (c.data_type = 'NUMBER') then if (c.column_name like '%ID' and c.data_scale is null) then data_type := 'bigint'; elsif (c.data_precision<3 and c.data_scale = 0) then data_type := 'tinyint'; elsif (c.data_precision<5 and c.data_scale = 0) then data_type := 'smallint'; elsif (c.data_precision<10 and c.data_scale = 0) then data_type := 'int'; elsif (c.data_precision is not null and c.data_scale = 0) then data_type := 'bigint'; elsif (c.data_precision is not null and c.data_scale is not null) then data_type := 'decimal(' || c.data_precision || ',' || c.data_scale || ')'; else data_type := i_number_default_type; end if; elsif (c.data_type = 'DATE' or c.data_type like 'TIMESTAMP%') then data_type := 'datetime'; elsif (c.data_type = 'CLOB' or c.data_type = 'NCLOB' or c.data_type = 'LONG') then data_type := 'text'; elsif (c.data_type = 'BLOB' or c.data_type = 'LONG RAW') then data_type := 'blob'; elsif (c.data_type = 'BINARY_FLOAT') then data_type := 'float'; elsif (c.data_type = 'BINARY_DOUBLE') then data_type := 'double'; else data_type := c.data_type; end if; column_str := ' `' || lower(c.column_name) || '` ' || data_type; if (c.column_name like i_auto_incretment_column_name and (c.data_scale is null or c.data_scale = 0)) then select count(*) into is_pk_column from all_constraints a, all_cons_columns b where a.owner = i_owner and a.table_name = i_table_name and a.constraint_type = 'P' and a.OWNER = b.OWNER and a.TABLE_NAME = b.TABLE_NAME and a.CONSTRAINT_NAME = b.CONSTRAINT_NAME and b.COLUMN_NAME = c.column_name; if is_pk_column > 0 then column_str := column_str || ' AUTO_INCREMENT'; end if; end if; if c.nullable = 'NO' then column_str := column_str || ' NOT NULL'; end if; if (trim(c.data_default) is not null) then column_str := column_str || ' DEFAULT ' || trim(replace(replace(c.data_default, chr(13), ''), chr(10), '')); end if; if c.comments is not null then column_str := column_str || ' COMMENT ''' || c.comments || ''''; end if; Result := Result || chr(10) || column_str || ','; end loop; for c in (select a.constraint_name, wm_concat(a.column_name) pk_columns from (select a.CONSTRAINT_NAME, '`' || b.COLUMN_NAME || '`' column_name from all_constraints a, all_cons_columns b where a.owner = i_owner and a.table_name = i_table_name and a.constraint_type = 'P' and a.OWNER = b.OWNER and a.TABLE_NAME = b.TABLE_NAME and a.CONSTRAINT_NAME = b.CONSTRAINT_NAME order by b.POSITION) a group by a.constraint_name) loop Result := Result || chr(10) || ' PRIMARY KEY (' || lower(c.pk_columns) || '),'; end loop; for c in (select a.constraint_name, wm_concat(a.column_name) uk_columns from (select a.CONSTRAINT_NAME, '`' || b.COLUMN_NAME || '`' column_name from all_constraints a, all_cons_columns b where a.owner = i_owner and a.table_name = i_table_name and a.constraint_type = 'U' and a.OWNER = b.OWNER and a.TABLE_NAME = b.TABLE_NAME and a.CONSTRAINT_NAME = b.CONSTRAINT_NAME order by b.POSITION) a group by a.constraint_name) loop Result := Result || chr(10) || ' UNIQUE KEY `' || lower(c.constraint_name) || '`(' || lower(c.uk_columns) || '),'; end loop; for c in (select a.index_name, wm_concat(a.column_name) ind_columns from (select a.index_name, '`' || a.COLUMN_NAME || '`' column_name from all_ind_columns a where a.table_owner = i_owner and a.TABLE_NAME = i_table_name and not exists (select index_name from all_constraints b where a.TABLE_OWNER = b.owner and a.TABLE_NAME = b.TABLE_NAME and a.INDEX_NAME = b.INDEX_NAME) order by a.COLUMN_POSITION) a group by a.index_name) loop Result := Result || chr(10) || ' KEY `' || lower(c.index_name) || '`(' || lower(c.ind_columns) || '),'; end loop; Result := substr(Result, 1, length(result) - 1) || chr(10) || ')'; select max(a.COMMENTS) into table_comments from all_tab_comments a where owner = i_owner and table_name = i_table_name; if (table_comments is not null) then Result := Result || 'COMMENT=''' || table_comments || ''''; end if; Result := Result || ';'; end if; return(Result); end fnc_table_to_mysql; /
|