๋ณธ๋ฌธ ๋ฐ”๋กœ๊ฐ€๊ธฐ
ORACLE/ADMIN

[Oracle] ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค ์ƒ์„ฑ SID ์ถ”๊ฐ€ CREATE DATABASE ๋ช…๋ น์–ด ์‚ฌ์šฉ

by ๐ŸŒปโ™š 2020. 7. 9.

OS : Red Hat Enterprise Linux Server 6.10
DB : Oracle 11.2.0.1

Oracle Database์—์„œ DBCA๋ฅผ ์ด์šฉํ•˜์ง€ ์•Š๊ณ  ์ˆ˜๋™์œผ๋กœ CREATE DATABASE ๋ช…๋ น์–ด๋ฅผ ์‚ฌ์šฉํ•ด์„œ ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค๋ฅผ ์ƒ์„ฑํ•˜๋Š” ์‹ค์Šต์„ ํ•˜๋ ค๊ณ ํ•ฉ๋‹ˆ๋‹ค. ์ƒˆ๋กœ์šด ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค๋ฅผ ์ƒ์„ฑํ•˜๋ฉด ์ƒˆ๋กœ์šด SID๋ฅผ ์ง€์ •ํ•˜์—ฌ ์—…๋ฌด๋ฅผ ๋‚˜๋ˆ  ๊ด€๋ฆฌํ•  ์ˆ˜ ์žˆ์Šต๋‹ˆ๋‹ค.

 

1. ํ™˜๊ฒฝ๋ณ€์ˆ˜ ์ˆ˜์ • oraenv ์‚ฌ์šฉ

Oracle ์„ค์น˜ํ•˜๋Š” ๊ณผ์ •์—์„œ ORACLE_SID, ORACLE_HOME ํ™˜๊ฒฝ๋ณ€์ˆ˜๋ฅผ ์„ค์ •ํ•˜๋Š” ์ž‘์—…์„ ์ง„ํ–‰ํ–ˆ์„ ๊ฒƒ ์ž…๋‹ˆ๋‹ค. Oracle Instance๋ฅผ ๊ธฐ๋™ํ• ๋•Œ ์–ด๋–ค ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค๋กœ ์—ฐ๊ฒฐํ•ด์•ผํ•˜๋Š”์ง€ ์•Œ๋ ค์ฃผ๋Š” ๋ณ€์ˆ˜๊ฐ’์ด๊ธฐ ๋•Œ๋ฌธ์— ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค๋ฅผ ํ•˜๋‚˜ ๋” ์ƒ์„ฑํ•œ๋‹ค๋ฉด ๊ฐ„๋‹จํ•˜๊ฒŒ ์ด ๋‘๊ฐ€์ง€ ํ™˜๊ฒฝ๋ณ€์ˆ˜๋ฅผ ์ˆ˜์ •ํ•˜๊ณ  ๋‹ค์‹œ Instance๋ฅผ ๊ธฐ๋™ํ•œ๋‹ค๋ฉด ๋ณ€๊ฒฝ๋œ ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค์˜ ์ •๋ณด๋กœ ์ ‘์†์ด ๊ฐ€๋Šฅํ•ฉ๋‹ˆ๋‹ค.

 

ํ•˜์ง€๋งŒ ๋ฒˆ๊ฐˆ์•„๊ฐ€๋ฉด ์—ฌ๋Ÿฌ ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค์— ์ ‘์†์„ ๋ฐ”๊ฟ”๊ฐ€๋ฉด์„œ ํ•ด์•ผํ• ๋•Œ ํ™˜๊ฒฝ๋ณ€์ˆ˜๋ฅผ ์žฌ์ •์˜ํ•ด์ฃผ๋Š” ์ž‘์—…์ด ๋ฒˆ๊ฑฐ๋กญ๋‹ค. ์ด ๋ฌธ์ œ๋ฅผ ํ•ด๊ฒฐํ•˜๊ธฐ ์œ„ํ•ด Oracle์—์„œ ์ œ๊ณตํ•ด์ฃผ๋Š” oraenv๋ฅผ ์‚ฌ์šฉํ•˜๋ฉด ์ข€ ๋” ํŽธํ•œ ๋ฐฉ๋ฒ•์œผ๋กœ ํ™˜๊ฒฝ๋ณ€์ˆ˜์˜ ๋ณ€๊ฒฝ์ž‘์—…์„ ํ•  ์ˆ˜ ์žˆ์Šต๋‹ˆ๋‹ค.

