OK, here's something but first some background.
One of the MVPs on this board, and one of the newest Microsoft Excel MVPs, is Masaru Kaji, also known as Colo. Bill Jelen's newest Excel & VBA book will be out in a couple months, and among the contributions to it is from Colo, for code that triggers an event by the act of deleting a row or column.
Your question deals with inserting a row. So, the code below will trigger an event when a row is inserted. All credit goes to Colo; he is the brains behind this; all I am doing is adjusting the code regarding the command bar controls and some of the code to change it from row deletion (his original code) to insertion (your question).
His original code for this is here on his site:
http://www.interq.or.jp/sun/puremis/colo/
What you would do is run the macro he calls "EventHack" to alert Excel that it should alert you when a row is inserted. To disable the code, run the "EventReset" macro. You can run these at Workbook Open, Activate, Close, or Deactivate.
Here is the entire code, full thanks again to Colo, modified very slightly by me to address the issue of row insertion:
Sub EventHack()
AssignMacro "JudgeRng"
End Sub
Sub EventReset()
AssignMacro ""
End Sub
Private Sub AssignMacro(ByVal strProc As String)
Dim lngId As Long
Dim CtrlCbc As CommandBarControl
Dim CtrlCbcRet As CommandBarControls
Dim arrIdNum As Variant
' 295 Insert Cells from worksheet menu
' 296 Insert rows from worksheet menu
' 945 Insert from right click menu
arrIdNum = Array(295, 296, 945)
For lngId = LBound(arrIdNum) To UBound(arrIdNum)
Set CtrlCbcRet = CommandBars.FindControls(ID:=arrIdNum(lngId))
For Each CtrlCbc In CtrlCbcRet
CtrlCbc.OnAction = strProc
Next
Set CtrlCbcRet = Nothing
Next
End Sub
Sub JudgeRng()
If Not TypeOf Selection Is Range Then Exit Sub
With Selection
If .Address = .EntireRow.Address Then
Call InsertRows("Row:" & .Row, xlUp)
Else
Application.Dialogs(xlDialogEditDelete).Show
End If
End With
End Sub
Sub InsertRows(ByVal str, ByVal lngDerec As Long)
MsgBox "Inserted: " & str & vbCrLf & "Your event code would go here."
Selection.Insert lngDerec
End Sub