ArcSDESQLExecute (arcpy)

サマリ

The ArcSDESQLExecute class provides a means of executing SQL statements via an ArcSDE connection.

説明

注意注意:
  • ArcGIS ソフトウェア以外のものを使用して ArcSDE および GDB のシステム テーブルを変更することはできません。SQL を使用してこれらのシステム テーブルを直接編集すると、ジオデータベースを破損する可能性があります。
  • SQL を使用してバージョン対応登録されたデータを編集する場合は、必ずバージョン ビューから行う必要があります。
  • リレーショナル データベース管理システム(DBMS)のデータ タイプとテーブル フォーマットを使用して DBMS に実装されたジオデータベースの場合は、DBMS 独自の SQL を使用して、データベースに格納された情報を操作できます。
  • SQL によってジオデータベースの情報にアクセスすれば、ジオデータベースによって管理されるテーブル データに外部アプリケーションからアクセスできます。この外部アプリケーションは、非空間データベース アプリケーションであっても、ArcObjects 以外の環境で開発されたカスタムの空間アプリケーションであっても構いません。ただし、ジオデータベースへの SQL アクセス時には、トポロジ、ネットワーク、テレイン、その他のクラスやワークスペースのエクステンションなど、ジオデータベースの機能は適用されないことに注意してください。
  • 一部のジオデータベース機能に必要なテーブル間の関係を維持するために、トリガやストアド プロシージャなどの DBMS 機能を使用できる場合があります。一方で、これらの機能を考慮せずにデータベースに対して SQL コマンドを実行すると(たとえば、INSERT ステートメントを実行してビジネス テーブルにレコードを追加する)、ジオデータベース機能が適用されず、ジオデータベース内のデータ間の関係が破壊される可能性があります。
  • ArcSDE または GDB のオブジェクトにアクセスしたり、これらのオブジェクトを変更したりする前に、DBMS 内で ArcSDE や GDB のオブジェクトに対して SQL を使用する場合の注意点について、ArcSDE およびジオデータベースの資料をすべてお読みください。

構文

ArcSDESQLExecute ({server}, {instance}, {database}, {user}, {password})
パラメータ説明データ タイプ
server

Name of the server on which the database is installed.

String
instance

The port number

String
database

Name of the database.

String
user

The user name.

String
password

The password for the user name.

String

特性

プロパティ説明データ タイプ
transactionAutoCommit
(読み書き)

The autocommit interval. This can be used to force intermediate commits after a specified number of features have been modified.

Integer

メソッドの概要

メソッド説明
commitTransaction ()

No DML statements will be committed until the CommitTransaction method is called.

注意注意:

A commit may also occur when the connection to ArcSDE it terminated (check specific DBMS documentation to see how each DBMS deals with a disconnect while in a transaction).

execute (sql_statement)

Sends the SQL statement to the database via an ArcSDE connection. If execute is run outside of a transaction, a commit will automatically take place once the SQL DML (INSERT, UPDATE, DELETE . . .) statement has been executed.

rollbackTransaction ()

Rollback any DML operations to the previous commit.

startTransaction ()

To control when your changes are committed to the database, call the startTransaction method before calling execute. This starts a transaction and no DML statements will be committed until the commitTransaction method is called.

メソッド

commitTransaction ()
execute (sql_statement)
パラメータ説明データ タイプ
sql_statement

The SQL statement.

String
rollbackTransaction ()
startTransaction ()

コードのサンプル

SQL ステートメントのリストを実行する
import arcpy
from arcpy import env
import sys

try:
    # Make data path relative
    #
    env.workspace = sys.path[0]
    
    # Two ways to create the object, which also creates the connection to ArcSDE.
    #   Using the first method, pass a set of strings containing the connection properties:
    #   <serverName>,<portNumber>,<version>,<userName>,<password>
    #   sdeConn = arcpy.ArcSDESQLExecute("gpserver3","5151","#","toolbox","toolbox")
    #   Using the second method pass the path to a valid ArcSDE connection file
    #
    sdeConn = arcpy.ArcSDESQLExecute("data\Connection to GPSERVER3.sde")
    
    # Get the SQL statements, separated by ; from a text string.
    #
    SQLStatement = arcpy.GetParameterAsText(0)
    SQLStatementList = SQLStatement.split(";")
    
    print "+++++++++++++++++++++++++++++++++++++++++++++\n"

    # For each SQL statement passed in, execute it.
    #
    for sql in SQLStatementList:
        print "Execute SQL Statement: " + sql
        try:
            # Pass the SQL statement to the database.
            #
            sdeReturn = sdeConn.execute(sql)
        except Exception, ErrorDesc:
            print ErrorDesc
            sdeReturn = False
        
        # If the return value is a list (a list of lists), display each list as a row from the 
        #   table being queried.
        if isinstance(sdeReturn, list):
            print "Number of rows returned by query: " + str(len(sdeReturn)), "rows"
            for row in sdeReturn:
                print row
            print "+++++++++++++++++++++++++++++++++++++++++++++\n"
        else:
            # If the return value was not a list, the statement was most likely a DDL statment. 
            #   Check its status.
            if sdeReturn == True:
                print "SQL statement: " + sql + " ran sucessfully."
                print "+++++++++++++++++++++++++++++++++++++++++++++\n"
            else:
                print "SQL statement: " + sql + " FAILED."
                print "+++++++++++++++++++++++++++++++++++++++++++++\n"
                