[oracle@host ~]$ . oraenv
ORACLE_SID = [orcl] ? prod
ORACLE_HOME = [/opt/oracle] ? /opt/oracle/app/product/11.2.0/dbhome_1
The Oracle base for ORACLE_HOME=/opt/oracle/app/product/11.2.0/dbhome_1 is /opt/oracle/app
[oracle@6host ~]$ echo $ORACLE_SID
prod
[oracle@host ~]$ echo $ORACLE_HOME
/opt/oracle/app/product/11.2.0/dbhome_1

 

oratab ํŒŒ์ผ ์ˆ˜์ •

oraenv๋ฅผ ์‚ฌ์šฉํ•ด์„œ ํ™˜๊ฒฝ๋ณ€์ˆ˜ ๋ณ€๊ฒฝ์ž‘์—…์ด ๊ฐ€๋Šฅํ•˜์ง€๋งŒ, ORACLE_HOME ๊ฒฝ๋กœ๊ฐ™์€ ๊ฒฝ์šฐ๋Š” ์˜คํƒ€๋กœ ์ธํ•ด ์ž˜๋ชป ํƒ€์ดํ•„ํ•  ์ˆ˜ ์žˆ์„ ๋ฟ๋”๋Ÿฌ ์ด๊ฒƒ๋„ ๊ท€์ฐฎ์€ ์ž‘์—…์ด๋‹ค. ๊ทธ๋ž˜์„œ /etc/oratab ํŒŒ์ผ์„ ์—ด์–ด ๋ณ€์ˆ˜๋ฅผ ์ •์˜ํ•˜๋“ฏ ๋ฏธ๋ฆฌ ๋ณ€๊ฒฝํ•  ์ •๋ณด๋ฅผ ์ €์žฅํ•ด๋‘๋ฉด ๋” ๊ฐ„ํŽธํ•˜๊ฒŒ ํ™˜๊ฒฝ๋ณ€์ˆ˜ ์ˆ˜์ •์ด ๊ฐ€๋Šฅํ•ฉ๋‹ˆ๋‹ค.

[oracle@host ~]$ vi /etc/oratab
# This file is used by ORACLE utilities.  It is created by root.sh
# and updated by the Database Configuration Assistant when creating
# a database.

# A colon, ':', is used as the field terminator.  A new line terminates
# the entry.  Lines beginning with a pound sign, '#', are comments.
#
# Entries are of the form:
#   $ORACLE_SID:$ORACLE_HOME:<N|Y>:
#
# The first and second fields are the system identifier and home
# directory of the database respectively.  The third filed indicates
# to the dbstart utility that the database should , "Y", or should not,
# "N", be brought up at system boot time.
#
# Multiple entries with the same $ORACLE_SID are not allowed.
#
#
orcl:/opt/oracle/app/product/11.2.0/dbhome_1:N

 

orcl์ด๋ผ๋Š” SID๋ฅผ ์‚ฌ์šฉํ•˜๋Š” ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค๋Š” ์‚ฌ์ „์— dbca๋ฅผ ์ด์šฉํ•ด์„œ ์ƒ์„ฑํ–ˆ์Šต๋‹ˆ๋‹ค. ORACLE_SID=prod๋กœ ์ถ”๊ฐ€ ์ƒ์„ฑํ•  ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค์˜ ์ •๋ณด๋ฅผ ์œ„์™€ ๊ฐ™์ด ํ˜•์‹์— ๋งž๊ฒŒ ์ถ”๊ฐ€ํ•˜๊ฒ ์Šต๋‹ˆ๋‹ค.

orcl:/opt/oracle/app/product/11.2.0/dbhome_1:N
prod:/opt/oracle/app/product/11.2.0/dbhome_1:N

 

oratab ํŒŒ์ผ์„ ์ˆ˜์ •ํ•˜๊ณ  ๋‹ค์‹œ oraenv ๋ช…๋ น์„ ์‚ฌ์šฉํ•ด์„œ prod๋กœ ๋ณ€๊ฒฝํ•ด๋ณด๊ฒ ์Šต๋‹ˆ๋‹ค.

[oracle@host ~]$ . oraenv 
ORACLE_SID = [prod] ? prod
The Oracle base for ORACLE_HOME=/opt/oracle/app/product/11.2.0/dbhome_1 is /opt/oracle/app

