Skip to main content

Importing InterSystems SQL

Importing InterSystems SQL

You can import InterSystems SQL code from a text file using either of the following %SYSTEM.SQL.SchemaOpens in a new tab methods:

  • ImportDDL()Opens in a new tab is a general-purpose SQL import method. This method runs as a background (non-interactive) process. To import InterSystems SQL you specify “IRIS” as the third parameter.

  • Run()Opens in a new tab is an InterSystems SQL import method. This method runs interactively from the Terminal. It prompts you to specify the location of the import text file, the location to create the Errors.log file and the Unsupported.log file, and other information.

Note:

This import and execution of SQL DDL code should not be confused with the Import Statements Action from the Management Portal SQL interface. That operation imports SQL Statements in XML format.

The following example imports the InterSystems IRIS SQL code file pathname mysqlcode.txt, executing the SQL commands listed in that file in the current namespace:

  DO $SYSTEM.SQL.Schema.ImportDDL("c:\InterSystems\mysqlcode.txt",,"IRIS")

By default, ImportDDL() creates an errors log file, as specified in the second parameter. This example, which omits the second parameter, creates by default a file named mysqlcode_Errors.log in the same directory as the SQL code file. This log file is created even when there is nothing written to it.

When executing ImportDDL() from the Terminal, it first lists the input file, then the error log file, then lists each SQL command imported, as shown in the following example:

Importing SQL Statements from file: c:\InterSystems\mysqlcode.txt
 
Recording any errors to principal device and log file: c:\InterSystems\mysqlcode_Errors.log

 SQL statement to process (number 1):
     CREATE TABLE Sample.NewTab (Name VARCHAR(40))
      Preparing SQL statement...
      Executing SQL statement...
  DONE
 
  SQL statement to process (number 2):
     CREATE INDEX NameIDX ON Sample.NewTab (Name)
      Preparing SQL statement...
      Executing SQL statement...
  DONE
 
Elapsed time: 7.342532 seconds

If an error occurs in any SQL command, the Terminal display the error, as shown in the following example:

SQL statement to process (number 3):
       INSERT INTO Sample.MyStudents (StudentName,StudentDOB) SELECT Name,
       DOB FROM Sample.Person WHERE Age <= '21'
    Preparing SQL statement...
ERROR #5540: SQLCODE: -30 Message:  Table 'SAMPLE.PERSON' not found
       Pausing 5 seconds - read error message!  (Type Q to Quit)

If you do not Quit within 5 seconds, ImportDDL() proceeds to execute the next SQL command. The error is recorded in the errors log file with a timestamp, the user name, and the namespace name.

Import File Format

An SQL text file must be an unformatted file such as a .txt file. Each SQL command must begin on its own line. An SQL command may be broken into multiple lines and indentation is permitted. Each SQL command must be followed by a GO statement on its own line.

The following is an example of a valid InterSystems SQL import file text:

  CREATE TABLE Sample.MyStudents (StudentName VARCHAR(32),StudentDOB DATE)
GO
  CREATE INDEX NameIdx ON TABLE Sample.MyStudents (StudentName)
GO
  INSERT INTO Sample.MyStudents (StudentName,StudentDOB) SELECT Name,
  DOB FROM Sample.Person WHERE Age <= '21'
GO
  INSERT INTO Sample.MyStudents (StudentName,StudentDOB) 
          VALUES ('Jones,Mary',60123)
GO
  UPDATE Sample.MyStudents SET StudentName='Smith-Jones,Mary' WHERE StudentName='Jones,Mary'
GO
  DELETE FROM Sample.MyStudents WHERE StudentName %STARTSWITH 'A'
GO

Supported SQL Commands

Not all valid InterSystems SQL commands can be imported. The following is a list of supported InterSystems SQL commands:

  • CREATE TABLE, ALTER TABLE, DROP TABLE

  • CREATE VIEW, ALTER VIEW, DROP VIEW

  • CREATE INDEX all index types, except bitslice

  • CREATE USER, DROP USER

  • CREATE ROLE

  • GRANT, REVOKE

  • INSERT, UPDATE, INSERT OR UPDATE, DELETE

  • SET OPTION

  • SELECT for optimizer plan mode only

FeedbackOpens in a new tab