ArcSDESQLExecute (arcpy)

Zusammenfassung

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

Diskussion

AchtungAchtung:
  • ArcSDE- und GDB-Systemtabellen dürfen nur mit der ArcGIS-Software geändert werden. Diese Systemtabellen können beschädigt werden, wenn sie direkt mit SQL bearbeitet werden.
  • Die Bearbeitung versionierter Daten per SQL sollte nur über versionierte Sichten erfolgen.
  • Bei Geodatabases, die in einem relationalen Datenbankmanagementsystem (DBMS) mit DBMS-Datentypen und -Tabellenformaten implementiert sind, können Sie die SQL des DBMS nutzen, um mit den in der Datenbank gespeicherten Informationen zu arbeiten.
  • Erfolgt der Zugriff auf die Informationen in einer Geodatabase über SQL, können externe Anwendungen auf die Tabellendaten zugreifen, die von der Geodatabase verwaltet werden. Bei diesen externen Anwendungen kann es sich um nicht räumliche Datenbankanwendungen oder benutzerdefinierte räumliche Anwendungen handeln, die in einer anderen Umgebung als ArcObjects entwickelt wurden. Wenn Sie über SQL auf die Geodatabase zugreifen, stehen jedoch nicht alle Geodatabase-Funktionen zur Verfügung, zum Beispiel Topologie, Netzwerke, Terrains oder andere Klassen- bzw. Workspace-Erweiterungen.
  • DBMS-Funktionen wie Trigger und gespeicherte Prozeduren können u. U. zur Verwaltung von Beziehungen zwischen Tabellen verwendet werden, die für bestimmte Geodatabase-Funktionen erforderlich sind. Wenn Sie jedoch die SQL-Befehle in der Datenbank ausführen, ohne diese zusätzliche Funktionalität zu berücksichtigen (z. B. beim Einfügen von Datensätzen in eine Business-Tabelle mit einer INSERT-Anweisung), wird die Geodatabase-Funktionalität umgangen und die Beziehungen zwischen den Daten in der Geodatabase können beschädigt werden.
  • Lesen Sie möglichst in der ArcSDE- und Geodatabase-Dokumentation alle Informationen zur Verwendung von SQL bei ArcSDE- bzw. GDB-Objekten im DBMS, bevor Sie auf ArcSDE- oder GDB-Objekte zugreifen bzw. diese bearbeiten.

Syntax

ArcSDESQLExecute ({server}, {instance}, {database}, {user}, {password})
ParameterErläuterungDatentyp
server

Name of the server on which the database is installed or a valid connection file.

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

Eigenschaften

EigenschaftErläuterungDatentyp
transactionAutoCommit
(Lesen und schreiben)

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

Integer

Methodenübersicht

MethodeErläuterung
commitTransaction ()

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

HinweisHinweis:

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.

Methoden

commitTransaction ()
execute (sql_statement)
ParameterErläuterungDatentyp
sql_statement

The SQL statement.

The execute method returns a list of lists in the case where the statement returns rows from a table; for statements that do not return rows, it will return an indication of the success or failure of the statement (True for success; None for failure). Statements that return a single value from a single row will return the value in an appropriate type (string, float, float).

Variant
rollbackTransaction ()
startTransaction ()

Codebeispiel

Query for the number of each crime type and return a list of lists of the crime type and count of incidents.

import arcpy

# Use an sde connection file to create the connection
sde = r'Database Connections\Connection to bedrock.sde'
sde_conn = arcpy.ArcSDESQLExecute(sde)

table_name = 'vtest.GDB.Crime'
field_name = 'CRIMETYPE'

sql = '''
SELECT {0}, COUNT({0}) AS f_count FROM {1}
GROUP BY {0}
ORDER BY f_count DESC
'''.format(field_name, table_name)

sde_return = sde_conn.execute(sql)
for i in sde_return:
    print('{}: {}'.format(*i))
Ausführen einer Liste von SQL-Anweisungen
import sys
import arcpy