ORACLE_SID ๊ฐ’๋งŒ ์ž…๋ ฅํ–ˆ๋Š”๋ฐ ORACLE_HOME์— ๋Œ€ํ•œ ์ •๋ณด๋ฅผ ์ž๋™์œผ๋กœ ์ธ์‹ํ•˜์—ฌ ๋ณ€๊ฒฝ ์™„๋ฃŒ๋˜์—ˆ์Šต๋‹ˆ๋‹ค.

 

 

2. pfile ์ƒ์„ฑ

[oracle@host ~]$ cd $ORACLE_HOME/dbs
[oracle@host dbs]$ ls
hc_DBUA0.dat  hc_orcl.dat  init.ora  initorcl.ora  lkORCL  orapworcl  spfileorcl.ora
[oracle@host dbs]$ vi initprod.ora
db_name=prod
control_files='/opt/oracle/app/oradata/prod/control01.ctl'
sga_target=400M
remote_login_passwordfile='EXCLUSIVE'

Database Create๋Š” nomount ์ƒํƒœ์—์„œ ๊ฐ€๋Šฅํ•ฉ๋‹ˆ๋‹ค. ํŒŒ๋ผ๋ฏธํ„ฐ ํŒŒ์ผ์„ ์ฝ์„ ์ˆ˜ ์žˆ๋Š” ์ƒํƒœ๊นŒ์ง€ Database๋ฅผ ์˜ฌ๋ฆฌ๋Š” ์ž‘์—…์ด ํ•„์š”ํ•˜์—ฌ pfile์„ ์ง์ ‘ ์ƒ์„ฑํ•˜์—ฌ ์ตœ์†Œ๋กœ ํ•„์š”ํ•œ ๋‚ด์šฉ์„ ์ž‘์„ฑํ•ฉ๋‹ˆ๋‹ค. pfile์€ $ORACLE_HOME/dbs ๊ฒฝ๋กœ์— init<ORACLE_SID>.ora ํ˜•ํƒœ๋กœ ํŒŒ์ผ์ด ์กด์žฌํ•ด์•ผํ•ฉ๋‹ˆ๋‹ค.

 

๊ธฐ๋ณธ์ ์œผ๋กœ Parameter file์„ ์—ด๊ธฐ ์œ„ํ•ด์„œ๋Š” db_name, control_files, shared_pool_size ๊ทธ๋ฆฌ๊ณ  db_cache_size ์ด 4๊ฐœ์ง€ ํŒŒ๋ผ๋ฏธํ„ฐ๊ฐ€ ์ •์˜๋˜์–ด ์žˆ์–ด์•ผํ•ฉ๋‹ˆ๋‹ค. ํ•˜์ง€๋งŒ sga_target ํŒŒ๋ผ๋ฏธํ„ฐ๋ฅผ ์ •์˜ํ•œ๋‹ค๋ฉด sga ๋ฉ”๋ชจ๋ฆฌ๋ฅผ ์ž๋™์œผ๋กœ ํ• ๋‹นํ•˜๊ธฐ ๋•Œ๋ฌธ์— shared_pool_size์™€ db_cache_size์˜ ์ •๋ณด๋ฅผ ์ œ์™ธํ•  ์ˆ˜ ์žˆ์Šต๋‹ˆ๋‹ค.

 

remote_login_passwordfile์€ ํ•„์ˆ˜์ ์ธ ์š”์†Œ๋Š” ์•„๋‹ˆ์ง€๋งŒ Password fie์ด ํ•˜๋‚˜์˜ ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค์—์„œ ์‚ฌ์šฉํ•  ์ˆ˜ ์žˆ๋„๋ก ์„ค์ •.

 

 

3. spfile ์ƒ์„ฑ

[oracle@host ~]$ sqlplus / as sysdba
SQL> create spfile from pfile;

File created.

SQL> !ls $ORACLE_HOME/dbs
hc_DBUA0.dat  hc_orcl.dat  init.ora  initorcl.ora  initprod.ora  lkORCL  orapworcl  spfileorcl.ora  spfileprod.ora

 

 