except Exception, ErrorDesc:
    print Exception, ErrorDesc
except:
    print "Problem executing SQL."
トランザクションを使用した条件付き更新
# WARNING - DO NOT USE ON VERSIONED TABLES OR FEATURE CLASSES. 
#   DO NOT USE ON ANY ArcSDE or GDB SYSTEM TABLES.
#   DOING SO MAY RESULT IN DATA CORRUPTION.

import arcpy
from arcpy import env
import sys

try:
    # Make data path relative (not relevant unless data is moved here and paths modified)
    #
    env.workspace = sys.path[0]

    #Column name:value that should be in the record.
    #
    SQLvalues = {"STREET_NAM":"'EUREKA'"}

    #Value that is incorrect if found in the above column.
    #
    badVal = "'EREKA'"

    #List of tables to look in for the bad value.
    #
    tableList = ["streetaddresses_blkA","streetaddresses_blkB", "streetaddresses_blkC"]
    
    # Two ways to create the object, which also creates the connection to ArcSDE.
    #   Using the first method, pass a set of strings containing the connection properties:
    #   <serverName>,<portNumber>,<version>,<userName>,<password>
    #
    sdeConn = arcpy.ArcSDESQLExecute("gpserver3","5151","#","toolbox","toolbox")

    # Using the second method pass the path to a valid ArcSDE connection file
    #   sdeConn = arcpy.ArcSDESQLExecute("data\Connection to GPSERVER3.sde")

    for tbl in tableList:
        print "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
        for col, val in SQLvalues.items():
            print "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
            #Check for the incorrect value in the column for the specific rows. If the table contains the 
            #incorrect value, correct it using the update SQL statement.
            #
            print "Analyzing table " + tbl + " for bad data: Column:" + col + " Value: " + badVal
            try:
                sql = "select OBJECTID," + col + " from " + tbl + " where " + col + " = " + badVal
                print "Attempt to execute SQL Statement: " + sql
                sdeReturn = sdeConn.execute(sql)
            except Exception, ErrorDesc:
                print ErrorDesc
                sdeReturn = False
            if isinstance(sdeReturn, list):
                if len(sdeReturn) > 0:
                    print "Identified " + str(len(sdeReturn)) + " rows with incorrect data. Starting transaction for update."
                    # Start the transaction
                    #
                    sdeConn.startTransaction()
                    print "Transaction started....."
                    # Perform the update
                    #
                    try:
                        sql = "update " + tbl + " set " + col + "=" + str(val) + " where " + col + " = " + badVal
                        print "Changing bad value: " + badVal + " to the good value: " + val + " using update statement:\n " + sql
                        sdeReturn = sdeConn.execute(sql)
                    except Exception, ErrorDesc:
                        print ErrorDesc
                        sdeReturn = False

                    # If the update completed sucessfully, commit the changes.  If not, rollback.
                    #
                    if sdeReturn == True:
                        print "Update statement: \n" + sql + " ran successfully."
                        # Commit the changes
                        #
                        sdeConn.commitTransaction()
                        print "Commited Transaction"

                        # List the changes.
                        #
                        try:
                            print "Displaying updated rows for visual inspection."
                            sql = "select OBJECTID," + col + " from " + tbl + " where " + col + " = " + val
                            print "Executing SQL Statement: \n" + sql
                            sdeReturn = sdeConn.execute(sql)
                        except Exception, ErrorDesc:
                            print ErrorDesc
                            sdeReturn = False
                        if isinstance(sdeReturn, list):
                            print len(sdeReturn), "rows"
                            for row in sdeReturn:
                                print row
                            print "+++++++++++++++++++++++++++++++++++++++++++++\n"
                        else:
                            if sdeReturn == True:
                                print "SQL statement: \n" + sql + "\nran successfully."
                                print "+++++++++++++++++++++++++++++++++++++++++++++\n"
                            else:
                                print "SQL statement: \n" + sql + "\nFAILED."
                                print "+++++++++++++++++++++++++++++++++++++++++++++\n"

                        print "+++++++++++++++++++++++++++++++++++++++++++++\n"
                    else:
                        print "SQL statement: \n" + sql + "\nFAILED.  Rolling back all changes."
                        # Rollback changes
                        #
                        sdeConn.rollbackTransaction()
                        print "Rolled back any changes."
                        print "+++++++++++++++++++++++++++++++++++++++++++++\n"
            else:
                print "No records required updating."
            
    # Disconnect and exit
    del sdeConn
    print "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"

except Exception, ErrorDesc:
    print Exception, ErrorDesc
except:
    print "Problem executing SQL."

関連トピック

9/14/2013