try:
    # Make data path relative
    arcpy.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>
    #   arcpy.ArcSDESQLExecute("gpserver3","5151","#","toolbox","toolbox")
    # Using the second method pass the path to a valid ArcSDE connection file
    sde_conn = arcpy.ArcSDESQLExecute(r"data\Connection to GPSERVER3.sde")

    # Get the SQL statements, separated by ; from a text string.
    sql_statement = arcpy.GetParameterAsText(0)
    sql_statement_list = sql_statement.split(";")

    print("+++++++++++++++++++++++++++++++++++++++++++++\n")

    # For each SQL statement passed in, execute it.
    for sql in sql_statement_list:
        print("Execute SQL Statement: {0}".format(sql))
        try:
            # Pass the SQL statement to the database.
            sde_return = sde_conn.execute(sql)
        except Exception as err:
            print(err)
            sde_return = 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(sde_return, list):
            print("Number of rows returned by query: {0} rows".format(
                len(sde_return)))
            for row in sde_return:
                print(row)
            print("+++++++++++++++++++++++++++++++++++++++++++++\n")
        else:
            # If the return value was not a list, the statement was
            # most likely a DDL statement. Check its status.
            if sde_return == True:
                print("SQL statement: {0} ran successfully.".format(sql))
            else:
                print("SQL statement: {0} FAILED.".format(sql))
            print("+++++++++++++++++++++++++++++++++++++++++++++\n")

except Exception as err:
    print(err)
Bedingte Aktualisierung mit einer Transaktion
# 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 sys
import arcpy

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

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

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

    #List of tables to look in for the bad value.
    tables = ["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>
    sde_conn = arcpy.ArcSDESQLExecute("gpserver3", "5151", "#",
                                      "toolbox", "toolbox")

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

    for tbl in tables:
        print("+++++++++++++++++++++++++++++++++++++++++++++++++++++++++++")
        for col, val in sql_values.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 {0} for bad data: "
                  "Column:{1} Value: {2}".format(tbl, col, bad_val))
            try:
                sql = "select OBJECTID,{0} from {1} where {0} = {2}".format(
                      col, tbl, bad_val)
                print("Attempt to execute SQL Statement: {0}".format(sql))
                sde_return = sde_conn.execute(sql)
            except Exception as err:
                print(err)
                sde_return = False

            if isinstance(sde_return, list):
                if len(sde_return) > 0:
                    print("Identified {0} rows with incorrect data. Starting "
                          "transaction for update.".format(len(sde_return)))
                    # Start the transaction
                    sde_conn.startTransaction()
                    print("Transaction started...")
                    # Perform the update
                    try:
                        sql = "update {0} set {1}={2} where {1} = {3}".format(
                              tbl, col, val, bad_val)
                        print("Changing bad value: {0} to the good value: "
                              "{1} using update statement:\n {2}".format(
                              bad_val, val, sql))
                        sde_return = sde_conn.execute(sql)
                    except Exception as err:
                        print(err)
                        sde_return = False

                    # If the update completed successfully, commit the
                    # changes.  If not, rollback.
                    if sde_return == True:
                        print("Update statement: \n"
                              "{0} ran successfully.".format(sql))
                        # Commit the changes
                        sde_conn.commitTransaction()
                        print("Committed Transaction")

                        # List the changes.
                        try:
                            print("Displaying updated rows for "
                                  "visual inspection.")
                            sql = "select OBJECTID" + \
                                  ",{0} from {1} where {0} = {2}".format(
                                  col, tbl, val)
                            print("Executing SQL Statement: \n{0}".format(sql))
                            sde_return = sde_conn.execute(sql)
                        except Exception as err:
                            print(err)
                            sde_return = False

                        if isinstance(sde_return, list):
                            print("{0} rows".format(len(sde_return)))
                            for row in sde_return:
                                print(row)
                            print("++++++++++++++++++++++++++++++++++++++++\n")
                        else:
                            if sde_return == True:
                                print("SQL statement: \n{0}\n"
                                      "ran successfully.".format(sql))
                            else:
                                print("SQL statement: \n{0}\n"
                                      "FAILED.".format(sql))
                            print("++++++++++++++++++++++++++++++++++++++++\n")

                        print("++++++++++++++++++++++++++++++++++++++++\n")
                    else:
                        print("SQL statement: \n{0}\nFAILED. "
                              "Rolling back all changes.".format(sql))
                        # Rollback changes
                        sde_conn.rollbackTransaction()
                        print("Rolled back any changes.")
                        print("++++++++++++++++++++++++++++++++++++++++\n")
            else:
                print "No records required updating."

    # Disconnect and exit
    del sde_conn
    print("+++++++++++++++++++++++++++++++++++++++++++++++++++++++++++")

except Exception as err:
    print(err)

Verwandte Themen

4/26/2014