pfile์„ ์‚ฌ์šฉํ•ด์„œ ์‹คํ–‰ํ•  ์ˆ˜ ์žˆ์ง€๋งŒ, ํŽธ์˜์ƒ ์ž‘์„ฑํ•œ pfile๋กœ spfile์„ ์ƒ์„ฑํ•˜๊ณ  Database๋ฅผ ์‹คํ–‰ํ•  ๊ณ„ํš์ž…๋‹ˆ๋‹ค. spfile ์ƒ์„ฑ ์ž‘์—…์€ DB๊ฐ€ ๋‚ด๋ ค๊ฐ€์žˆ๋Š” ์ƒํƒœ์—์„œ ๋งŒ๋“ค ์ˆ˜ ์žˆ๊ณ  ์ƒ์„ฑ ์ดํ›„ spfile<ORACLE_SID>.ora ํ˜•ํƒœ์˜ ํŒŒ์ผ์ด ๋งŒ๋“ค์–ด์ง„ ๊ฒƒ์„ ํ™•์ธํ•  ์ˆ˜ ์žˆ์Šต๋‹ˆ๋‹ค.

 

 

DB nomount ์‹คํ–‰

SQL> startup nomount
ORACLE instance started.

Total System Global Area  417546240 bytes
Fixed Size		    2213936 bytes
Variable Size		  134219728 bytes
Database Buffers	  272629760 bytes
Redo Buffers		    8482816 bytes

Database ์ƒ์„ฑ์„ ์œ„ํ•ด nomount ์ƒํƒœ๋กœ DB๋ฅผ ์‹คํ–‰ํ•ฉ๋‹ˆ๋‹ค. ์ •์ƒ์ ์œผ๋กœ ์˜ฌ๋ผ์™”๋‹ค๋ฉด ์ƒ์„ฑํ•œ pfile์— ๋ฌธ์ œ๊ฐ€ ์—†๋‹ค๋Š” ๋œป์ž…๋‹ˆ๋‹ค.

 

 

4. DB ์ƒ์„ฑ

[oracle@host ~]$ mkdir  /opt/oracle/app/oradata/prod

DB ์ƒ์„ฑํ•˜๋ฉด์„œ ๋งŒ๋“ค์–ด์งˆ datafile, redologfile๋“ค์˜ ๊ฒฝ๋กœ๋ฅผ ๋งŒ๋“ค์–ด์ค๋‹ˆ๋‹ค.

 

[oracle@host ~]$ sqlplus / as sysdba
CREATE DATABASE prod
USER SYS IDENTIFIED BY oracle
USER SYSTEM IDENTIFIED BY oracle
CONTROLFILE REUSE
LOGFILE GROUP 1 ('/opt/oracle/app/oradata/prod/redo01a.log'
                ,'/opt/oracle/app/oradata/prod/redo01b.log') SIZE 100M REUSE,
        GROUP 2 ('/opt/oracle/app/oradata/prod/redo02a.log'
                ,'/opt/oracle/app/oradata/prod/redo02b.log') SIZE 100M REUSE
EXTENT MANAGEMENT LOCAL
DATAFILE '/opt/oracle/app/oradata/prod/system01.dbf' SIZE 400M REUSE AUTOEXTEND ON
SYSAUX
DATAFILE '/opt/oracle/app/oradata/prod/sysaux01.dbf' SIZE 200M REUSE AUTOEXTEND ON
DEFAULT TEMPORARY TABLESPACE TEMP
TEMPFILE '/opt/oracle/app/oradata/prod/temp01.dbf' SIZE 100M REUSE AUTOEXTEND ON
UNDO TABLESPACE UNDOTBS1
DATAFILE '/opt/oracle/app/oradata/prod/undotbs01.dbf' SIZE 200M REUSE AUTOEXTEND ON
CHARACTER SET AL32UTF8
NATIONAL CHARACTER SET AL16UTF16;

Database created.

 

USER SYS IDENTIFIED ... : SYS ์œ ์ € ๋น„๋ฐ€๋ฒˆํ˜ธ ์ง€์ •

 

USER SYSTEM IDENTIFIED ... : SYSTEM  ์œ ์ € ๋น„๋ฐ€๋ฒˆํ˜ธ ์ง€์ •

 

CONTROLFILE :

REUSE ๋ช…๋ น์„ ์‚ฌ์šฉํ•˜๊ธฐ ์œ„ํ•ด ๋ช…์‹œ. LOGFILE GROUP ์ด๋‚˜ DATAFILE๋“ค์—์„œ๋„ REUSE ์˜ต์…˜์ด ๋ถ™์–ด ์žˆ์Šต๋‹ˆ๋‹ค. ์ด ์˜ต์…˜์€ ๋งŒ์•ฝ ํ•ด๋‹น ํŒŒ์ผ์ด ์ด๋ฏธ ์กด์žฌํ•œ๋‹ค๋ฉด ํ•ด๋‹น ํŒŒ์ผ ์ด๋ฆ„ ๊ทธ๋Œ€๋กœ ์‚ฌ์šฉํ•˜์—ฌ ๋ฎ์–ด์จ์„œ DB๋ฅผ ์ƒ์„ฑํ•ฉ๋‹ˆ๋‹ค.

 

LOGFILE GROUP : ๋กœ๊ทธ ํŒŒ์ผ์€ ์ตœ์†Œ 2๊ฐœ์˜ ๊ทธ๋ฃน์œผ๋กœ ์ง€์ •ํ•ด์•ผํ•ฉ๋‹ˆ๋‹ค.

 

EXTENET MANAGEMENT LOCAL :

LOCAL ๋ฐฉ์‹์€ Tablespace์— ๋Œ€ํ•œ free space ๊ณต๊ฐ„์„ datafile ์ž์ฒด์—์„œ bitmap์„ ์ด์šฉํ•ด์„œ ๊ด€๋ฆฌํ•˜๋Š” ๋ฐฉ๋ฒ•์ž…๋‹ˆ๋‹ค. ๋‹ค๋ฅธ๋ฐฉ๋ฒ•์œผ๋กœ Tablespace์˜ free space ๊ณต๊ฐ„์— ๋Œ€ํ•œ ์ •๋ณด๋ฅผ data dictionary์—์„œ ๊ด€๋ฆฌํ•˜๋Š” DICTIONARY ๋ฐฉ์‹์ด ์žˆ์ง€๋งŒ data dictionary์— ๋Œ€ํ•œ ๊ฒฝํ•ฉ์ด ์‹ฌํ•ด์ง€๊ณ  ์„ฑ๋Šฅ์ €ํ•˜์˜ ์›์ธ์œผ๋กœ Oracle 8i๋ถ€ํ„ฐ LOCAL ๋ฐฉ์‹์ด ์ฒ˜์Œ ์†Œ๊ฐœ๋˜๋ฉด์„œ ์ด ๋ฐฉ์‹์œผ๋กœ ๊ด€๋ฆฌํ•˜๋„๋ก ๊ถŒ์žฅํ•ฉ๋‹ˆ๋‹ค.

 

DATAFILE :

        ์ง€์ • ์—†์Œ : SYSTEM Tablespace

        SYSAUX : SYSTEM Auxilary(๋ณด์กฐ)

        UNDO : ์–ธ๋‘ Tablespace ์ง€์ •

 

TEMPFILE : TEMPORARY Tablespace๋Š” DEFAULT TEMPORARY TABLESPACE๋ฅผ ๊ผญ ์ง€์ •ํ•ด์ค˜์•ผํ•ฉ๋‹ˆ๋‹ค.

 

CHARACTER SET, NATIONAL CHARACTER SET : ๋ฌธ์ž ์ธ์ฝ”๋”ฉ ์ง€์ •

 

 

 

DB Open ํ™•์ธ

SQL> select instance_name, status from v$instance; 

Instance๊ฐ€ Open ์ƒํƒœ๊นŒ์ง€ ์˜ฌ๋ผ์™”๋Š”์ง€ ํ™•์ธํ•ฉ๋‹ˆ๋‹ค.

 

์—ฌ๋Ÿฌ SID ์‚ฌ์šฉ ํ™•์ธ

ํ™˜๊ฒฝ๋ณ€์ˆ˜ ๋ณ€๊ฒฝ

[oracle@host ~]$ . oraenv 
ORACLE_SID = [prod] ? orcl
The Oracle base for ORACLE_HOME=/opt/oracle/app/product/11.2.0/dbhome_1 is /opt/oracle/app
[oracle@host ~]$ sqlplus / as sysdba

prod์— ๋ถ™์–ด์„œ ์ž‘์—…ํ•˜๋‹ค๊ฐ€ orcl๋กœ ๋ณ€๊ฒฝํ•ด์„œ ์ž‘์—…ํ•˜๊ธฐ ์œ„ํ•ด์„œ oraenv๋กœ ํ™˜๊ฒฝ๋ณ€์ˆ˜์˜ ์ •๋ณด๋ฅผ ๋ณ€๊ฒฝํ•˜๊ณ  ๋กœ๊ทธ์ธํ•ด์ค๋‹ˆ๋‹ค.

 

 

orcl instance startup

SQL> startup

orcl instance๋ฅผ ๊ธฐ๋™ํ•ด์ค๋‹ˆ๋‹ค.

 

SQL> select instance_name, status from v$instance; 

orcl์—์„œ๋„ ๋งˆ์ฐฌ๊ฐ€์ง€๋กœ instance์˜ open ์ƒํƒœ๋ฅผ ํ™•์ธํ•ฉ๋‹ˆ๋‹ค.

 

[oracle@host ~]$ ps -ef | grep smon

์ฃผ์š” ํ”„๋กœ์„ธ์Šค์ค‘ ํ•˜๋‚˜์ธ smon์˜ ํ”„๋กœ์„ธ์Šค๊ฐ€ ๊ธฐ๋™์ค‘์ธ์ง€ ํ™•์ธํ•ฉ๋‹ˆ๋‹ค. prod์™€ orcl๋ชจ๋‘ ์˜ฌ๋ผ์™€ ์žˆ๋‹ค๋ฉด ๊ฐ๊ฐ ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค์— ์—ฐ๊ฒฐ๋œ ์ธ์Šคํ„ด์Šค๋ฅผ ์˜ฌ๋ ค์ค€ ๊ฒƒ์„ ํ™•์ธํ•  ์ˆ˜ ์žˆ์Šต๋‹ˆ๋‹ค.

 

 

ํ›„์†์ž‘์—…

๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค์˜ ์ƒ์„ฑ์€ ์™„๋ฃŒ๋˜์—ˆ๊ณ  ์ด์ƒ์—†์ด ๋Œ์•„๊ฐ‘๋‹ˆ๋‹ค. ํ•˜์ง€๋งŒ ์ˆ˜๋™ ์ƒ์„ฑํ–ˆ์„ ๋•Œ Data Dictionary ์กฐํšŒ์ž‘์—…์ด๋‚˜, Oracle์—์„œ ์ œ๊ณตํ•˜๋Š” ํŒจํ‚ค์ง€๋“ค์ด ์‹คํ–‰๋˜์ง€ ์•Š์Šต๋‹ˆ๋‹ค. ์ด๋Ÿฐ ๋ฌธ์ œ๋“ค์„ ํ•ด๊ฒฐํ•˜๊ธฐ ์œ„ํ•ด ๋ช‡ ๊ฐ€์ง€ ํ›„์†์ž‘์—…์„ ํ•ด์ค˜์•ผํ•ฉ๋‹ˆ๋‹ค. ํ›„์†์ž‘์—…์— ๋Œ€ํ•œ ๋‚ด์šฉ์€ ์•„๋ž˜ ๋งํฌ๋ฅผ ํ†ตํ•ด ์ง„ํ–‰ํ•  ์ˆ˜ ์žˆ์Šต๋‹ˆ๋‹ค.

 

[Oracle] ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค ์ƒ์„ฑ ํ›„์† ์ž‘์—…, Data Dictionary ์กฐํšŒ ์•ˆ๋˜๋Š” ๊ฒƒ ๋ฌธ์ œ ํ•ด๊ฒฐ

๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค ์ƒ์„ฑ ํ›„์† ์ž‘์—… ์ด์ „ ๊ธ€์—์„œ ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค ์ˆ˜๋™์ƒ์„ฑํ•˜๋Š” ์ž‘์—…์„ ์ง„ํ–‰ํ–ˆ์Šต๋‹ˆ๋‹ค. ์ˆ˜๋™์œผ๋กœ ์ž‘์—…์„ ์ง„ํ–‰ ํ–ˆ์„ ๋•Œ ๋ฌธ์ œ์—†์ด ๋ฐ์ดํ„ฐ๋ฒ ์ด์Šค๋ฅผ ์‚ฌ์šฉํ•  ์ˆ˜ ์žˆ์ง€๋งŒ, ๋ช‡๊ฐ€์ง€ ์•ˆ๋˜๋Š” ๊ธฐ๋Šฅ๋“ค๏ฟฝ

myjamong.tistory.com

 

 

๋Œ“๊ธ€